Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

Querying Data From One Table Against Another Table For All Results Expand / Collapse
Author
Message
Posted Monday, August 13, 2012 3:03 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, August 14, 2012 6:31 AM
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.
Post #1344441
Posted Monday, August 13, 2012 3:44 PM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Yesterday @ 11:03 AM
Points: 2,901, Visits: 2,925
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,
SQL Server developer at Seavus
www.seavus.com
Post #1344459
Posted Monday, August 13, 2012 3:56 PM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Thursday, July 3, 2014 9:59 AM
Points: 990, Visits: 2,217
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?
Post #1344463
Posted Monday, August 13, 2012 4:11 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 8:42 PM
Points: 23,009, Visits: 31,510
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





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)
Post #1344472
Posted Monday, August 13, 2012 4:16 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Friday, April 11, 2014 3:04 PM
Points: 2,127, Visits: 747
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



Post #1344475
Posted Tuesday, August 14, 2012 6:43 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, August 14, 2012 6:31 AM
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.
Post #1344663
Posted Tuesday, August 14, 2012 6:57 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 9:56 AM
Points: 7,120, Visits: 13,491
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
Post #1344680
Posted Tuesday, August 14, 2012 8:12 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 8:42 PM
Points: 23,009, Visits: 31,510
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

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)
Post #1344740
Posted Tuesday, August 14, 2012 8:17 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 9:56 AM
Points: 7,120, Visits: 13,491
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
Post #1344746
Posted Tuesday, August 14, 2012 8:35 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 1:50 PM
Points: 2,691, Visits: 3,374
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
Post #1344759
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse