Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Querying Data From One Table Against Another Table For All Results


Querying Data From One Table Against Another Table For All Results

Author
Message
michaelhamptonwork
michaelhamptonwork
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
Points: 2 Visits: 2
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.
Igor Micev
Igor Micev
SSCarpal Tunnel
SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)

Group: General Forum Members
Points: 4158 Visits: 4843
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.
Smile


Igor Micev,SQL Server developer at Seavuswww.seavus.com
rVadim
rVadim
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1054 Visits: 2299
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?
Lynn Pettis
Lynn Pettis
SSC-Insane
SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)

Group: General Forum Members
Points: 24155 Visits: 37923
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




Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
andersg98
andersg98
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2136 Visits: 774
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



michaelhamptonwork
michaelhamptonwork
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
Points: 2 Visits: 2
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.
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)

Group: General Forum Members
Points: 8923 Visits: 19009
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
Exploring Recursive CTEs by Example Dwain Camps
Lynn Pettis
Lynn Pettis
SSC-Insane
SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)

Group: General Forum Members
Points: 24155 Visits: 37923
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.

Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)

Group: General Forum Members
Points: 8923 Visits: 19009
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
Exploring Recursive CTEs by Example Dwain Camps
SQLKnowItAll
SQLKnowItAll
SSCrazy
SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)

Group: General Forum Members
Points: 2796 Visits: 3681
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/

Thanks,

Jared
SQL Know-It-All

How to post data/code on a forum to get the best help - Jeff Moden
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search