forked from DavidWiseman/sqlserver-kit
-
Notifications
You must be signed in to change notification settings - Fork 0
/
FindTablesWithSimilarTableStructure.sql
62 lines (61 loc) · 2.27 KB
/
FindTablesWithSimilarTableStructure.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
/*
Author: Jana Sattainathan
Original link: https://sqljana.wordpress.com/2017/03/31/sql-server-find-tables-with-similar-table-structure
*/
WITH ColCountsByTable
AS
(
SELECT
c.TABLE_CATALOG,
c.TABLE_SCHEMA,
c.TABLE_NAME,
COUNT(1) AS Column_Count
FROM INFORMATION_SCHEMA.COLUMNS c
/*
--Plug in the schema and table name to get similar views/tables just for one or more tables
WHERE
c.TABLE_SCHEMA = 'TransactionPreProcessing'
AND c.TABLE_NAME IN ('PreStagingTransaction')
*/
GROUP BY
c.TABLE_CATALOG,
c.TABLE_SCHEMA,
c.TABLE_NAME
)
SELECT
100 * COUNT(c2.COLUMN_NAME) /*Matching_Column_Count*/ / MIN(ColCountsByTable.Column_Count) /*Column_Count*/ AS Match_Percent,
c.TABLE_CATALOG,
c.TABLE_SCHEMA,
c.TABLE_NAME,
DENSE_RANK() OVER(ORDER BY c.TABLE_CATALOG, c.TABLE_SCHEMA, c.TABLE_NAME) Table_Rank,
MIN(ColCountsByTable.Column_Count) AS Column_Count,
c2.TABLE_CATALOG AS Matching_Catalog,
c2.TABLE_SCHEMA AS Matching_Schema,
c2.TABLE_NAME AS Matching_Table,
COUNT(c2.COLUMN_NAME) AS Matching_Column_Count
FROM INFORMATION_SCHEMA.TABLES t
INNER JOIN INFORMATION_SCHEMA.COLUMNS c
ON t.TABLE_CATALOG = c.TABLE_CATALOG
AND t.TABLE_SCHEMA = c.TABLE_SCHEMA
AND t.TABLE_NAME = c.TABLE_NAME
INNER JOIN ColCountsByTable
ON t.TABLE_CATALOG = ColCountsByTable.TABLE_CATALOG
AND t.TABLE_SCHEMA = ColCountsByTable.TABLE_SCHEMA
AND t.TABLE_NAME = ColCountsByTable.TABLE_NAME
LEFT OUTER JOIN INFORMATION_SCHEMA.COLUMNS c2
ON t.TABLE_NAME != c2.TABLE_NAME
AND c.COLUMN_NAME = c2.COLUMN_NAME
GROUP BY
c.TABLE_CATALOG,
c.TABLE_SCHEMA,
c.TABLE_NAME,
c2.TABLE_CATALOG,
c2.TABLE_SCHEMA,
c2.TABLE_NAME
--Use the below HAVING clause if you want to restrict results to only matches above a certain percent
--HAVING
-- /*Match_Percent*/
-- (100 * COUNT(c2.COLUMN_NAME) /*Matching_Column_Count*/) / MIN(ColCountsByTable.Column_Count) /*Column_Count*/
-- >= 50 --Require atleast 50% of the columns to match
ORDER BY
Match_Percent DESC