Skip to content

Commit 0b2c068

Browse files
committed
Add Temporal Table Maker script
1 parent 10166c6 commit 0b2c068

File tree

1 file changed

+157
-0
lines changed

1 file changed

+157
-0
lines changed

Scripts/Temporal_Table_Maker.sql

Lines changed: 157 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,157 @@
1+
/*
2+
Author: Bill Fellows
3+
Original link: http://billfellows.blogspot.ru/2017/10/temporal-table-maker.html
4+
*/
5+
6+
DECLARE
7+
@query nvarchar(4000)
8+
, @targetSchema sysname = 'dbo_HISTORY'
9+
, @tableName sysname
10+
, @targetFileGroup sysname = 'History';
11+
12+
DECLARE
13+
CSR CURSOR
14+
FAST_FORWARD
15+
FOR
16+
SELECT ALL
17+
CONCAT(
18+
'SELECT * FROM '
19+
, S.name
20+
, '.'
21+
, T.name)
22+
, T.name
23+
FROM
24+
sys.schemas AS S
25+
INNER JOIN sys.tables AS T
26+
ON T.schema_id = S.schema_id
27+
WHERE
28+
1=1
29+
AND S.name = 'dbo'
30+
AND T.name NOT IN
31+
(SELECT TI.name FROM sys.schemas AS SI INNER JOIN sys.tables AS TI ON TI.schema_id = SI.schema_id WHERE SI.name = @targetSchema);
32+
33+
OPEN CSR;
34+
FETCH NEXT FROM CSR INTO @query, @tableName;
35+
WHILE @@FETCH_STATUS = 0
36+
BEGIN
37+
-- do something
38+
SELECT
39+
CONCAT
40+
(
41+
'CREATE TABLE '
42+
, @targetSchema
43+
, '.'
44+
, @tableName
45+
, '('
46+
, STUFF
47+
(
48+
(
49+
SELECT
50+
CONCAT
51+
(
52+
','
53+
, DEDFRS.name
54+
, ' '
55+
, DEDFRS.system_type_name
56+
, ' '
57+
, CASE DEDFRS.is_nullable
58+
WHEN 1 THEN ''
59+
ELSE 'NOT '
60+
END
61+
, 'NULL'
62+
)
63+
FROM
64+
sys.dm_exec_describe_first_result_set(@query, N'', 1) AS DEDFRS
65+
ORDER BY
66+
DEDFRS.column_ordinal
67+
FOR XML PATH('')
68+
)
69+
, 1
70+
, 1
71+
, ''
72+
)
73+
, ', SysStartTime datetime2(7) NOT NULL'
74+
, ', SysEndTime datetime2(7) NOT NULL'
75+
, ')'
76+
, ' ON '
77+
, @targetFileGroup
78+
, ';'
79+
, CHAR(13)
80+
, 'CREATE CLUSTERED COLUMNSTORE INDEX CCI_'
81+
, @targetSchema
82+
, '_'
83+
, @tableName
84+
, ' ON '
85+
, @targetSchema
86+
, '.'
87+
, @tableName
88+
, ' ON '
89+
, @targetFileGroup
90+
, ';'
91+
, CHAR(13)
92+
, 'CREATE NONCLUSTERED INDEX IX_'
93+
, @targetSchema
94+
, '_'
95+
, @tableName
96+
, '_PERIOD_COLUMNS '
97+
, ' ON '
98+
, @targetSchema
99+
, '.'
100+
, @tableName
101+
102+
, '('
103+
, 'SysEndTime'
104+
, ',SysStartTime'
105+
, (
106+
SELECT
107+
CONCAT
108+
(
109+
','
110+
, DEDFRS.name
111+
)
112+
FROM
113+
sys.dm_exec_describe_first_result_set(@query, N'', 1) AS DEDFRS
114+
WHERE
115+
DEDFRS.is_part_of_unique_key = 1
116+
ORDER BY
117+
DEDFRS.column_ordinal
118+
FOR XML PATH('')
119+
)
120+
, ')'
121+
, ' ON '
122+
, @targetFileGroup
123+
, ';'
124+
, CHAR(13)
125+
, 'ALTER TABLE '
126+
, 'dbo'
127+
, '.'
128+
, @tableName
129+
, ' ADD '
130+
, 'SysStartTime datetime2(7) GENERATED ALWAYS AS ROW START HIDDEN'
131+
, ' CONSTRAINT DF_'
132+
, 'dbo_'
133+
, @tableName
134+
, '_SysStartTime DEFAULT SYSUTCDATETIME()'
135+
, ', SysEndTime datetime2(7) GENERATED ALWAYS AS ROW END HIDDEN'
136+
, ' CONSTRAINT DF_'
137+
, 'dbo_'
138+
, @tableName
139+
, '_SysEndTime DEFAULT DATETIME2FROMPARTS(9999, 12, 31, 23,59, 59,9999999,7)'
140+
, ', PERIOD FOR SYSTEM_TIME (SysStartTime, SysEndTime);'
141+
, CHAR(13)
142+
, 'ALTER TABLE '
143+
, 'dbo'
144+
, '.'
145+
, @tableName
146+
, ' SET (SYSTEM_VERSIONING = ON (HISTORY_TABLE = '
147+
, @targetSchema
148+
, '.'
149+
, @tableName
150+
, '));'
151+
152+
);
153+
154+
FETCH NEXT FROM CSR INTO @query, @tableName;
155+
END
156+
CLOSE CSR;
157+
DEALLOCATE CSR;

0 commit comments

Comments
 (0)