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

compare all tables and find number of common columns between all tables Expand / Collapse
Author
Message
Posted Wednesday, June 19, 2013 10:05 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, December 16, 2014 4:59 PM
Points: 27, Visits: 256
is there any way to compare every table with each other in a database list the number of common column between each tables!! ?? prefer using join over subquery and information_schema.column, if possible thx.
example: lets say there are 4 tables in a database table1, table2, table3 and table4.
list1 list2 commonColumns
----- -------- --------------------
table1 table2 1
table1 table3 2
table1 table4 0
table2 table1 1
table2 table3 5
table2 table4 2
table3 table1 3
table3 table2 0
table3 table4 1
table4 table1 2
table4 table2 3
table4 table3 0

this is what i have got so far

select c1.table_name,c2.table_name,c1.COLUMN_NAME
from information_schema.columns c1
JOIN information_schema.columns c2
ON c1.column_name= c2.column_name
where c2.table_name <> c1.table_name
and c2.column_name = c1.column_name
ORDER BY c1.table_name, c2.TABLE_NAME
Post #1465450
Posted Thursday, June 20, 2013 2:23 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 1:40 PM
Points: 1,683, Visits: 19,609

SELECT t1.name AS list1,
t2.name AS list2,
count(distinct c2.name) AS commonColumns
FROM sys.tables t1
CROSS JOIN sys.tables t2
INNER JOIN sys.columns c1 ON c1.object_id = t1.object_id
LEFT OUTER JOIN sys.columns c2 ON c2.object_id = t2.object_id AND c1.name=c2.name
GROUP BY t1.name,t2.name
ORDER BY t1.name,t2.name



____________________________________________________

How to get the best help on a forum

http://www.sqlservercentral.com/articles/Best+Practices/61537

Never approach a goat from the front, a horse from the rear, or a fool from any direction.
Post #1465508
Posted Thursday, June 20, 2013 10:09 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, December 16, 2014 4:59 PM
Points: 27, Visits: 256
thank you for your effort but I get an error when I run the query

Msg 245, Level 16, State 1, Line 1
Conversion failed when converting the nvarchar value ' Enrollments' to data type int.

how do I fix this conversion error?

Post #1465812
Posted Thursday, June 20, 2013 10:17 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 2:05 PM
Points: 13,327, Visits: 12,820
sqlsean (6/20/2013)
thank you for your effort but I get an error when I run the query

Msg 245, Level 16, State 1, Line 1
Conversion failed when converting the nvarchar value ' Enrollments' to data type int.

how do I fix this conversion error?



Actually Mark did a remarkable job posting a query with absolutely nothing to work with.

In order to help we will need a few things:

1. Sample DDL in the form of CREATE TABLE statements
2. Sample data in the form of INSERT INTO statements
3. Expected results based on the sample data

Please take a few minutes and read the first article in my signature for best practices when posting questions.


_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1465821
Posted Thursday, June 20, 2013 10:39 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, December 16, 2014 4:59 PM
Points: 27, Visits: 256
sorry mark let me correct myself your query works jus fine and yes indeed it is a remarkable job for the information that I have provided. since you have already provided a working query let not bother about sample data.
however, when I try to get only records that has "commoncolumns" with value more than 1, then I get that conversion error.
how can I get through this? thank you again.

Post #1465838
Posted Thursday, June 20, 2013 10:46 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 2:05 PM
Points: 13,327, Visits: 12,820
sqlsean (6/20/2013)
sorry mark let me correct myself your query works jus fine and yes indeed it is a remarkable job for the information that I have provided. since you have already provided a working query let not bother about sample data.
however, when I try to get only records that has "commoncolumns" with value more than 1, then I get that conversion error.
how can I get through this? thank you again.



I only sort of looked at the post...given that we are dealing with common tables I agree that sample data would be rather silly in this case.

Can you simply add a having clause? This works for me at least.

SELECT t1.name AS list1,
t2.name AS list2,
count(distinct c2.name) AS commonColumns
FROM sys.tables t1
CROSS JOIN sys.tables t2
INNER JOIN sys.columns c1 ON c1.object_id = t1.object_id
LEFT OUTER JOIN sys.columns c2 ON c2.object_id = t2.object_id AND c1.name=c2.name
GROUP BY t1.name,t2.name
having count(distinct c2.name) > 1
ORDER BY t1.name,t2.name



_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1465844
Posted Thursday, June 20, 2013 12:16 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, December 16, 2014 4:59 PM
Points: 27, Visits: 256
thank you sean, it worked.
Post #1465885
Posted Thursday, June 20, 2013 12:17 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 2:05 PM
Points: 13,327, Visits: 12,820
sqlsean (6/20/2013)
thank you sean, it worked.


You're welcome sqlme.

Again my apologies for not reading the whole issue previously.


_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1465887
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse