Skip to content
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

Altering a nullable column to not null generates invalid SQL commands for migration #32062

Closed
joakimriedel opened this issue Oct 16, 2023 · 11 comments · Fixed by #32102
Closed
Labels
area-migrations area-temporal-tables closed-fixed The issue has been fixed and is/will be included in the release indicated by the issue milestone. customer-reported type-bug

Comments

@joakimriedel
Copy link
Contributor

joakimriedel commented Oct 16, 2023

File a bug

Altering a nullable column to not null of a temporal table generates invalid idempotent script. The script does not include necessary commands to disable system versioning and alter the history table data, which cause an error running the script due to null column values in history. (see remark)

Include your code

The migration will be generated similar to;

            migrationBuilder.AlterColumn<bool>(
                name: "ColumnName",
                table: "TableName",
                type: "bit",
                nullable: false,
                defaultValue: false,
                oldClrType: typeof(bool),
                oldType: "bit",
                oldNullable: true)
                .Annotation("SqlServer:IsTemporal", true)
                .Annotation("SqlServer:TemporalHistoryTableName", "TableNameHistory")
                .Annotation("SqlServer:TemporalHistoryTableSchema", null)
                .Annotation("SqlServer:TemporalPeriodEndColumnName", "PeriodEnd")
                .Annotation("SqlServer:TemporalPeriodStartColumnName", "PeriodStart")
                .OldAnnotation("SqlServer:IsTemporal", true)
                .OldAnnotation("SqlServer:TemporalHistoryTableName", "TableNameHistory")
                .OldAnnotation("SqlServer:TemporalHistoryTableSchema", null)
                .OldAnnotation("SqlServer:TemporalPeriodEndColumnName", "PeriodEnd")
                .OldAnnotation("SqlServer:TemporalPeriodStartColumnName", "PeriodStart");

Generating the idempotent script would output something like;

IF NOT EXISTS(SELECT * FROM [__EFMigrationsHistory] WHERE [MigrationId] = N'20231016135852_Migration')
BEGIN
    DECLARE @var116 sysname;
    SELECT @var116 = [d].[name]
    FROM [sys].[default_constraints] [d]
    INNER JOIN [sys].[columns] [c] ON [d].[parent_column_id] = [c].[column_id] AND [d].[parent_object_id] = [c].[object_id]
    WHERE ([d].[parent_object_id] = OBJECT_ID(N'[TableName]') AND [c].[name] = N'ColumnName');
    IF @var116 IS NOT NULL EXEC(N'ALTER TABLE [TableName] DROP CONSTRAINT [' + @var116 + '];');
    EXEC(N'UPDATE [TableName] SET [ColumnName] = CAST(0 AS bit) WHERE [ColumnName] IS NULL');
    ALTER TABLE [TableName] ALTER COLUMN [ColumnName] bit NOT NULL;
    ALTER TABLE [TableName] ADD DEFAULT CAST(0 AS bit) FOR [ColumnName];
END;
GO

But I would expect it to be something like;

IF NOT EXISTS(SELECT * FROM [__EFMigrationsHistory] WHERE [MigrationId] = N'20231016135852_Migration')
BEGIN
    ALTER TABLE [TableName] SET (SYSTEM_VERSIONING = OFF)
END;
GO

IF NOT EXISTS(SELECT * FROM [__EFMigrationsHistory] WHERE [MigrationId] = N'20231016135852_Migration')
BEGIN
    DECLARE @var116 sysname;
    SELECT @var116 = [d].[name]
    FROM [sys].[default_constraints] [d]
    INNER JOIN [sys].[columns] [c] ON [d].[parent_column_id] = [c].[column_id] AND [d].[parent_object_id] = [c].[object_id]
    WHERE ([d].[parent_object_id] = OBJECT_ID(N'[TableName]') AND [c].[name] = N'ColumnName');
    IF @var116 IS NOT NULL EXEC(N'ALTER TABLE [TableName] DROP CONSTRAINT [' + @var116 + '];');

    EXEC(N'UPDATE [TableName] SET [ColumnName] = CAST(0 AS bit) WHERE [ColumnName] IS NULL');
    ALTER TABLE [TableName] ALTER COLUMN [ColumnName] bit NOT NULL;
    ALTER TABLE [TableName] ADD DEFAULT CAST(0 AS bit) FOR [ColumnName];

    EXEC(N'UPDATE [TableNameHistory] SET [ColumnName] = CAST(0 AS bit) WHERE [ColumnName] IS NULL');
    ALTER TABLE [TableNameHistory] ALTER COLUMN [ColumnName] bit NOT NULL;
    ALTER TABLE [TableNameHistory] ADD DEFAULT CAST(0 AS bit) FOR [ColumnName];
END;
GO

IF NOT EXISTS(SELECT * FROM [__EFMigrationsHistory] WHERE [MigrationId] = N'20231016135852_Migration')
BEGIN
    DECLARE @historyTableSchema sysname = SCHEMA_NAME()
    EXEC(N'ALTER TABLE [TableName] SET (SYSTEM_VERSIONING = ON (HISTORY_TABLE = [' + @historyTableSchema + '].[TableNameHistory]))')
