Skip to content

Commit e1e7d07

Browse files
authored
Add files via upload
1 parent c49faf2 commit e1e7d07

File tree

1 file changed

+63
-0
lines changed

1 file changed

+63
-0
lines changed

SSDB.Primary_Keys_List.sql

Lines changed: 63 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,63 @@
1+
WITH
2+
column_names -- listing of all the columns used in the primary key
3+
AS
4+
(
5+
SELECT
6+
kc.object_id
7+
, kc.parent_object_id
8+
, PrimaryKeyName = QUOTENAME(OBJECT_NAME(kc.object_id))
9+
, SchemaName = QUOTENAME(OBJECT_SCHEMA_NAME(kc.parent_object_id))
10+
, TableName = QUOTENAME(OBJECT_NAME(kc.parent_object_id))
11+
, ColumnName = COL_NAME(ob.object_id, ic.column_id)
12+
, ic.key_ordinal
13+
, key_number = CAST(kc.parent_object_id AS VARCHAR) + CAST(ic.key_ordinal AS VARCHAR)
14+
, parent_number = CAST(kc.parent_object_id AS VARCHAR) + CAST(ic.key_ordinal - 1 AS VARCHAR)
15+
, descending_key = CASE ic.is_descending_key WHEN 0 THEN 'ASC' ELSE 'DESC' END
16+
, clustered_desc = CASE INDEXPROPERTY(kc.parent_object_id, OBJECT_NAME(kc.object_id),'IsClustered') WHEN 1 THEN 'CLUSTERED' ELSE 'NONCLUSTERED' END
17+
FROM
18+
sys.key_constraints kc
19+
INNER JOIN sys.objects ob on kc.parent_object_id = ob.object_id
20+
INNER JOIN sys.indexes AS I ON KC.unique_index_id = I.index_id AND KC.parent_object_id = I.object_id
21+
INNER JOIN sys.index_columns ic ON I.object_id = IC.object_id AND I.index_id = IC.index_id
22+
WHERE
23+
kc.type = 'PK'
24+
AND ob.type = 'U'
25+
AND ob.name not in ('dtproperties','sysdiagrams') -- not true user tables
26+
--AND COL_NAME(ob.object_id, ic.column_id) = N'$(targetColumn)'
27+
)
28+
,
29+
max_key_ordinal --get the max ordinal number for complete list of columns
30+
AS
31+
(
32+
SELECT
33+
object_id
34+
, parent_object_id
35+
, max_ordinal_value = MAX(key_ordinal)
36+
FROM column_names
37+
GROUP BY
38+
object_id
39+
, parent_object_id
40+
)
41+
,
42+
primary_key_columns(object_id, parent_object_id, PrimaryKeyName, ColumnNames, SchemaName, TableName, key_ordinal, key_number, clustered_desc) -- recursive query to get all the columns in a comma separated list
43+
AS
44+
(
45+
SELECT pt.object_id, pt.parent_object_id, pt.PrimaryKeyName, ColumnNames = CAST(pt.ColumnName + ' ' + pt.descending_key AS VARCHAR(MAX)), pt.SchemaName, pt.TableName, pt.key_ordinal, pt.key_number, pt.clustered_desc
46+
FROM column_names pt
47+
INNER JOIN column_names ch ON pt.key_number = ch.key_number
48+
WHERE pt.key_ordinal = 1 -- parent record
49+
UNION ALL
50+
SELECT pt.object_id, pt.parent_object_id, pt.PrimaryKeyName, CAST(ch.ColumnNames + ', ' + pt.ColumnName + ' ' + pt.descending_key AS VARCHAR(MAX)), pt.SchemaName, pt.TableName, pt.key_ordinal, pt.key_number, pt.clustered_desc
51+
FROM column_names pt
52+
INNER JOIN primary_key_columns ch ON pt.parent_number = ch.key_number --recursive part
53+
WHERE pt.key_ordinal != 1 -- child record
54+
)
55+
SELECT
56+
pk.PrimaryKeyName
57+
, pk.SchemaName
58+
, pk.TableName
59+
, 'create_primary_key' = 'ALTER TABLE ' + pk.SchemaName + '.' + pk.TableName + ' ADD CONSTRAINT ' + pk.PrimaryKeyName + ' PRIMARY KEY ' + clustered_desc + ' (' + pk.ColumnNames + ') '
60+
, 'drop_primary_key' = 'ALTER TABLE ' + pk.SchemaName + '.' + pk.TableName + ' DROP CONSTRAINT ' + pk.PrimaryKeyName
61+
FROM
62+
primary_key_columns pk
63+
INNER JOIN max_key_ordinal mv ON mv.object_id = pk.object_id AND mv.parent_object_id = pk.parent_object_id AND mv.max_ordinal_value = pk.key_ordinal

0 commit comments

Comments
 (0)