-
Notifications
You must be signed in to change notification settings - Fork 564
/
Copy pathsqlserver_specific_schema.rb
371 lines (326 loc) · 13.8 KB
/
sqlserver_specific_schema.rb
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
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
# frozen_string_literal: true
ActiveRecord::Schema.define do
# Exhaustive Data Types
execute File.read(ARTest::SQLServer.schema_datatypes_2012_file)
create_table :sst_datatypes_migration, force: true do |t|
# Simple Rails conventions.
t.integer :integer_col
t.bigint :bigint_col
t.boolean :boolean_col
t.decimal :decimal_col
t.float :float_col
t.string :string_col
t.text :text_col
t.datetime :datetime_nil_precision_col, precision: nil
t.datetime :datetime_col # Precision defaults to 6
t.timestamp :timestamp_col # Precision defaults to 6
t.time :time_col
t.date :date_col
t.binary :binary_col
# Our type methods.
t.real :real_col
t.money :money_col
t.smalldatetime :smalldatetime_col
t.datetime2 :datetime2_col
t.datetimeoffset :datetimeoffset
t.smallmoney :smallmoney_col
t.char :char_col
t.varchar :varchar_col
t.text_basic :text_basic_col
t.nchar :nchar_col
t.ntext :ntext_col
t.binary_basic :binary_basic_col
t.binary_basic :binary_basic_16_col, limit: 16
t.varbinary :varbinary_col
t.uuid :uuid_col
t.ss_timestamp :sstimestamp_col
if supports_json?
t.json :json_col
else
t.text :json_col
end
end
# Edge Cases
if ENV["IN_MEMORY_OLTP"] && supports_in_memory_oltp?
create_table "sst_memory", force: true, id: false,
options: "WITH (MEMORY_OPTIMIZED = ON, DURABILITY = SCHEMA_AND_DATA)" do |t|
t.primary_key_nonclustered :id
t.string :name
t.timestamps
end
end
create_table "sst_bookings", force: true do |t|
t.string :name
t.datetime2 :created_at, null: false
t.datetime2 :updated_at, null: false
end
create_table "sst_uuids", force: true, id: :uuid do |t|
t.string :name
t.uuid :other_uuid, default: "NEWID()"
t.uuid :uuid_nil_default, default: nil
end
create_table "sst_my$strange_table", force: true do |t|
t.string :name
end
create_table :SST_UPPER_TESTS, force: true do |t|
t.column :COLUMN1, :string
t.column :COLUMN2, :integer
end
create_table :sst_no_pk_data, force: true, id: false do |t|
t.string :name
end
create_table "sst_quoted-table", force: true do |t|
end
execute "IF EXISTS (SELECT TABLE_NAME FROM INFORMATION_SCHEMA.VIEWS WHERE TABLE_NAME = 'sst_quoted-view1') DROP VIEW [sst_quoted-view1]"
execute "CREATE VIEW [sst_quoted-view1] AS SELECT * FROM [sst_quoted-table]"
execute "IF EXISTS (SELECT TABLE_NAME FROM INFORMATION_SCHEMA.VIEWS WHERE TABLE_NAME = 'sst_quoted-view2') DROP VIEW [sst_quoted-view2]"
execute "CREATE VIEW [sst_quoted-view2] AS \n /*#{'x' * 4000}}*/ \n SELECT * FROM [sst_quoted-table]"
create_table :sst_string_defaults, force: true do |t|
t.column :string_with_null_default, :string, default: nil
t.column :string_with_pretend_null_one, :string, default: "null"
t.column :string_with_pretend_null_two, :string, default: "(null)"
t.column :string_with_pretend_null_three, :string, default: "NULL"
t.column :string_with_pretend_null_four, :string, default: "(NULL)"
t.column :string_with_pretend_paren_three, :string, default: "(3)"
t.column :string_with_multiline_default, :string, default: "Some long default with a\nnew line."
end
create_table :sst_string_collation, collation: :SQL_Latin1_General_CP1_CI_AS, force: true do |t|
t.string :string_without_collation
t.varchar :string_default_collation, collation: :SQL_Latin1_General_CP1_CI_AS
t.varchar :string_with_collation, collation: :SQL_Latin1_General_CP1_CS_AS
t.varchar :varchar_with_collation, collation: :SQL_Latin1_General_CP1_CS_AS
end
create_table :sst_edge_schemas, force: true do |t|
t.string :description
t.column "crazy]]quote", :string
t.column "with spaces", :string
end
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sst_natural_pk_data') DROP TABLE sst_natural_pk_data"
execute <<-NATURALPKTABLESQL
CREATE TABLE sst_natural_pk_data(
parent_id int,
name nvarchar(255),
description nvarchar(1000),
legacy_id nvarchar(10) NOT NULL PRIMARY KEY
)
NATURALPKTABLESQL
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sst_natural_pk_int_data') DROP TABLE sst_natural_pk_int_data"
execute <<-NATURALPKINTTABLESQL
CREATE TABLE sst_natural_pk_int_data(
legacy_id int NOT NULL PRIMARY KEY,
parent_id int,
name nvarchar(255),
description nvarchar(1000)
)
NATURALPKINTTABLESQL
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sst_tinyint_pk') DROP TABLE sst_tinyint_pk"
execute <<-TINYITPKTABLE
CREATE TABLE sst_tinyint_pk(
id tinyint IDENTITY NOT NULL PRIMARY KEY,
name nvarchar(255)
)
TINYITPKTABLE
execute "DROP DEFAULT [sst_getdateobject];" rescue nil
execute "CREATE DEFAULT [sst_getdateobject] AS getdate();" rescue nil
create_table "sst_defaultobjects", force: true do |t|
t.string :name
t.date :date
end
execute "sp_bindefault 'sst_getdateobject', 'sst_defaultobjects.date'"
execute "DROP PROCEDURE my_getutcdate" rescue nil
execute <<-SQL
CREATE PROCEDURE my_getutcdate AS
SELECT GETUTCDATE() utcdate
SQL
create_table 'A Table With Spaces', force: true do |t|
t.string :name
end
# Constraints
create_table(:sst_has_fks, force: true) do |t|
t.column(:fk_id, :bigint, null: false)
t.column(:fk_id2, :bigint)
end
create_table(:sst_has_pks, force: true) {}
execute <<-ADDFKSQL
ALTER TABLE sst_has_fks
ADD CONSTRAINT FK__sst_has_fks_id
FOREIGN KEY ([fk_id])
REFERENCES [sst_has_pks] ([id]),
CONSTRAINT FK__sst_has_fks_id2
FOREIGN KEY ([fk_id2])
REFERENCES [sst_has_pks] ([id])
ADDFKSQL
# Views
execute "IF EXISTS (SELECT TABLE_NAME FROM INFORMATION_SCHEMA.VIEWS WHERE TABLE_NAME = 'sst_customers_view') DROP VIEW sst_customers_view"
execute <<-CUSTOMERSVIEW
CREATE VIEW sst_customers_view AS
SELECT id, name, balance
FROM customers
CUSTOMERSVIEW
execute "IF EXISTS (SELECT TABLE_NAME FROM INFORMATION_SCHEMA.VIEWS WHERE TABLE_NAME = 'sst_string_defaults_view') DROP VIEW sst_string_defaults_view"
execute <<-STRINGDEFAULTSVIEW
CREATE VIEW sst_string_defaults_view AS
SELECT id, string_with_pretend_null_one as pretend_null
FROM sst_string_defaults
STRINGDEFAULTSVIEW
execute "IF EXISTS (SELECT TABLE_NAME FROM INFORMATION_SCHEMA.VIEWS WHERE TABLE_NAME = 'sst_string_defaults_big_view') DROP VIEW sst_string_defaults_big_view"
execute <<-STRINGDEFAULTSBIGVIEW
CREATE VIEW sst_string_defaults_big_view AS
SELECT id, string_with_pretend_null_one as pretend_null
/*#{'x' * 4000}}*/
FROM sst_string_defaults
STRINGDEFAULTSBIGVIEW
# Trigger
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sst_table_with_trigger') DROP TABLE sst_table_with_trigger"
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sst_table_with_trigger_history') DROP TABLE sst_table_with_trigger_history"
execute <<-SQL
CREATE TABLE sst_table_with_trigger(
id bigint IDENTITY NOT NULL PRIMARY KEY,
event_name nvarchar(255)
)
CREATE TABLE sst_table_with_trigger_history(
id bigint IDENTITY NOT NULL PRIMARY KEY,
id_source nvarchar(36),
event_name nvarchar(255)
)
SQL
execute <<-SQL
CREATE TRIGGER sst_table_with_trigger_t ON sst_table_with_trigger
FOR INSERT
AS
INSERT INTO sst_table_with_trigger_history (id_source, event_name)
SELECT id AS id_source, event_name FROM INSERTED
SQL
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sst_table_with_uuid_trigger') DROP TABLE sst_table_with_uuid_trigger"
execute <<-SQL
CREATE TABLE sst_table_with_uuid_trigger(
id uniqueidentifier DEFAULT NEWID() PRIMARY KEY,
event_name nvarchar(255)
)
SQL
execute <<-SQL
CREATE TRIGGER sst_table_with_uuid_trigger_t ON sst_table_with_uuid_trigger
FOR INSERT
AS
INSERT INTO sst_table_with_trigger_history (id_source, event_name)
SELECT id AS id_source, event_name FROM INSERTED
SQL
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sst_table_with_composite_pk_trigger') DROP TABLE sst_table_with_composite_pk_trigger"
execute <<-SQL
CREATE TABLE sst_table_with_composite_pk_trigger(
pk_col_one int NOT NULL,
pk_col_two int NOT NULL,
event_name nvarchar(255),
CONSTRAINT PK_sst_table_with_composite_pk_trigger PRIMARY KEY (pk_col_one, pk_col_two)
)
SQL
execute <<-SQL
CREATE TRIGGER sst_table_with_composite_pk_trigger_t ON sst_table_with_composite_pk_trigger
FOR INSERT
AS
INSERT INTO sst_table_with_trigger_history (id_source, event_name)
SELECT pk_col_one AS id_source, event_name FROM INSERTED
SQL
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sst_table_with_composite_pk_trigger_with_different_data_type') DROP TABLE sst_table_with_composite_pk_trigger_with_different_data_type"
execute <<-SQL
CREATE TABLE sst_table_with_composite_pk_trigger_with_different_data_type(
pk_col_one uniqueidentifier DEFAULT NEWID(),
pk_col_two int NOT NULL,
event_name nvarchar(255),
CONSTRAINT PK_sst_table_with_composite_pk_trigger_with_different_data_type PRIMARY KEY (pk_col_one, pk_col_two)
)
SQL
execute <<-SQL
CREATE TRIGGER sst_table_with_composite_pk_trigger_with_different_data_type_t ON sst_table_with_composite_pk_trigger_with_different_data_type
FOR INSERT
AS
INSERT INTO sst_table_with_trigger_history (id_source, event_name)
SELECT pk_col_one AS id_source, event_name FROM INSERTED
SQL
# Another schema.
create_table :sst_schema_columns, force: true do |t|
t.column :field1, :integer
end
execute "IF NOT EXISTS(SELECT * FROM sys.schemas WHERE name = 'test') EXEC sp_executesql N'CREATE SCHEMA test'"
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sst_schema_columns' and TABLE_SCHEMA = 'test') DROP TABLE test.sst_schema_columns"
execute <<-SIMILIARTABLEINOTHERSCHEMA
CREATE TABLE test.sst_schema_columns(
id int IDENTITY NOT NULL primary key,
filed_1 int,
field_2 int,
name varchar(255),
description varchar(1000),
n_name nvarchar(255),
n_description nvarchar(1000)
)
SIMILIARTABLEINOTHERSCHEMA
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sst_schema_identity' and TABLE_SCHEMA = 'test') DROP TABLE test.sst_schema_identity"
execute <<-SIMILIARTABLEINOTHERSCHEMA
CREATE TABLE test.sst_schema_identity(
id int IDENTITY NOT NULL primary key,
filed_1 int
)
SIMILIARTABLEINOTHERSCHEMA
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sst_schema_natural_id' and TABLE_SCHEMA = 'test') DROP TABLE test.sst_schema_natural_id"
execute <<-NATURALPKTABLESQLINOTHERSCHEMA
CREATE TABLE test.sst_schema_natural_id(
parent_id int,
name nvarchar(255),
description nvarchar(1000),
legacy_id nvarchar(10) NOT NULL PRIMARY KEY,
)
NATURALPKTABLESQLINOTHERSCHEMA
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sst_schema_test_multiple_schema' and TABLE_SCHEMA = 'test') DROP TABLE test.sst_schema_test_multiple_schema"
execute <<-SCHEMATESTMULTIPLESCHEMA
CREATE TABLE test.sst_schema_test_multiple_schema(
field_1 int NOT NULL PRIMARY KEY,
field_2 int,
)
SCHEMATESTMULTIPLESCHEMA
execute "IF NOT EXISTS(SELECT * FROM sys.schemas WHERE name = 'test2') EXEC sp_executesql N'CREATE SCHEMA test2'"
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sst_schema_test_multiple_schema' and TABLE_SCHEMA = 'test2') DROP TABLE test2.sst_schema_test_multiple_schema"
execute <<-SCHEMATESTMULTIPLESCHEMA
CREATE TABLE test2.sst_schema_test_multiple_schema(
field_1 int,
field_2 int NOT NULL PRIMARY KEY,
)
SCHEMATESTMULTIPLESCHEMA
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'unique_key_dumped_table') DROP TABLE unique_key_dumped_table"
execute <<-SQLSERVERUNIQUEKEYS
CREATE TABLE unique_key_dumped_table (
id int IDENTITY(1,1) NOT NULL,
unique_field int DEFAULT 0 NOT NULL,
CONSTRAINT IX_UNIQUE_KEY UNIQUE (unique_field),
CONSTRAINT PK_UNIQUE_KEY PRIMARY KEY (id)
);
SQLSERVERUNIQUEKEYS
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sst_composite_without_identity') DROP TABLE sst_composite_without_identity"
execute <<-COMPOSITE_WITHOUT_IDENTITY
CREATE TABLE sst_composite_without_identity (
pk_col_one int NOT NULL,
pk_col_two int NOT NULL,
CONSTRAINT PK_sst_composite_without_identity PRIMARY KEY (pk_col_one, pk_col_two)
);
COMPOSITE_WITHOUT_IDENTITY
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sst_composite_with_identity') DROP TABLE sst_composite_with_identity"
execute <<-COMPOSITE_WITH_IDENTITY
CREATE TABLE sst_composite_with_identity (
pk_col_one int IDENTITY NOT NULL,
pk_col_two int NOT NULL,
CONSTRAINT PK_sst_composite_with_identity PRIMARY KEY (pk_col_one, pk_col_two)
);
COMPOSITE_WITH_IDENTITY
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'aliens' and TABLE_SCHEMA = 'test') DROP TABLE test.aliens"
execute <<-TABLE_IN_OTHER_SCHEMA_USED_BY_MODEL
CREATE TABLE test.aliens(
id int IDENTITY NOT NULL primary key,
name varchar(255)
)
TABLE_IN_OTHER_SCHEMA_USED_BY_MODEL
create_table "recurring_tasks", force: true do |t|
t.string :key
t.integer :priority, default: 0
t.datetime2 :created_at
t.datetime2 :updated_at
end
end