END;
GO

I am also facing a similar issue when renaming a column;

IF NOT EXISTS(SELECT * FROM [__EFMigrationsHistory] WHERE [MigrationId] = N'20230924183929_Migration')
BEGIN
    EXEC sp_rename N'[TableName].[OldName]', N'NewName', N'COLUMN';
END;
GO

instead of

IF NOT EXISTS(SELECT * FROM [__EFMigrationsHistory] WHERE [MigrationId] = N'20230924183929_Migration')
BEGIN
    ALTER TABLE [TableName] SET (SYSTEM_VERSIONING = OFF)
END;
GO

IF NOT EXISTS(SELECT * FROM [__EFMigrationsHistory] WHERE [MigrationId] = N'20230924183929_Migration')
BEGIN
    EXEC sp_rename N'[TableName].[OldName]', N'NewName', N'COLUMN';
    EXEC sp_rename N'[TableNameHistory].[OldName]', N'NewName', N'COLUMN';
END;
GO

IF NOT EXISTS(SELECT * FROM [__EFMigrationsHistory] WHERE [MigrationId] = N'20230924183929_Migration')
BEGIN
    DECLARE @historyTableSchema sysname = SCHEMA_NAME()
    EXEC(N'ALTER TABLE [TableName] SET (SYSTEM_VERSIONING = ON (HISTORY_TABLE = [' + @historyTableSchema + '].[TableNameHistory]))')
END;
GO

even though it's marked temporal in migration code

            migrationBuilder.RenameColumn(
                name: "OldName",
                table: "TableName",
                newName: "NewName")
                .Annotation("SqlServer:IsTemporal", true)
                .Annotation("SqlServer:TemporalHistoryTableName", "TableNameHistory")
                .Annotation("SqlServer:TemporalHistoryTableSchema", null)
                .Annotation("SqlServer:TemporalPeriodEndColumnName", "PeriodEnd")
                .Annotation("SqlServer:TemporalPeriodStartColumnName", "PeriodStart");

DROPPING columns however, works perfectly and the necessary disabling of SYSTEM_VERSIONING gets written to the idempotent script.

Exception

Trying to execute dotnet ef database update fails with the following exception.

