Querying Data From One Table Against Another Table For All Results

  • Hello,

    I am new to the forums and overall new to SQL and SRSS. I have two 2008 SQL databases that I am trying to generate a report from two different data sets.

    Essentially, I have one database that contains all of our supported buildings with their subnets:

    Table - Building_Information

    Building_Name Subnet

    Building 1 192.168.1.%

    Building 2 192.168.2.%

    Building 3 192.168.3.%

    And then in another database, I have a list of all of our devices:

    Table - Device_Information

    DeviceNum IP_Address

    Device1 192.168.1.2

    Device2 192.168.1.3

    Device3 192.168.2.2

    Device4 192.168.3.1

    Device5 192.168.3.2

    Device6 192.168.3.3

    What I am trying to achieve is a report by Building of the total number of devices in each Building.

    I have a Dataset for Building_Information:

    SELECT *

    FROM Building_Information

    and a second Dataset for Device_Information:

    SELECT count(IP_Address)

    FROM Device_Information

    WHERE (IP_Address LIKE (@Subnet))

    matching the parameter of @Subnet on the queried values of the Subnet from the Building_Information query.

    However, on the multiple value pass it gives an error because of the like statement (Incorrect syntax ","). When I try to substitute the LIKE for IN, it will only match the value if it is an exact match.

    Any ideas would be great.

    Thank you.

  • Hi,

    You must miss something simple. I don't know your exact code, however put attention on data types in tables of both databases.

    select col1,col2,...,colN

    from db1.shcema1.table1 tb1

    join db2.schema2.table2 tb2 on convert(nvarchar(100), tb1.id) = convert(nvarchar(100),tb2.id)

    where ... 'your conditions'

    also check if the collations on both databases are same.

    🙂

    Igor Micev,My blog: www.igormicev.com

  • Please next time provide DDL and INSERTs like this:

    CREATE TABLE #Building_Information (

    Building_Name VARCHAR(50)

    ,Subnet VARCHAR(15)

    );

    INSERT INTO #Building_Information (Building_Name, Subnet)

    VALUES ('Building 1', '192.168.1.%'),

    ('Building 2', '192.168.2.%'),

    ('Building 3', '192.168.3.%')

    SELECT * FROM #Building_Information

    CREATE TABLE #Device_Information (

    DeviceNum VARCHAR(50)

    ,IP_Address VARCHAR(15)

    );

    INSERT INTO #Device_Information (DeviceNum, IP_Address)

    VALUES ('Device1', '192.168.1.2'),

    ('Device2', '192.168.1.3'),

    ('Device3', '192.168.2.2'),

    ('Device4', '192.168.3.1'),

    ('Device5', '192.168.3.2'),

    ('Device6', '192.168.3.3')

    SELECT * FROM #Device_Information

    Now what do you mean by "multiple value pass"? What is the value of @Subnet when error occures?

    --Vadim R.

  • Do you mean something like this (based on test setup provided by rVadim):

    CREATE TABLE #Building_Information (

    Building_Name VARCHAR(50)

    ,Subnet VARCHAR(15)

    );

    INSERT INTO #Building_Information (Building_Name, Subnet)

    VALUES ('Building 1', '192.168.1.%'),

    ('Building 2', '192.168.2.%'),

    ('Building 3', '192.168.3.%')

    SELECT * FROM #Building_Information

    CREATE TABLE #Device_Information (

    DeviceNum VARCHAR(50)

    ,IP_Address VARCHAR(15)

    );

    INSERT INTO #Device_Information (DeviceNum, IP_Address)

    VALUES ('Device1', '192.168.1.2'),

    ('Device2', '192.168.1.3'),

    ('Device3', '192.168.2.2'),

    ('Device4', '192.168.3.1'),

    ('Device5', '192.168.3.2'),

    ('Device6', '192.168.3.3')

    SELECT * FROM #Device_Information;

    SELECT

    *

    FROM

    #Building_Information bi

    INNER JOIN #Device_Information di

    ON (di.IP_Address LIKE bi.Subnet);

    SELECT

    bi.Building_Name,

    COUNT(di.DeviceNum) NumberOfDevices

    FROM

    #Building_Information bi

    INNER JOIN #Device_Information di

    ON (di.IP_Address LIKE bi.Subnet)

    GROUP BY

    Building_Name;

    GO

    DROP TABLE #Building_Information;

    DROP TABLE #Device_Information;

    GO

  • you will probably need to split the IP addresses to deal with the third octet reaching double digits. But with the data you supplied this works:

    SELECT B.Building_Name, D.Device_cnt

    FROM Building_Information AS B

    LEFT JOIN (SELECT LEFT(IP_Address,9) AS Subnet, COUNT(DeviceNum) AS Device_cnt

    FROM Device_Information

    GROUP BY LEFT(IP_Address,9)) AS D

    ON LEFT(B.Subnet,9) = D.Subnet

  • Thank you all for your help. I think I will try going the route that Lynn suggested and possibly try to import the table from my second database into my first as to eliminate that issue.

    Thank you all.

  • Here's an alternative using PARSENAME()

    SELECT

    bi.Building_Name,

    COUNT(di.DeviceNum) NumberOfDevices

    FROM #Building_Information bi

    INNER JOIN #Device_Information di

    ON PARSENAME(bi.Subnet,4) = PARSENAME(di.IP_Address,4)

    AND PARSENAME(bi.Subnet,3) = PARSENAME(di.IP_Address,3)

    AND PARSENAME(bi.Subnet,2) = PARSENAME(di.IP_Address,2)

    GROUP BY Building_Name;

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • ChrisM@Work (8/14/2012)


    Here's an alternative using PARSENAME()

    SELECT

    bi.Building_Name,

    COUNT(di.DeviceNum) NumberOfDevices

    FROM #Building_Information bi

    INNER JOIN #Device_Information di

    ON PARSENAME(bi.Subnet,4) = PARSENAME(di.IP_Address,4)

    AND PARSENAME(bi.Subnet,3) = PARSENAME(di.IP_Address,3)

    AND PARSENAME(bi.Subnet,2) = PARSENAME(di.IP_Address,2)

    GROUP BY Building_Name;

    Only issue with using parsename() is that it is slow and will disallow the use of indexes on the joining columns if they exist.

  • Lynn Pettis (8/14/2012)


    ChrisM@Work (8/14/2012)


    Here's an alternative using PARSENAME()

    SELECT

    bi.Building_Name,

    COUNT(di.DeviceNum) NumberOfDevices

    FROM #Building_Information bi

    INNER JOIN #Device_Information di

    ON PARSENAME(bi.Subnet,4) = PARSENAME(di.IP_Address,4)

    AND PARSENAME(bi.Subnet,3) = PARSENAME(di.IP_Address,3)

    AND PARSENAME(bi.Subnet,2) = PARSENAME(di.IP_Address,2)

    GROUP BY Building_Name;

    Only issue with using parsename() is that it is slow and will disallow the use of indexes on the joining columns if they exist.

    Absolutely. Your alternative, using LIKE with a wildcard to the right of the test string, is SARGable. Thanks for the reminder, Lynn.

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • I think we are missing a key aspect of what the OP is asking. This is closer to an SSRS question, I believe. There are 2 datasets in his report; 1 to provide the selected buildings as a drop-down list and another to provide the data based on the selection. Then, in SSRS you can allow "multiple selection" in the drop-down (report parameter). Check this out if you are trying to understand the multi-value parameter in SSRS:

    http://social.msdn.microsoft.com/Forums/en-US/sqlreportingservices/thread/c02370b5-aeda-47ec-a3a8-43b2ec1e6c26/

    Jared
    CE - Microsoft

  • SQLKnowItAll (8/14/2012)


    I think we are missing a key aspect of what the OP is asking. This is closer to an SSRS question, I believe. There are 2 datasets in his report; 1 to provide the selected buildings as a drop-down list and another to provide the data based on the selection. Then, in SSRS you can allow "multiple selection" in the drop-down (report parameter). Check this out if you are trying to understand the multi-value parameter in SSRS:

    http://social.msdn.microsoft.com/Forums/en-US/sqlreportingservices/thread/c02370b5-aeda-47ec-a3a8-43b2ec1e6c26/

    Here is what I think is pertinent question:

    What I am trying to achieve is a report by Building of the total number of devices in each Building.

    And I think that this query (excluding all setup and tear down SQL code) answers that question:

    SELECT

    bi.Building_Name, -- Building

    COUNT(di.DeviceNum) NumberOfDevices -- Number of devices in the building

    FROM

    #Building_Information bi

    INNER JOIN #Device_Information di

    ON (di.IP_Address LIKE bi.Subnet)

    GROUP BY

    Building_Name;

  • I think Jared is right. The whole thing boils down to incorrect formation of @Subnet parameter. That is why asked what is in it. If it's like below, you will get the "invalid syntax" error:

    SELECT count(IP_Address)

    FROM #Device_Information

    WHERE (IP_Address LIKE ('192.168.1.%','192.168.2.%'))

    --Vadim R.

  • rVadim (8/14/2012)


    I think Jared is right. The whole thing boils down to incorrect formation of @Subnet parameter. That is why asked what is in it. If it's like below, you will get the "invalid syntax" error:

    SELECT count(IP_Address)

    FROM #Device_Information

    WHERE (IP_Address LIKE ('192.168.1.%','192.168.2.%'))

    Again, the pertinent part of the OP's question:

    What I am trying to achieve is a report by Building of the total number of devices in each Building.

    I read this to mean that I need a query that will return the number of devices by building.

    Does this not do that?

    SELECT

    bi.Building_Name, -- Building

    COUNT(di.DeviceNum) NumberOfDevices -- Number of devices in the building

    FROM

    #Building_Information bi

    INNER JOIN #Device_Information di

    ON (di.IP_Address LIKE bi.Subnet)

    GROUP BY

    Building_Name;

  • Lynn Pettis (8/14/2012)


    rVadim (8/14/2012)


    I think Jared is right. The whole thing boils down to incorrect formation of @Subnet parameter. That is why asked what is in it. If it's like below, you will get the "invalid syntax" error:

    SELECT count(IP_Address)

    FROM #Device_Information

    WHERE (IP_Address LIKE ('192.168.1.%','192.168.2.%'))

    Again, the pertinent part of the OP's question:

    What I am trying to achieve is a report by Building of the total number of devices in each Building.

    I read this to mean that I need a query that will return the number of devices by building.

    Does this not do that?

    SELECT

    bi.Building_Name, -- Building

    COUNT(di.DeviceNum) NumberOfDevices -- Number of devices in the building

    FROM

    #Building_Information bi

    INNER JOIN #Device_Information di

    ON (di.IP_Address LIKE bi.Subnet)

    GROUP BY

    Building_Name;

    +1

    ----------------------------------------------------------------------------------
    Your lack of planning does not constitute an emergency on my part...unless you're my manager...or a director and above...or a really loud-spoken end-user..All right - what was my emergency again?

  • Matt Miller (#4) (8/15/2012)


    Lynn Pettis (8/14/2012)


    rVadim (8/14/2012)


    I think Jared is right. The whole thing boils down to incorrect formation of @Subnet parameter. That is why asked what is in it. If it's like below, you will get the "invalid syntax" error:

    SELECT count(IP_Address)

    FROM #Device_Information

    WHERE (IP_Address LIKE ('192.168.1.%','192.168.2.%'))

    Again, the pertinent part of the OP's question:

    What I am trying to achieve is a report by Building of the total number of devices in each Building.

    I read this to mean that I need a query that will return the number of devices by building.

    Does this not do that?

    SELECT

    bi.Building_Name, -- Building

    COUNT(di.DeviceNum) NumberOfDevices -- Number of devices in the building

    FROM

    #Building_Information bi

    INNER JOIN #Device_Information di

    ON (di.IP_Address LIKE bi.Subnet)

    GROUP BY

    Building_Name;

    +1

    Ok, we can argue this all day. You showed him a better way of getting the data set. I showed him how to understand reporting services. 2 birds.

    Lynn, even though I agree that your query is better structured...the issue was

    However, on the multiple value pass it gives an error because of the like statement (Incorrect syntax ","). When I try to substitute the LIKE for IN, it will only match the value if it is an exact match.

    Passing multiple-values parameters in the report itself will still cause the error and does not solve the problem which is solved by understanding how SSRS handles a multi-value pass to the parameter. If the OP still wants a report where the user can select 1, 2, 3, 4, etc. buildings and should only receive a report based on those choices, the supplied query does not change that. The multi-value pass still needed to be modified.

    Jared
    CE - Microsoft

Viewing 15 posts - 1 through 15 (of 19 total)

You must be logged in to reply to this topic. Login to reply