-
Notifications
You must be signed in to change notification settings - Fork 565
Fix multiple nil identity columns for merge insert #1327
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
base: main
Are you sure you want to change the base?
Conversation
elsif insert.primary_keys.include?(key) && value.nil? | ||
column = insert.send(:column_from_key, key) | ||
|
||
if column.is_identity? |
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
just curious: is it possible under MSSQL that you have an identity column that is not a primary key? or is identity column just another word for "column with autogenerated identifier"?
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Had to look that up. Looks like you can have a primary key that is not an identity column and an identity column that is not a primary key.
CREATE TABLE ExampleTable (
PrimaryKeyCol INT NOT NULL PRIMARY KEY,
IdentityColumn INT IDENTITY(1,1) NOT NULL,
SomeOtherCol NVARCHAR(100) NULL
);
if column.is_identity? | ||
identity_index += 1 | ||
table_name = quote(quote_table_name(column.table_name)) | ||
Arel.sql("IDENT_CURRENT(#{table_name}) + (IDENT_INCR(#{table_name}) * #{identity_index})") |
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
shouldn't this be enough?
Arel.sql("IDENT_CURRENT(#{table_name}) + (IDENT_INCR(#{table_name}) * #{identity_index})") | |
Arel.sql("IDENT_CURRENT(#{table_name}) + (IDENT_INCR(#{table_name}) + #{identity_index})") |
but I am not sure. I assume MSSQL uses the identifier generated here and does not overwrite them, correct? if it does overwrite it, then ignore this comment. if it does not overwrite it, then I would prefer the +
, as it would generate much smaller values.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
The values given by "IDENT_CURRENT(#{table_name}) + (IDENT_INCR(#{table_name}) * #{identity_index})"
are the IDs used when the record is created. I used multiplication as IDENT_INCR
is the step value (https://learn.microsoft.com/en-us/sql/t-sql/functions/ident-incr-transact-sql?view=sql-server-ver16) that should be used for generating the ID.
So if IDENT_CURRENT('books)
is 100 and IDENT_INCR('books')
is 2 then the next IDs generated should be 102, 104, 106, etc. To generate this sequence we need to use multiplication. If we used addition then the IDs generated would be 102, 103, 104, etc.
Handle merge inserts that contain multiple
nil
identity columns. Eg:Previously the SQL generated would have been:
When this is run only the book with title "New edition 1" is created in the table. The reason is that "New edition 2" is first inserted but then "New edition 1" is updated over "New edition 2" since it matches
ON ( target.[id] = source.[id] )
.The fix changes the inserted ID columns to the following so that they don't match and both records get inserted:
This fixes the following tests which were added by rails/rails#54962