forked from ktaranov/sqlserver-kit
-
Notifications
You must be signed in to change notification settings - Fork 14
/
Copy pathTemporal_Table_Maker.sql
157 lines (151 loc) · 3.78 KB
/
Temporal_Table_Maker.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
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
/*
Author: Bill Fellows
Original link: http://billfellows.blogspot.ru/2017/10/temporal-table-maker.html
*/
DECLARE
@query nvarchar(4000)
, @targetSchema sysname = 'dbo_HISTORY'
, @tableName sysname
, @targetFileGroup sysname = 'History';
DECLARE
CSR CURSOR
FAST_FORWARD
FOR
SELECT ALL
CONCAT(
'SELECT * FROM '
, S.name
, '.'
, T.name)
, T.name
FROM
sys.schemas AS S
INNER JOIN sys.tables AS T
ON T.schema_id = S.schema_id
WHERE
1=1
AND S.name = 'dbo'
AND T.name NOT IN
(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);
OPEN CSR;
FETCH NEXT FROM CSR INTO @query, @tableName;
WHILE @@FETCH_STATUS = 0
BEGIN
-- do something
SELECT
CONCAT
(
'CREATE TABLE '
, @targetSchema
, '.'
, @tableName
, '('
, STUFF
(
(
SELECT
CONCAT
(
','
, DEDFRS.name
, ' '
, DEDFRS.system_type_name
, ' '
, CASE DEDFRS.is_nullable
WHEN 1 THEN ''
ELSE 'NOT '
END
, 'NULL'
)
FROM
sys.dm_exec_describe_first_result_set(@query, N'', 1) AS DEDFRS
ORDER BY
DEDFRS.column_ordinal
FOR XML PATH('')
)
, 1
, 1
, ''
)
, ', SysStartTime datetime2(7) NOT NULL'
, ', SysEndTime datetime2(7) NOT NULL'
, ')'
, ' ON '
, @targetFileGroup
, ';'
, CHAR(13)
, 'CREATE CLUSTERED COLUMNSTORE INDEX CCI_'
, @targetSchema
, '_'
, @tableName
, ' ON '
, @targetSchema
, '.'
, @tableName
, ' ON '
, @targetFileGroup
, ';'
, CHAR(13)
, 'CREATE NONCLUSTERED INDEX IX_'
, @targetSchema
, '_'
, @tableName
, '_PERIOD_COLUMNS '
, ' ON '
, @targetSchema
, '.'
, @tableName
, '('
, 'SysEndTime'
, ',SysStartTime'
, (
SELECT
CONCAT
(
','
, DEDFRS.name
)
FROM
sys.dm_exec_describe_first_result_set(@query, N'', 1) AS DEDFRS
WHERE
DEDFRS.is_part_of_unique_key = 1
ORDER BY
DEDFRS.column_ordinal
FOR XML PATH('')
)
, ')'
, ' ON '
, @targetFileGroup
, ';'
, CHAR(13)
, 'ALTER TABLE '
, 'dbo'
, '.'
, @tableName
, ' ADD '
, 'SysStartTime datetime2(7) GENERATED ALWAYS AS ROW START HIDDEN'
, ' CONSTRAINT DF_'
, 'dbo_'
, @tableName
, '_SysStartTime DEFAULT SYSUTCDATETIME()'
, ', SysEndTime datetime2(7) GENERATED ALWAYS AS ROW END HIDDEN'
, ' CONSTRAINT DF_'
, 'dbo_'
, @tableName
, '_SysEndTime DEFAULT DATETIME2FROMPARTS(9999, 12, 31, 23,59, 59,9999999,7)'
, ', PERIOD FOR SYSTEM_TIME (SysStartTime, SysEndTime);'
, CHAR(13)
, 'ALTER TABLE '
, 'dbo'
, '.'
, @tableName
, ' SET (SYSTEM_VERSIONING = ON (HISTORY_TABLE = '
, @targetSchema
, '.'
, @tableName
, '));'
);
FETCH NEXT FROM CSR INTO @query, @tableName;
END
CLOSE CSR;
DEALLOCATE CSR;