Microsoft.Data.SqlClient.SqlException (0x80131904): Cannot insert the value NULL into column 'ColumnName', table 'Database.dbo.TableNameHistory'; column does not allow nulls. UPDATE fails.
The statement has been terminated.
   at Microsoft.Data.SqlClient.SqlConnection.OnError(SqlException exception, Boolean breakConnection, Action`1 wrapCloseInAction)
   at Microsoft.Data.SqlClient.SqlInternalConnection.OnError(SqlException exception, Boolean breakConnection, Action`1 wrapCloseInAction)
   at Microsoft.Data.SqlClient.TdsParser.ThrowExceptionAndWarning(TdsParserStateObject stateObj, Boolean callerHasConnectionLock, Boolean asyncClose)
   at Microsoft.Data.SqlClient.TdsParser.TryRun(RunBehavior runBehavior, SqlCommand cmdHandler, SqlDataReader dataStream, BulkCopySimpleResultSet bulkCopyHandler, TdsParserStateObject stateObj, Boolean& dataReady)
   at Microsoft.Data.SqlClient.SqlCommand.RunExecuteNonQueryTds(String methodName, Boolean isAsync, Int32 timeout, Boolean asyncWrite)
   at Microsoft.Data.SqlClient.SqlCommand.InternalExecuteNonQuery(TaskCompletionSource`1 completion, Boolean sendToPipe, Int32 timeout, Boolean& usedCache, Boolean asyncWrite, Boolean inRetry, String methodName)
   at Microsoft.Data.SqlClient.SqlCommand.ExecuteNonQuery()
   at Microsoft.EntityFrameworkCore.Storage.RelationalCommand.ExecuteNonQuery(RelationalCommandParameterObject parameterObject)
   at Microsoft.EntityFrameworkCore.Migrations.MigrationCommand.ExecuteNonQuery(IRelationalConnection connection, IReadOnlyDictionary`2 parameterValues)
   at Microsoft.EntityFrameworkCore.Migrations.Internal.MigrationCommandExecutor.ExecuteNonQuery(IEnumerable`1 migrationCommands, IRelationalConnection connection)
   at Microsoft.EntityFrameworkCore.Migrations.Internal.Migrator.Migrate(String targetMigration)
   at Microsoft.EntityFrameworkCore.Design.Internal.MigrationsOperations.UpdateDatabase(String targetMigration, String connectionString, String contextType)
   at Microsoft.EntityFrameworkCore.Design.OperationExecutor.UpdateDatabaseImpl(String targetMigration, String connectionString, String contextType)
   at Microsoft.EntityFrameworkCore.Design.OperationExecutor.UpdateDatabase.<>c__DisplayClass0_0.<.ctor>b__0()
   at Microsoft.EntityFrameworkCore.Design.OperationExecutor.OperationBase.Execute(Action action)

Include provider and version information

EF Core version: 7.0.11
Database provider: Microsoft.EntityFrameworkCore.SqlServer
Target framework: .NET 7

@joakimriedel joakimriedel changed the title Altering a nullable column to not null generates invalid system versioning idempotent script Altering a nullable column to not null generates invalid SQL commands for migration Oct 16, 2023
@ajcvickers
Copy link
Member

/cc @bricelam @maumar

@maumar
Copy link
Contributor

maumar commented Oct 18, 2023

this is still a problem in the current bits. We should disable period before nullable -> non-nullable alter column operations, like we do for dropcolumn. There are also some other operations that require it, listed in the remarks linked in the bug report.
Also we should test our migrations with data (at least in some cases) - this bug would have slipped through the cracks, even if we had this exact scenario covered in our tests. It only repros if there is a row with a null value for the column that is to be converted to non-nullable.

@joakimriedel do you see the exception for rename case as well, or just noting the fact that we don't disable period for the rename case (but there is no exception as is)?

@joakimriedel
Copy link
Contributor Author

@maumar the rename case was a bit different, I did not get any exception running the migration locally on mssqllocaldb , but the idempotent script blew up running on Azure SQL complaining about the history table not being renamed or something. I had to manually disable versioning to run the rename on both tables to upgrade our production servers.

@maumar
Copy link
Contributor

maumar commented Oct 18, 2023

@joakimriedel thanks for the info, I will look into the rename case bit deeper then. If you still have the exception message that Azure SQL gave you, can you provide it?

@joakimriedel
Copy link
Contributor Author

@maumar unfortunately that migration was a few months back and I didn't file an issue since it thought it was a temporary issue. I could try to see if I can recreate it.

@maumar
Copy link
Contributor

maumar commented Oct 18, 2023

@joakimriedel that would definitely help us pin point the problem. Alternatively, we could just blanket disable versioning for all the alter/rename operations, but I'd really like to avoid that, because this could cause failures in other scenarios. Temporal tables migrations is really messy because of the shared state between operations.

@joakimriedel
Copy link
Contributor Author

joakimriedel commented Oct 18, 2023

@maumar OK so I restored the database back to before the migration with renamed column and tried it again, which refreshed my memory.

Renaming the column does not error, in fact, it does not do anything at all.

I can call sp_rename how many times I want, it just won't rename and it does not throw any errors. The error I got previously was due to the next step in the migration using the new column name (while the db still had the old name).

To actually make sp_rename rename the column, versioning has to be disabled and you have to call sp_rename on both the temporary table and the history table and then enable versioning again.

@maumar
Copy link
Contributor

maumar commented Oct 18, 2023

@joakimriedel thanks a lot for the extra info!

maumar added a commit that referenced this issue Oct 19, 2023
…lid SQL commands for migration

Problem was that alter column from nullable to non-nullable on a temporal table requires us to disable versioning, so that null values could be properly updated to the new defaults.

Fixes #32062
@maumar maumar added the closed-fixed The issue has been fixed and is/will be included in the release indicated by the issue milestone. label Oct 19, 2023
maumar added a commit that referenced this issue Oct 24, 2023
…lid SQL commands for migration (#32102)

Problem was that alter column from nullable to non-nullable on a temporal table requires us to disable versioning, so that null values could be properly updated to the new defaults.

Fixes #32062
@maumar maumar added this to the 9.0.0 milestone Oct 24, 2023
@joakimriedel
Copy link
Contributor Author

@maumar two questions, 1) will the rename case also be patched 2) will the fix be backported to 8.0 as well?

@maumar
Copy link
Contributor

maumar commented Oct 24, 2023

@joakimriedel rename issue looks like a bug in Azure SQL, rather than EF Core. However, I am unable to reproduce it on my end. The simple scenario of rename property on a temporal table in Azure SQL works just fine in my test environment. I was about to reach out to you, if you could help us with pin-pointing the problem. Would you be willing to provide the migration code (or the migration sql) and/or the table / EF model that the name change was applied on? Could be publicly or privately, if that works better - my email is my github alias at microsoft dot com.

When it comes to patching, unfortunately we caught the bug about 2 weeks too late. At this point we only accept critical level bugs into EF8. This issue doesn't meet the bar for patch at the moment, given that it's relatively uncommon scenario and there is a reasonable workaround. If we get more customers hitting the problem, we will reconsider patching it into 8, but for now the answer is sadly: no.

@joakimriedel
Copy link
Contributor Author

@maumar today I finally got some time to look at this again, and it seems as if it is just one particular table that won't work to rename columns on without disabling system versioning. The only thing that differs with this table and other system versioned I have in my database is that it also has a geography spatial column. I posted a report here, hopefully I can get some debugging help from the Azure SQL team.

@ajcvickers ajcvickers modified the milestones: 9.0.0, 9.0.0-preview1 Jan 31, 2024
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
area-migrations area-temporal-tables closed-fixed The issue has been fixed and is/will be included in the release indicated by the issue milestone. customer-reported type-bug
Projects
None yet
3 participants