Skip to content

Commit db8199a

Browse files
authored
Small refactor of Support insert_all and upsert_all using MERGE (#1314)
1 parent e092ebb commit db8199a

File tree

1 file changed

+45
-43
lines changed

1 file changed

+45
-43
lines changed

lib/active_record/connection_adapters/sqlserver/database_statements.rb

+45-43
Original file line numberDiff line numberDiff line change
@@ -154,50 +154,54 @@ def default_insert_value(column)
154154
private :default_insert_value
155155

156156
def build_insert_sql(insert) # :nodoc:
157-
if insert.skip_duplicates? || insert.update_duplicates?
158-
insert_all = insert.send(:insert_all)
159-
columns_with_uniqueness_constraints = get_columns_with_uniqueness_constraints(insert_all:, insert:)
160-
161-
# if we do not have any columns that might have conflicting values, just execute a regular insert
162-
return build_sql_for_regular_insert(insert) if columns_with_uniqueness_constraints.flatten.empty?
163-
164-
sql = <<~SQL
165-
MERGE INTO #{insert.model.quoted_table_name} WITH (UPDLOCK, HOLDLOCK) AS target
166-
USING (
167-
SELECT *
168-
FROM (
169-
SELECT #{insert.send(:columns_list)}, #{partition_by_columns_with_uniqueness_constraints(columns_with_uniqueness_constraints:)}
170-
FROM (#{insert.values_list})
171-
AS t1 (#{insert.send(:columns_list)})
172-
) AS ranked_source
173-
WHERE #{is_first_record_across_all_uniqueness_constraints(columns_with_uniqueness_constraints:)}
174-
) AS source
175-
ON (#{joining_on_columns_with_uniqueness_constraints(columns_with_uniqueness_constraints:)})
176-
SQL
177-
178-
if insert.update_duplicates?
179-
sql << " WHEN MATCHED THEN UPDATE SET "
180-
181-
if insert.raw_update_sql?
182-
sql << insert.raw_update_sql
183-
else
184-
if insert.record_timestamps?
185-
sql << build_sql_for_recording_timestamps_when_updating(insert:)
186-
end
157+
# Use regular insert if not skipping/updating duplicates.
158+
return build_sql_for_regular_insert(insert:) unless insert.skip_duplicates? || insert.update_duplicates?
187159

188-
sql << insert.updatable_columns.map { |column| "target.#{quote_column_name(column)}=source.#{quote_column_name(column)}" }.join(",")
189-
end
190-
end
191-
sql << " WHEN NOT MATCHED BY TARGET THEN"
192-
sql << " INSERT (#{insert.send(:columns_list)}) VALUES (#{insert_all.keys_including_timestamps.map { |column| "source.#{quote_column_name(column)}" }.join(", ")})"
193-
sql << build_sql_for_returning(insert:, insert_all: insert.send(:insert_all))
160+
insert_all = insert.send(:insert_all)
161+
columns_with_uniqueness_constraints = get_columns_with_uniqueness_constraints(insert_all:, insert:)
162+
163+
# If we do not have any columns that might have conflicting values just execute a regular insert, else use merge.
164+
if columns_with_uniqueness_constraints.flatten.empty?
165+
build_sql_for_regular_insert(insert:)
166+
else
167+
build_sql_for_merge_insert(insert:, insert_all:, columns_with_uniqueness_constraints:)
168+
end
169+
end
194170

195-
sql << ";"
171+
def build_sql_for_merge_insert(insert:, insert_all:, columns_with_uniqueness_constraints:) # :nodoc:
172+
sql = <<~SQL
173+
MERGE INTO #{insert.model.quoted_table_name} WITH (UPDLOCK, HOLDLOCK) AS target
174+
USING (
175+
SELECT *
176+
FROM (
177+
SELECT #{insert.send(:columns_list)}, #{partition_by_columns_with_uniqueness_constraints(columns_with_uniqueness_constraints:)}
178+
FROM (#{insert.values_list})
179+
AS t1 (#{insert.send(:columns_list)})
180+
) AS ranked_source
181+
WHERE #{is_first_record_across_all_uniqueness_constraints(columns_with_uniqueness_constraints:)}
182+
) AS source
183+
ON (#{joining_on_columns_with_uniqueness_constraints(columns_with_uniqueness_constraints:)})
184+
SQL
185+
186+
if insert.update_duplicates?
187+
sql << " WHEN MATCHED THEN UPDATE SET "
188+
189+
if insert.raw_update_sql?
190+
sql << insert.raw_update_sql
191+
else
192+
if insert.record_timestamps?
193+
sql << build_sql_for_recording_timestamps_when_updating(insert:)
194+
end
196195

197-
return sql
196+
sql << insert.updatable_columns.map { |column| "target.#{quote_column_name(column)}=source.#{quote_column_name(column)}" }.join(",")
197+
end
198198
end
199+
sql << " WHEN NOT MATCHED BY TARGET THEN"
200+
sql << " INSERT (#{insert.send(:columns_list)}) VALUES (#{insert_all.keys_including_timestamps.map { |column| "source.#{quote_column_name(column)}" }.join(", ")})"
201+
sql << build_sql_for_returning(insert:, insert_all: insert.send(:insert_all))
202+
sql << ";"
199203

200-
build_sql_for_regular_insert(insert)
204+
sql
201205
end
202206

203207
# === SQLServer Specific ======================================== #
@@ -536,11 +540,9 @@ def get_columns_with_uniqueness_constraints(insert_all:, insert:)
536540
end
537541
private :get_columns_with_uniqueness_constraints
538542

539-
def build_sql_for_regular_insert(insert)
543+
def build_sql_for_regular_insert(insert:)
540544
sql = "INSERT #{insert.into}"
541-
542545
sql << build_sql_for_returning(insert:, insert_all: insert.send(:insert_all))
543-
544546
sql << " #{insert.values_list}"
545547
sql
546548
end
@@ -553,7 +555,7 @@ def build_sql_for_regular_insert(insert)
553555
# but since we have to use MERGE in MSSQL, which in return is a JOIN, we have to perform the "de-duplication" ourselves
554556
# otherwise the "JOIN" clause would complain about non-unique values and being unable to JOIN the two tables
555557
# this works easiest by using PARTITION and make sure that any record
556-
# we are trying to insert is "the first one seen across all the potential columns with uniquness constraints"
558+
# we are trying to insert is "the first one seen across all the potential columns with uniqueness constraints"
557559
def partition_by_columns_with_uniqueness_constraints(columns_with_uniqueness_constraints:)
558560
columns_with_uniqueness_constraints.map.with_index do |group_of_columns_with_uniqueness_constraints, index|
559561
<<~PARTITION_BY

0 commit comments

Comments
 (0)