You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
**NOTE:** The method we utilize to make SHOWPLANs work is very brittle to complex SQL. There is no getting around this as we have to deconstruct an already prepared statement for the sp_executesql method. If you find that explain breaks your app, simple disable it. Do not open a github issue unless you have a patch. Please [consult the Rails guides](http://guides.rubyonrails.org/active_record_querying.html#running-explain) for more info.
171
171
172
+
#### `insert_all` / `upsert_all` support
173
+
174
+
`insert_all` and `upsert_all` on other database system like MySQL, SQlite or PostgreSQL use a clause with their `INSERT` statement to either skip duplicates (`ON DUPLICATE KEY IGNORE`) or to update the existing record (`ON DUPLICATE KEY UPDATE`). Microsoft SQL Server does not offer these clauses, so the support for these two options is implemented slightly different.
175
+
176
+
Behind the scenes, we execute a `MERGE` query, which joins your data that you want to insert or update into the table existing on the server. The emphasis here is "JOINING", so we also need to remove any duplicates that might make the `JOIN` operation fail, e.g. something like this:
177
+
178
+
```ruby
179
+
Book.insert_all [
180
+
{ id:200, author_id:8, name:"Refactoring" },
181
+
{ id:200, author_id:8, name:"Refactoring" }
182
+
]
183
+
```
184
+
185
+
The removal of duplicates happens during the SQL query.
186
+
187
+
Because of this implementation, if you pass `on_duplicate` to `upsert_all`, make sure to assign your value to `target.[column_name]` (e.g. `target.status = GREATEST(target.status, 1)`). To access the values that you want to upsert, use `source.[column_name]`.
Copy file name to clipboardexpand all lines: test/cases/adapter_test_sqlserver.rb
+11-1
Original file line number
Diff line number
Diff line change
@@ -13,6 +13,7 @@ class AdapterTestSQLServer < ActiveRecord::TestCase
13
13
fixtures:tasks
14
14
15
15
let(:basic_insert_sql){"INSERT INTO [funny_jokes] ([name]) VALUES('Knock knock')"}
16
+
let(:basic_merge_sql){"MERGE INTO [ships] WITH (UPDLOCK, HOLDLOCK) AS target USING ( SELECT * FROM ( SELECT [id], [name], ROW_NUMBER() OVER ( PARTITION BY [id] ORDER BY [id] DESC ) AS rn_0 FROM ( VALUES (101, N'RSS Sir David Attenborough') ) AS t1 ([id], [name]) ) AS ranked_source WHERE rn_0 = 1 ) AS source ON (target.[id] = source.[id]) WHEN MATCHED THEN UPDATE SET target.[name] = source.[name]"}
16
17
let(:basic_update_sql){"UPDATE [customers] SET [address_street] = NULL WHERE [id] = 2"}
17
18
let(:basic_select_sql){"SELECT * FROM [customers] WHERE ([customers].[id] = 1)"}
18
19
@@ -91,6 +92,7 @@ class AdapterTestSQLServer < ActiveRecord::TestCase
91
92
92
93
it"return unquoted table name object from basic INSERT UPDATE and SELECT statements"do
@identity_merge_sql="MERGE INTO [ships] WITH (UPDLOCK, HOLDLOCK) AS target USING ( SELECT * FROM ( SELECT [id], [name], ROW_NUMBER() OVER ( PARTITION BY [id] ORDER BY [id] DESC ) AS rn_0 FROM ( VALUES (101, N'RSS Sir David Attenborough') ) AS t1 ([id], [name]) ) AS ranked_source WHERE rn_0 = 1 ) AS source ON (target.[id] = source.[id]) WHEN MATCHED THEN UPDATE SET target.[name] = source.[name] WHEN NOT MATCHED BY TARGET THEN INSERT ([id], [name]) VALUES (source.[id], source.[name]) OUTPUT INSERTED.[id]"
225
+
@identity_merge_sql_unquoted="MERGE INTO ships WITH (UPDLOCK, HOLDLOCK) AS target USING ( SELECT * FROM ( SELECT id, name, ROW_NUMBER() OVER ( PARTITION BY id ORDER BY id DESC ) AS rn_0 FROM ( VALUES (101, N'RSS Sir David Attenborough') ) AS t1 (id, name) ) AS ranked_source WHERE rn_0 = 1 ) AS source ON (target.id = source.id) WHEN MATCHED THEN UPDATE SET target.name = source.name WHEN NOT MATCHED BY TARGET THEN INSERT (id, name) VALUES (source.id, source.name) OUTPUT INSERTED.id"
226
+
@identity_merge_sql_unordered="MERGE INTO [ships] WITH (UPDLOCK, HOLDLOCK) AS target USING ( SELECT * FROM ( SELECT [name], [id], ROW_NUMBER() OVER ( PARTITION BY [id] ORDER BY [id] DESC ) AS rn_0 FROM ( VALUES (101, N'RSS Sir David Attenborough') ) AS t1 ([name], [id]) ) AS ranked_source WHERE rn_0 = 1 ) AS source ON (target.[id] = source.[id]) WHEN MATCHED THEN UPDATE SET target.[name] = source.[name] WHEN NOT MATCHED BY TARGET THEN INSERT ([name], [id]) VALUES (source.[name], source.[id]) OUTPUT INSERTED.[id]"
227
+
222
228
@identity_insert_sql_non_dbo="INSERT INTO [test].[aliens] ([id],[name]) VALUES(420,'Mork')"
223
229
@identity_insert_sql_non_dbo_unquoted="INSERT INTO test.aliens ([id],[name]) VALUES(420,'Mork')"
224
230
@identity_insert_sql_non_dbo_unordered="INSERT INTO [test].[aliens] ([name],[id]) VALUES('Mork',420)"
@@ -235,6 +241,10 @@ class AdapterTestSQLServer < ActiveRecord::TestCase
Copy file name to clipboardexpand all lines: test/cases/schema_test_sqlserver.rb
+18
Original file line number
Diff line number
Diff line change
@@ -102,6 +102,24 @@ class SchemaTestSQLServer < ActiveRecord::TestCase
102
102
end
103
103
end
104
104
105
+
describe"MERGE statements"do
106
+
itdo
107
+
assert_equal"[dashboards]",connection.send(:get_raw_table_name,"MERGE INTO [dashboards] AS target")
108
+
end
109
+
110
+
itdo
111
+
assert_equal"lock_without_defaults",connection.send(:get_raw_table_name,"MERGE INTO lock_without_defaults AS target")
112
+
end
113
+
114
+
itdo
115
+
assert_equal"[WITH - SPACES]",connection.send(:get_raw_table_name,"MERGE INTO [WITH - SPACES] AS target")
116
+
end
117
+
118
+
itdo
119
+
assert_equal"[with].[select notation]",connection.send(:get_raw_table_name,"MERGE INTO [with].[select notation] AS target")
120
+
end
121
+
end
122
+
105
123
describe"CREATE VIEW statements"do
106
124
itdo
107
125
assert_equal"test_table_as",connection.send(:get_raw_table_name,"CREATE VIEW test_views ( test_table_a_id, test_table_b_id ) AS SELECT test_table_as.id as test_table_a_id, test_table_bs.id as test_table_b_id FROM (test_table_as with(nolock) LEFT JOIN test_table_bs with(nolock) ON (test_table_as.id = test_table_bs.test_table_a_id))")
0 commit comments