Skip to content

Commit dd20bce

Browse files
committed
refactor code into more smaller methods
1 parent 3f88a74 commit dd20bce

File tree

1 file changed

+99
-77
lines changed

1 file changed

+99
-77
lines changed

lib/active_record/connection_adapters/sqlserver/database_statements.rb

+99-77
Original file line numberDiff line numberDiff line change
@@ -156,47 +156,23 @@ def default_insert_value(column)
156156
def build_insert_sql(insert) # :nodoc:
157157
if insert.skip_duplicates? || insert.update_duplicates?
158158
insert_all = insert.send(:insert_all)
159-
conflict_columns = get_conflicted_columns(insert_all:, insert:)
159+
columns_with_uniqueness_constraints = get_columns_with_uniqueness_constraints(insert_all:, insert:)
160160

161161
# 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 conflict_columns.flatten.empty?
163-
164-
# why is the "PARTITION BY" clause needed?
165-
# in every DBMS system, insert_all / upsert_all is usually implemented with INSERT, that allows to define what happens
166-
# when duplicates are found (SKIP OR UPDATE)
167-
# by default rows are considered to be unique by every unique index on the table
168-
# but since we have to use MERGE in MSSQL, which in return is a JOIN, we have to perform the "de-duplication" ourselves
169-
# otherwise the "JOIN" clause would complain about non-unique values and being unable to JOIN the two tables
170-
# this works easiest by using PARTITION and make sure that any record
171-
# we are trying to insert is "the first one seen across all the potential conflicted columns"
172-
sql = <<~SQL
162+
return build_sql_for_regular_insert(insert) if columns_with_uniqueness_constraints.flatten.empty?
173163

