commit 7af5271512b61adb8d21407679f51c3b63ca2188 Author: David Lavati Date: Thu Jun 20 19:48:39 2019 +0200 HIVE-21756 Backport HIVE-21404: MSSQL upgrade script alters the wrong column (David Lavati via Zoltan Haindrich, Ashutosh Bapat) Signed-off-by: Zoltan Haindrich (cherry picked from commit 78f85137f778330d3881e4291340f97427b04a34) Change-Id: Ia3c60f1610eed6a9e504085977c5d01ee679c1cb diff --git a/standalone-metastore/src/main/sql/mssql/upgrade-3.1.0-to-3.2.0.mssql.sql b/standalone-metastore/src/main/sql/mssql/upgrade-3.1.0-to-3.2.0.mssql.sql index f2031c8263..cc3f2639fb 100644 --- a/standalone-metastore/src/main/sql/mssql/upgrade-3.1.0-to-3.2.0.mssql.sql +++ b/standalone-metastore/src/main/sql/mssql/upgrade-3.1.0-to-3.2.0.mssql.sql @@ -21,7 +21,46 @@ ALTER TABLE DBS ADD CREATE_TIME INT; ALTER TABLE CTLGS ADD CREATE_TIME INT; -- HIVE-20221 -ALTER TABLE "SERDE_PARAMS" ALTER COLUMN "PARAM_VALUE" nvarchar(MAX); + +-- We can not change the datatype of a column with default value. Hence we first drop the default constraint +-- and then change the datatype. We wrap the code to drop the default constraint in a stored procedure to avoid +-- code duplicate. We create temporary stored procedures since we do not need them during normal +-- metastore operation. +CREATE PROCEDURE #DROP_DEFAULT_CONSTRAINT @TBL_NAME sysname, @COL_NAME sysname +AS +BEGIN + DECLARE @constraintname sysname + SELECT @constraintname = default_constraints.name + FROM sys.all_columns INNER JOIN sys.tables ON all_columns.object_id = tables.object_id + INNER JOIN sys.schemas ON tables.schema_id = schemas.schema_id + INNER JOIN sys.default_constraints ON all_columns.default_object_id = default_constraints.object_id + WHERE schemas.name = 'dbo' AND tables.name = @TBL_NAME AND all_columns.name = @COL_NAME + + IF (@constraintname IS NOT NULL) + BEGIN + DECLARE @sql nvarchar(max) = 'ALTER TABLE [dbo].' + QUOTENAME(@TBL_NAME) + ' DROP CONSTRAINT ' + QUOTENAME(@constraintname) + EXEC(@sql) + END +END; + +-- Similarly for primary key constraint +CREATE PROCEDURE #DROP_PRIMARY_KEY_CONSTRAINT @TBL_NAME sysname +AS +BEGIN + DECLARE @constraintname sysname + SELECT @constraintname = constraint_name + FROM information_schema.table_constraints + WHERE constraint_type = 'PRIMARY KEY' AND table_schema = 'dbo' AND table_name = @TBL_NAME + IF @constraintname IS NOT NULL + BEGIN + DECLARE @sql_pk nvarchar(max) = 'ALTER TABLE [dbo].' + QUOTENAME(@TBL_NAME) + ' DROP CONSTRAINT ' + @constraintname + EXEC(@sql_pk) + end +END; + +EXEC #DROP_DEFAULT_CONSTRAINT "PARTITION_PARAMS", "PARAM_VALUE"; +ALTER TABLE "PARTITION_PARAMS" ALTER COLUMN "PARAM_VALUE" varchar(max); + -- These lines need to be last. Insert any changes above. UPDATE VERSION SET SCHEMA_VERSION='3.2.0', VERSION_COMMENT='Hive release version 3.2.0' where VER_ID=1;