Add update_sql option to #upsert_all

This commit is contained in:
Vladimir Dementyev 2021-04-12 18:01:42 +03:00
parent c7613dde53
commit 8f3c12f880
7 changed files with 64 additions and 13 deletions

@ -1,3 +1,14 @@
* Add `update_sql` option to `#upsert_all` to make it possible to use raw SQL to update columns on conflict:
```ruby
Book.upsert_all(
[{ id: 1, status: 1 }, { id: 2, status: 1 }],
update_sql: "status = GREATEST(books.status, EXCLUDED.status)"
)
```
*Vladimir Dementyev*
* Allow passing raw SQL as `returning` statement to `#upsert_all`:
```ruby

@ -551,8 +551,12 @@ def build_insert_sql(insert) # :nodoc:
sql << " ON DUPLICATE KEY UPDATE #{no_op_column}=#{no_op_column}"
elsif insert.update_duplicates?
sql << " ON DUPLICATE KEY UPDATE "
sql << insert.touch_model_timestamps_unless { |column| "#{column}<=>VALUES(#{column})" }
sql << insert.updatable_columns.map { |column| "#{column}=VALUES(#{column})" }.join(",")
if insert.raw_update_sql?
sql << insert.raw_update_sql
else
sql << insert.touch_model_timestamps_unless { |column| "#{column}<=>VALUES(#{column})" }
sql << insert.updatable_columns.map { |column| "#{column}=VALUES(#{column})" }.join(",")
end
end
sql

@ -439,8 +439,12 @@ def build_insert_sql(insert) # :nodoc:
sql << " ON CONFLICT #{insert.conflict_target} DO NOTHING"
elsif insert.update_duplicates?
sql << " ON CONFLICT #{insert.conflict_target} DO UPDATE SET "
sql << insert.touch_model_timestamps_unless { |column| "#{insert.model.quoted_table_name}.#{column} IS NOT DISTINCT FROM excluded.#{column}" }
sql << insert.updatable_columns.map { |column| "#{column}=excluded.#{column}" }.join(",")
if insert.raw_update_sql?
sql << insert.raw_update_sql
else
sql << insert.touch_model_timestamps_unless { |column| "#{insert.model.quoted_table_name}.#{column} IS NOT DISTINCT FROM excluded.#{column}" }
sql << insert.updatable_columns.map { |column| "#{column}=excluded.#{column}" }.join(",")
end
end
sql << " RETURNING #{insert.returning}" if insert.returning

@ -313,8 +313,12 @@ def build_insert_sql(insert) # :nodoc:
sql << " ON CONFLICT #{insert.conflict_target} DO NOTHING"
elsif insert.update_duplicates?
sql << " ON CONFLICT #{insert.conflict_target} DO UPDATE SET "
sql << insert.touch_model_timestamps_unless { |column| "#{column} IS excluded.#{column}" }
sql << insert.updatable_columns.map { |column| "#{column}=excluded.#{column}" }.join(",")
if insert.raw_update_sql?
sql << insert.raw_update_sql
else
sql << insert.touch_model_timestamps_unless { |column| "#{column} IS excluded.#{column}" }
sql << insert.updatable_columns.map { |column| "#{column}=excluded.#{column}" }.join(",")
end
end
sql

@ -5,13 +5,13 @@
module ActiveRecord
class InsertAll # :nodoc:
attr_reader :model, :connection, :inserts, :keys
attr_reader :on_duplicate, :returning, :unique_by
attr_reader :on_duplicate, :returning, :unique_by, :update_sql
def initialize(model, inserts, on_duplicate:, returning: nil, unique_by: nil)
def initialize(model, inserts, on_duplicate:, returning: nil, unique_by: nil, update_sql: nil)
raise ArgumentError, "Empty list of attributes passed" if inserts.blank?
@model, @connection, @inserts, @keys = model, model.connection, inserts, inserts.first.keys.map(&:to_s)
@on_duplicate, @returning, @unique_by = on_duplicate, returning, unique_by
@on_duplicate, @returning, @unique_by, @update_sql = on_duplicate, returning, unique_by, update_sql
if model.scope_attributes?
@scope_attributes = model.scope_attributes
@ -182,6 +182,12 @@ def touch_model_timestamps_unless(&block)
end.compact.join
end
def raw_update_sql
insert_all.update_sql
end
alias raw_update_sql? raw_update_sql
private
attr_reader :connection, :insert_all

@ -198,8 +198,8 @@ def insert_all!(attributes, returning: nil)
# go through Active Record's type casting and serialization.
#
# See <tt>ActiveRecord::Persistence#upsert_all</tt> for documentation.
def upsert(attributes, returning: nil, unique_by: nil)
upsert_all([ attributes ], returning: returning, unique_by: unique_by)
def upsert(attributes, returning: nil, unique_by: nil, update_sql: nil)
upsert_all([ attributes ], returning: returning, unique_by: unique_by, update_sql: update_sql)
end
# Updates or inserts (upserts) multiple records into the database in a
@ -245,6 +245,11 @@ def upsert(attributes, returning: nil, unique_by: nil)
# <tt>:unique_by</tt> is recommended to be paired with
# Active Record's schema_cache.
#
# [:update_sql]
# Specify a custom SQL for updating rows on conflict.
#
# NOTE: in this case you must provide all the columns you want to update by yourself.
#
# ==== Examples
#
# # Inserts multiple records, performing an upsert when records have duplicate ISBNs.
@ -256,8 +261,8 @@ def upsert(attributes, returning: nil, unique_by: nil)
# ], unique_by: :isbn)
#
# Book.find_by(isbn: "1").title # => "Eloquent Ruby"
def upsert_all(attributes, returning: nil, unique_by: nil)
InsertAll.new(self, attributes, on_duplicate: :update, returning: returning, unique_by: unique_by).execute
def upsert_all(attributes, returning: nil, unique_by: nil, update_sql: nil)
InsertAll.new(self, attributes, on_duplicate: :update, returning: returning, unique_by: unique_by, update_sql: update_sql).execute
end
# Given an attributes hash, +instantiate+ returns a new instance of

@ -473,6 +473,19 @@ def test_upsert_all_has_many_through
assert_raise(ArgumentError) { book.subscribers.upsert_all([ { nick: "Jimmy" } ]) }
end
def test_upsert_all_updates_using_provided_sql
skip unless supports_insert_on_duplicate_update?
operator = sqlite? ? "MAX" : "GREATEST"
Book.upsert_all(
[{ id: 1, status: 1 }, { id: 2, status: 1 }],
update_sql: "status = #{operator}(books.status, 1)"
)
assert_equal "published", Book.find(1).status
assert_equal "written", Book.find(2).status
end
private
def capture_log_output
output = StringIO.new
@ -484,4 +497,8 @@ def capture_log_output
ActiveRecord::Base.logger = old_logger
end
end
def sqlite?
ActiveRecord::Base.connection.adapter_name.match?(/sqlite/i)
end
end