164+
sql = <<~SQL
174165
MERGE INTO #{insert.model.quoted_table_name} WITH (UPDLOCK, HOLDLOCK) AS target
175166
USING (
176167
SELECT *
177168
FROM (
178-
SELECT #{insert.send(:columns_list)}, #{conflict_columns.map.with_index do |group_of_conflicted_columns, index|
179-
<<~PARTITION_BY
180-
ROW_NUMBER() OVER (
181-
PARTITION BY #{group_of_conflicted_columns.map { |column| quote_column_name(column) }.join(",")}
182-
ORDER BY #{group_of_conflicted_columns.map { |column| "#{quote_column_name(column)} DESC" }.join(",")}
183-
) AS rn_#{index}
184-
PARTITION_BY
185-
end.join(", ")
186-
}
169+
SELECT #{insert.send(:columns_list)}, #{partition_by_columns_with_uniqueness_constraints(columns_with_uniqueness_constraints:)}
187170
FROM (#{insert.values_list})
188171
AS t1 (#{insert.send(:columns_list)})
189172
) AS ranked_source
190-
WHERE #{conflict_columns.map.with_index do |group_of_conflicted_columns, index|
191-
"rn_#{index} = 1"
192-
end.join(" AND ")
193-
}
173+
WHERE #{is_first_record_across_all_uniqueness_constraints(columns_with_uniqueness_constraints:)}
194174
) AS source
195-
ON (#{conflict_columns.map do |columns|
196-
columns.map do |column|
197-
"target.#{quote_column_name(column)} = source.#{quote_column_name(column)}"
198-
end.join(" AND ")
199-
end.join(") OR (")})
175+
ON (#{joining_on_columns_with_uniqueness_constraints(columns_with_uniqueness_constraints:)})
200176
SQL
201177

202178
if insert.update_duplicates?
@@ -206,11 +182,7 @@ def build_insert_sql(insert) # :nodoc:
206182
sql << insert.raw_update_sql
207183
else
208184
if insert.record_timestamps?
209-
sql << insert.model.timestamp_attributes_for_update_in_model.filter_map do |column_name|
210-
if insert.send(:touch_timestamp_attribute?, column_name)
211-
"target.#{quote_column_name(column_name)}=CASE WHEN (#{insert.updatable_columns.map { |column| "(COALESCE(target.#{quote_column_name(column)}, 'NULL') = COALESCE(source.#{quote_column_name(column)}, 'NULL'))" }.join(" AND ")}) THEN target.#{quote_column_name(column_name)} ELSE #{high_precision_current_timestamp} END,"
212-
end
213-
end.join
185+
sql << build_sql_for_recording_timestamps_when_updating(insert:)
214186
end
215187

216188
sql << insert.updatable_columns.map { |column| "target.#{quote_column_name(column)}=source.#{quote_column_name(column)}" }.join(",")
@@ -228,48 +200,6 @@ def build_insert_sql(insert) # :nodoc:
228200
build_sql_for_regular_insert(insert)
229201
end
230202

231-
def build_sql_for_returning(insert:, insert_all:)
232-
return "" unless insert_all.returning
233-
234-
returning_values_sql = if insert_all.returning.is_a?(String)
235-
insert_all.returning
236-
else
237-
Array(insert_all.returning).map do |attribute|
238-
if insert.model.attribute_alias?(attribute)
239-
"INSERTED.#{quote_column_name(insert.model.attribute_alias(attribute))} AS #{quote_column_name(attribute)}"
240-
else
241-
"INSERTED.#{quote_column_name(attribute)}"
242-
end
243-
end.join(",")
244-
end
245-
246-
" OUTPUT #{returning_values_sql}"
247-
end
248-
private :build_sql_for_returning
249-
250-
def get_conflicted_columns(insert_all:, insert:)
251-
if (unique_by = insert_all.unique_by)
252-
[unique_by.columns]
253-
else
254-
# Compare against every unique constraint (primary key included).
255-
# Discard constraints that are not fully included on insert.keys. Prevents invalid queries.
256-
# Example: ignore unique index for columns ["name"] if insert keys is ["description"]
257-
(insert_all.send(:unique_indexes).map(&:columns) + [insert_all.primary_keys]).select do |columns|
258-
columns.to_set.subset?(insert.keys)
259-
end
260-
end
261-
end
262-
private :get_conflicted_columns
263-
264-
def build_sql_for_regular_insert(insert)
265-
sql = "INSERT #{insert.into}"
266-
267-
sql << build_sql_for_returning(insert:, insert_all: insert.send(:insert_all))
268-
sql << " #{insert.values_list}"
269-
sql
270-
end
271-
private :build_sql_for_regular_insert
272-
273203
# === SQLServer Specific ======================================== #
274204

275205
def execute_procedure(proc_name, *variables)
@@ -571,6 +501,98 @@ def internal_raw_execute(sql, raw_connection, perform_do: false)
571501
result = raw_connection.execute(sql)
572502
perform_do ? result.do : result
573503
end
504+
505+
# === SQLServer Specific (insert_all / upsert_all support) ===================== #
506+
def build_sql_for_returning(insert:, insert_all:)
507+
return "" unless insert_all.returning
508+
509+
returning_values_sql = if insert_all.returning.is_a?(String)
510+
insert_all.returning
511+
else
512+
Array(insert_all.returning).map do |attribute|
513+
if insert.model.attribute_alias?(attribute)
514+
"INSERTED.#{quote_column_name(insert.model.attribute_alias(attribute))} AS #{quote_column_name(attribute)}"
515+
else
516+
"INSERTED.#{quote_column_name(attribute)}"
517+
end
518+
end.join(",")
519+
end
520+
521+
" OUTPUT #{returning_values_sql}"
522+
end
523+
private :build_sql_for_returning
524+
525+
def get_columns_with_uniqueness_constraints(insert_all:, insert:)
526+
if (unique_by = insert_all.unique_by)
527+
[unique_by.columns]
528+
else
529+
# Compare against every unique constraint (primary key included).
530+
# Discard constraints that are not fully included on insert.keys. Prevents invalid queries.
531+
# Example: ignore unique index for columns ["name"] if insert keys is ["description"]
532+
(insert_all.send(:unique_indexes).map(&:columns) + [insert_all.primary_keys]).select do |columns|
533+
columns.to_set.subset?(insert.keys)
534+
end
535+
end
536+
end
537+
private :get_columns_with_uniqueness_constraints
538+
539+
def build_sql_for_regular_insert(insert)
540+
sql = "INSERT #{insert.into}"
541+
542+
sql << build_sql_for_returning(insert:, insert_all: insert.send(:insert_all))
543+
544+
sql << " #{insert.values_list}"
545+
sql
546+
end
547+
private :build_sql_for_regular_insert
548+
549+
# why is the "PARTITION BY" clause needed?
550+
# in every DBMS system, insert_all / upsert_all is usually implemented with INSERT, that allows to define what happens
551+
# when duplicates are found (SKIP OR UPDATE)
552+
# by default rows are considered to be unique by every unique index on the table
553+
# but since we have to use MERGE in MSSQL, which in return is a JOIN, we have to perform the "de-duplication" ourselves
554+
# otherwise the "JOIN" clause would complain about non-unique values and being unable to JOIN the two tables
555+
# 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"
557+
def partition_by_columns_with_uniqueness_constraints(columns_with_uniqueness_constraints:)
558+
columns_with_uniqueness_constraints.map.with_index do |group_of_columns_with_uniqueness_constraints, index|
559+
<<~PARTITION_BY
560+
ROW_NUMBER() OVER (
561+
PARTITION BY #{group_of_columns_with_uniqueness_constraints.map { |column| quote_column_name(column) }.join(",")}
562+
ORDER BY #{group_of_columns_with_uniqueness_constraints.map { |column| "#{quote_column_name(column)} DESC" }.join(",")}
563+
) AS rn_#{index}
564+
PARTITION_BY
565+
end.join(", ")
566+
end
567+
private :partition_by_columns_with_uniqueness_constraints
568+
569+
def is_first_record_across_all_uniqueness_constraints(columns_with_uniqueness_constraints:)
570+
columns_with_uniqueness_constraints.map.with_index do |group_of_columns_with_uniqueness_constraints, index|
571+
"rn_#{index} = 1"
572+
end.join(" AND ")
573+
end
574+
private :is_first_record_across_all_uniqueness_constraints
575+
576+
def joining_on_columns_with_uniqueness_constraints(columns_with_uniqueness_constraints:)
577+
columns_with_uniqueness_constraints.map do |columns|
578+
columns.map do |column|
579+
"target.#{quote_column_name(column)} = source.#{quote_column_name(column)}"
580+
end.join(" AND ")
581+
end.join(") OR (")
582+
end
583+
private :joining_on_columns_with_uniqueness_constraints
584+
585+
# normally, generating the CASE SQL is done entirely by Rails
586+
# and you would just hook into "touch_model_timestamps_unless" to add your database-specific instructions
587+
# however, since we need to have "target." for the assignment, we also generate the CASE switch ourselves
588+
def build_sql_for_recording_timestamps_when_updating(insert:)
589+
insert.model.timestamp_attributes_for_update_in_model.filter_map do |column_name|
590+
if insert.send(:touch_timestamp_attribute?, column_name)
591+
"target.#{quote_column_name(column_name)}=CASE WHEN (#{insert.updatable_columns.map { |column| "(COALESCE(target.#{quote_column_name(column)}, 'NULL') = COALESCE(source.#{quote_column_name(column)}, 'NULL'))" }.join(" AND ")}) THEN target.#{quote_column_name(column_name)} ELSE #{high_precision_current_timestamp} END,"
592+
end
593+
end.join
594+
end
595+
private :build_sql_for_recording_timestamps_when_updating
574596
end
575597
end
576598
end

0 commit comments

Comments
 (0)