Deep Dive into Changing Database Collation

  • Comments posted to this topic are about the item Deep Dive into Changing Database Collation

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • Hi Lowel,

    I did a test of your work on more databases. Here are the remarks:

    The collation of a test database is not changed. I run it on the AdventureWorks2014 databases.

    On another database the following error occurred:

    Msg 8152, Level 16, State 10, Line 390

    String or binary data would be truncated.

    Need to extend the columns for the names, there are databases with indexes names longer than 100 chars.

    Then reserved words like Key, used as a column name, must be scripted as [Key].

    Another error message is the following:

    Msg 2717, Level 16, State 2, Line 395

    The size (8000) given to the parameter 'Params' exceeds the maximum allowed (4000).

    Faild on

    ALTER TABLE [dbo].[Queues] ALTER COLUMN [Params] nvarchar(8000) NOT NULL;

    but [Params] is defined as nvarchar(4000)

    You'd better add GO terminator after every ALTER statement.

    Another issue

    Msg 5074, Level 16, State 1, Line 436

    The object 'AllOddTypes' is dependent on column 'Identifier'.

    Msg 4922, Level 16, State 9, Line 436

    ALTER TABLE ALTER COLUMN Identifier failed because one or more objects access this column.

    You have to work more on the dependency problem.

    I'm sure there are many other bugs, but if you manage to eliminate these, would be better.

    And collation change on database level is not such an easy task.

    Igor Micev,My blog: www.igormicev.com

  • Igor thank you very much for your feedback!

    Your feedback was spot on, and the extra pair of eyes helped enormously.

    because you gave such detailed feedback, i was easily able to fix the following items:

    -- 1.fixed size of #Results table allowed truncation.

    -- 2.column names in indexes and includes are now quotenamed; logic that made assumptions on column name plus comma change dto be the quotenamed column instead.

    -- 3.fixed the nvarchar columns being doubled in size issue.

    -- 4.fixed some minor whitespace issues for aliases like AS Column name and the space before "Unique" when building constraints

    -- 5.moved logic for dropping temp table sot the top so they can be interrogated more easily

    I've modified my script below, to address the items you identified, except for this one:

    Msg 5074, Level 16, State 1, Line 436

    The object 'AllOddTypes' is dependent on column 'Identifier'.

    Msg 4922, Level 16, State 9, Line 436

    ALTER TABLE ALTER COLUMN Identifier failed because one or more objects access this column.

    i'm not sure what object that is,and i think it should have been handled in the call to sp_msdependencies;

    is that in an adventureworks database? If it is not,could i trouble you to script it out? i'm guessing it might be a TVF that gets rows with odd numbered [Identifier] values.

    --#################################################################################################

    --Collation Changer Version 1.03 by Lowell

    --because of a reference to 'sys.sql_expression_dependencies', this is valid only

    --For SQL2008 and above.

    --Brainstorm: first map out a list of all the objects to change;

    --simple constraints

    --STEP_001 check constraints

    --STEP_002 default constraints

    --STEP_003 calculated column definitions

    --STEP_004 foreign key constraints

    --complex constraints and indexes (unique/pk/regular/includes/filtered indexes)

    --STEP_005 primary keys

    --STEP_006 unique indexes

    --STEP_007 regular indexes(also featuring includes or filtered indexes)

    --columns themselves

    --STEP_008 Column Collation definitions

    --views that reference any of the object tables

    --STEP_009 refresh dependent views, procs and functions

    --Version 1.01 changes:

    --2016-03-07 added improvements related to Igor Micev sggestions found here:

    -- http://www.sqlservercentral.com/Forums/Topic1767151-566-1.aspx

    -- 1.fixed size of #Results table allowed truncation.

    -- 2.column names in indexes and includes are now quotenamed; logic that made assumptions on column name plus comma change dto be the quotenamed column instead.

    -- 3.fixed the nvarchar columns being doubled in size issue.

    -- 4.fixed some minor whitespace issues for aliases like AS Column name and the space before "Unique" when building constraints

    -- 5.moved logic for dropping temp table sot the top so they can be interrogated more easily

    --Version 1.02 Changes

    --fixed case sensitive issues found by mister.magoo http://www.sqlservercentral.com/Forums/FindPost1767225.aspx

    -- 1.OBJECT_ID was wrong case lines 330,336

    -- 2.ROWS had wrong case line 332

    -- 3.sp_msdependencies ahd wrong case line 573

    --added enhancements found by Outback http://www.sqlservercentral.com/Forums/FindPost1768453.aspx

    -- 1. Foreign keys did not have ON DELETE/ON UPDATE options.

    -- 2. Added not for replication for FK as well

    -- 3. Index Creation was incorrect for unique/clustered items that were not contraints.

    --#################################################################################################

    --#################################################################################################

    --Declare and assign our lone variable

    --#################################################################################################

    DECLARE @NewCollation VARCHAR(128) = 'Latin1_General_CI_AS'; --'SQL_Latin1_General_CP1_CI_AS' -- change this to the collation that you need

    --WAS 'SQL_Latin1_General_CP1_CI_AS'

    --toggling 'Latin1_General_CI_AS'

    IF OBJECT_ID('tempdb.[dbo].[#Results]') IS NOT NULL

    DROP TABLE [dbo].[#Results];

    CREATE TABLE [dbo].[#Results] (

    [ID] INT IDENTITY(1,1) NOT NULL PRIMARY KEY,

    [ExecutionOrder] INT NOT NULL,

    [Command] NVARCHAR(max) NULL);

    INSERT INTO #Results

    (ExecutionOrder,Command)

    SELECT

    0 AS ExecutionOrder, '--Suite of commands to change collation of all columns that are not currently ' + QUOTENAME(@NewCollation) AS Command;

    --#################################################################################################

    --Start a transaction? might cause huge bloating of the transaction log, but too bad.

    --#################################################################################################

    ----INSERT INTO #Results

    ---- (ExecutionOrder,Command)

    ----SELECT 1,'SET XACT_ABORT ON' UNION ALL

    ----SELECT 2,'BEGIN TRAN' UNION ALL

    ----SELECT 1000, 'COMMIT TRAN'

    IF (SELECT

    OBJECT_ID('Tempdb.dbo.#MyAffectedTables')) IS NOT NULL

    DROP TABLE #MyAffectedTables;

    SELECT

    objz.object_id,

    SCHEMA_NAME(objz.schema_id) AS SchemaName,

    objz.name AS TableName,

    colz.name AS ColumnName,

    colz.collation_name,

    colz.column_id

    INTO

    #MyAffectedTables

    FROM sys.columns colz

    INNER JOIN sys.tables objz

    ON colz.object_id = objz.object_id

    WHERE colz.collation_name IS NOT NULL

    AND objz.is_ms_shipped = 0

    AND colz.is_computed = 0

    AND colz.collation_name <> @NewCollation;

    --AND colz.collation_name <> @NewCollation

    --#################################################################################################

    --STEP_001 check constriants

    --#################################################################################################

    INSERT INTO #Results

    (ExecutionOrder,Command)

    SELECT

    10 AS ExecutionOrder,

    CONVERT(VARCHAR(8000), 'ALTER TABLE ' + QUOTENAME(tabz.SchemaName) + '.' + QUOTENAME(tabz.TableName) + ' DROP CONSTRAINT ' + QUOTENAME(conz.name) + ';') AS Command

    FROM sys.check_constraints conz

    INNER JOIN #MyAffectedTables tabz

    ON conz.parent_object_id = tabz.object_id

    AND conz.parent_column_id = tabz.column_id;

    --add the recreation of the constraints.

    INSERT INTO #Results

    (ExecutionOrder,Command)

    SELECT

    100 AS ExecutionOrder,

    CONVERT(VARCHAR(8000), 'ALTER TABLE ' + QUOTENAME(tabz.SchemaName) + '.' + QUOTENAME(tabz.TableName) + ' ADD CONSTRAINT ' + QUOTENAME(conz.name) + ' CHECK ' + conz.definition + ';') AS Command

    FROM sys.check_constraints conz

    INNER JOIN #MyAffectedTables tabz

    ON conz.parent_object_id = tabz.object_id

    AND conz.parent_column_id = tabz.column_id;

    --#################################################################################################

    --STEP_002 default constriants

    --#################################################################################################

    /*--visualize the data

    SELECT *

    FROM sys.default_constraints conz

    INNER JOIN #MyAffectedTables tabz

    ON conz.parent_object_id = tabz.object_id

    AND conz.parent_column_id = tabz.column_id

    */

    INSERT INTO #Results

    (ExecutionOrder,Command)

    SELECT

    20 AS ExecutionOrder,

    CONVERT(VARCHAR(8000), 'ALTER TABLE ' + QUOTENAME(tabz.SchemaName) + '.' + QUOTENAME(tabz.TableName) + ' DROP CONSTRAINT ' + QUOTENAME(conz.name) + ';') AS Command

    FROM sys.default_constraints conz

    INNER JOIN #MyAffectedTables tabz

    ON conz.parent_object_id = tabz.object_id

    AND conz.parent_column_id = tabz.column_id;

    INSERT INTO #Results

    (ExecutionOrder,Command)

    SELECT

    200 AS ExecutionOrder,

    CONVERT(VARCHAR(8000), 'ALTER TABLE ' + QUOTENAME(tabz.SchemaName) + '.' + QUOTENAME(tabz.TableName) + ' ADD CONSTRAINT ' + QUOTENAME(conz.name) + ' DEFAULT ' + conz.definition + ' FOR ' + quotename(tabz.ColumnName) + ';') AS Command

    FROM sys.default_constraints conz

    INNER JOIN #MyAffectedTables tabz

    ON conz.parent_object_id = tabz.object_id

    AND conz.parent_column_id = tabz.column_id;

    --#################################################################################################

    --STEP_003 calculated columns : refering internal columns to the table

    --#################################################################################################

    --need distinct in case of a calculated columns appending two or more columns together: we need the definition only once.

    INSERT INTO #Results

    (ExecutionOrder,Command)

    SELECT

    DISTINCT

    30 AS ExecutionOrder,

    'ALTER TABLE ' + QUOTENAME(SCHEMA_NAME(objz.schema_id)) + '.' + QUOTENAME(objz.name) + ' DROP COLUMN ' + QUOTENAME(colz.name) + ';' AS Command

    FROM sys.columns colz

    LEFT OUTER JOIN sys.tables objz

    ON colz.[object_id] = objz.[object_id]

    LEFT OUTER JOIN sys.computed_columns CALC

    ON colz.[object_id] = CALC.[object_id]

    AND colz.[column_id] = CALC.[column_id]

    --only calculations referencing columns

    LEFT OUTER JOIN sys.sql_expression_dependencies depz

    ON colz.object_id = depz.referenced_id

    AND colz.column_id = depz.referencing_minor_id

    INNER JOIN #MyAffectedTables tabz

    ON depz.referenced_id = tabz.object_id

    AND depz.referenced_minor_id = tabz.column_id

    WHERE colz.is_computed = 1;

    INSERT INTO #Results

    (ExecutionOrder,Command)

    SELECT

    DISTINCT

    300 AS ExecutionOrder,

    'ALTER TABLE ' + QUOTENAME(SCHEMA_NAME(objz.schema_id)) + '.' + QUOTENAME(objz.name) + ' ADD ' + QUOTENAME(colz.name) + ' AS ' + ISNULL(CALC.definition, '')

    + CASE

    WHEN CALC.is_persisted = 1

    THEN ' PERSISTED'

    ELSE ''

    END + ';' AS Command

    FROM sys.columns colz

    LEFT OUTER JOIN sys.tables objz

    ON colz.[object_id] = objz.[object_id]

    LEFT OUTER JOIN sys.computed_columns CALC

    ON colz.[object_id] = CALC.[object_id]

    AND colz.[column_id] = CALC.[column_id]

    --only calculations referencing columns

    LEFT OUTER JOIN sys.sql_expression_dependencies depz

    ON colz.object_id = depz.referenced_id

    AND colz.column_id = depz.referencing_minor_id

    INNER JOIN #MyAffectedTables tabz

    ON depz.referenced_id = tabz.object_id

    AND depz.referenced_minor_id = tabz.column_id

    WHERE colz.is_computed = 1;

    --#################################################################################################

    --STEP_004 foreign key constriants :child references

    --#################################################################################################

    /*--visualize the data

    --at least in my case, it is very rare to have a char column as the value for a FK; my FK's are all int/bigint

    --I had to create a fake pair of tables to test this.

    */

    INSERT INTO #Results

    (ExecutionOrder,Command)

    SELECT

    DISTINCT

    40 AS ExecutionOrder,

    CONVERT(VARCHAR(8000), 'ALTER TABLE ' + QUOTENAME(tabz.SchemaName) + '.' + QUOTENAME(tabz.TableName) + ' DROP CONSTRAINT ' + QUOTENAME(conz.name) + ';') AS Command

    FROM sys.foreign_keys conz

    INNER JOIN sys.foreign_key_columns colz

    ON conz.object_id = colz.constraint_object_id

    INNER JOIN #MyAffectedTables tabz

    ON conz.parent_object_id = tabz.object_id

    WHERE tabz.object_id = colz.parent_object_id

    AND tabz.column_id = colz.parent_column_id;

    --foreign keys, potentially, can span multiple keys;

    --'scriptlet to do all FK's for reference.

    INSERT INTO #Results

    (ExecutionOrder,Command)

    SELECT

    DISTINCT

    --FK must be added AFTER the PK/unique constraints are added back.

    850 AS ExecutionOrder,

    'ALTER TABLE '

    + QUOTENAME(schema_name(conz.schema_id) )

    + '.'

    + QUOTENAME(OBJECT_NAME(conz.parent_object_id))

    + ' ADD CONSTRAINT '

    + QUOTENAME(conz.name)

    + ' FOREIGN KEY ('

    + ChildCollection.ChildColumns

    + ') REFERENCES '

    + QUOTENAME(SCHEMA_NAME(conz.schema_id))

    + '.'

    + QUOTENAME(OBJECT_NAME(conz.referenced_object_id))

    + ' (' + ParentCollection.ParentColumns

    + ') '

    + ' ON UPDATE ' + CASE conz.update_referential_action

    WHEN 0 THEN 'NO ACTION '

    WHEN 1 THEN 'CASCADE '

    WHEN 2 THEN 'SET NULL '

    ELSE 'SET DEFAULT '

    END

    + ' ON DELETE ' + CASE conz.delete_referential_action

    WHEN 0 THEN 'NO ACTION '

    WHEN 1 THEN 'CASCADE '

    WHEN 2 THEN 'SET NULL '

    ELSE 'SET DEFAULT '

    END

    + CASE conz.is_not_for_replication

    WHEN 1 THEN ' NOT FOR REPLICATION '

    ELSE ''

    END

    + ';' AS Command

    FROM sys.foreign_keys conz

    INNER JOIN sys.foreign_key_columns colz

    ON conz.object_id = colz.constraint_object_id

    INNER JOIN #MyAffectedTables tabz

    ON conz.parent_object_id = tabz.object_id

    AND tabz.column_id = colz.parent_column_id

    INNER JOIN (--gets my child tables column names

    SELECT

    conz.name,

    ChildColumns = STUFF((SELECT

    ',' + REFZ.name

    FROM sys.foreign_key_columns fkcolz

    INNER JOIN sys.columns REFZ

    ON fkcolz.parent_object_id = REFZ.object_id

    AND fkcolz.parent_column_id = REFZ.column_id

    WHERE fkcolz.parent_object_id = conz.parent_object_id

    AND fkcolz.constraint_object_id = conz.object_id

    ORDER BY

    fkcolz.constraint_column_id

    FOR XML PATH('')), 1, 1, '')

    FROM sys.foreign_keys conz

    INNER JOIN sys.foreign_key_columns colz

    ON conz.object_id = colz.constraint_object_id

    GROUP BY

    conz.name,

    conz.parent_object_id,--- without GROUP BY multiple rows are returned

    conz.object_id

    ) ChildCollection

    ON conz.name = ChildCollection.name

    INNER JOIN (--gets the parent tables column names for the FK reference

    SELECT

    conz.name,

    ParentColumns = STUFF((SELECT

    ',' + REFZ.name

    FROM sys.foreign_key_columns fkcolz

    INNER JOIN sys.columns REFZ

    ON fkcolz.referenced_object_id = REFZ.object_id

    AND fkcolz.referenced_column_id = REFZ.column_id

    WHERE fkcolz.referenced_object_id = conz.referenced_object_id

    AND fkcolz.constraint_object_id = conz.object_id

    ORDER BY fkcolz.constraint_column_id

    FOR XML PATH('')), 1, 1, '')

    FROM sys.foreign_keys conz

    INNER JOIN sys.foreign_key_columns colz

    ON conz.object_id = colz.constraint_object_id

    -- AND colz.parent_column_id

    GROUP BY

    conz.name,

    conz.referenced_object_id,--- without GROUP BY multiple rows are returned

    conz.object_id

    ) ParentCollection

    ON conz.name = ParentCollection.name;

    --#################################################################################################

    --STEP_005, 006 and 007 primary keys,unique indexes,regular indexes

    --#################################################################################################

    /*pre-quel sequel to gather the data:*/

    IF (SELECT

    OBJECT_ID('Tempdb.dbo.#Indexes')) IS NOT NULL

    DROP TABLE #Indexes;

    SELECT

    CASE

    WHEN is_primary_key = 1

    THEN 'ALTER TABLE ' + QUOTENAME(SCHEMA_NAME) + '.' + QUOTENAME(OBJECT_NAME) + ' DROP CONSTRAINT ' + QUOTENAME(index_name) + ';'

    WHEN is_unique_constraint = 1

    THEN 'ALTER TABLE ' + QUOTENAME(SCHEMA_NAME) + '.' + QUOTENAME(OBJECT_NAME) + ' DROP CONSTRAINT ' + QUOTENAME(index_name) + ';'

    ELSE 'DROP INDEX ' + +QUOTENAME(index_name) + ' ON ' + QUOTENAME(SCHEMA_NAME) + '.' + QUOTENAME(OBJECT_NAME) + ';'

    END COLLATE database_default AS c1,

    CASE

    WHEN is_primary_key = 1

    THEN 'ALTER TABLE ' + QUOTENAME(SCHEMA_NAME) + '.' + QUOTENAME(OBJECT_NAME) + ' ADD CONSTRAINT ' + QUOTENAME(index_name) + ' PRIMARY KEY '

    + CASE

    WHEN type_desc = 'CLUSTERED'

    THEN type_desc

    ELSE ''

    END + ' (' + index_columns_key + ')' + ';'

    WHEN is_unique_constraint = 1

    THEN 'ALTER TABLE ' + QUOTENAME(SCHEMA_NAME) + '.' + QUOTENAME(OBJECT_NAME) + ' ADD CONSTRAINT ' + QUOTENAME(index_name) + ' UNIQUE (' + index_columns_key + ')' + ';'

    --ELSE 'DROP INDEX IX_ProductVendor_BusinessEntityID ON Purchasing.ProductVendor WITH (ONLINE = ON, MAXDOP = 2)'

    ELSE 'CREATE '

    + CASE

    WHEN is_unique = 1

    THEN 'UNIQUE '

    ELSE ''

    END

    + CASE

    WHEN index_id = 1

    THEN 'CLUSTERED '

    ELSE ''

    END

    + 'INDEX ' + +QUOTENAME(index_name) + ' ON ' + +QUOTENAME(SCHEMA_NAME) + '.' + QUOTENAME(OBJECT_NAME) + ' (' + index_columns_key + ')'

    + CASE

    WHEN index_columns_include = '---'

    THEN ''

    ELSE ' INCLUDE (' + index_columns_include + ')'

    END

    + CASE

    WHEN has_filter = 0

    THEN ''

    ELSE ' WHERE ' + filter_definition + ' '

    END + ';'

    END COLLATE database_default AS c2,

    *

    INTO

    #INDEXES

    FROM (SELECT

    SCH.schema_id,

    SCH.[name] COLLATE database_default AS SCHEMA_NAME,

    OBJS.[object_id],

    OBJS.[name] COLLATE database_default AS OBJECT_NAME,

    IDX.index_id,

    ISNULL(IDX.[name], '---') COLLATE database_default AS index_name,

    partitions.Rows,

    partitions.SizeMB,

    INDEXPROPERTY(OBJS.[object_id], IDX.[name], 'IndexDepth') AS IndexDepth,

    IDX.type,

    IDX.type_desc COLLATE database_default AS type_desc,

    IDX.fill_factor,

    IDX.is_unique,

    IDX.is_primary_key,

    IDX.is_unique_constraint,

    IDX.has_filter,

    IDX.filter_definition,

    ISNULL(Index_Columns.index_columns_key, '---') COLLATE database_default AS index_columns_key,

    ISNULL(Index_Columns.index_columns_include, '---') COLLATE database_default AS index_columns_include

    FROM sys.objects OBJS

    INNER JOIN sys.schemas SCH

    ON OBJS.schema_id = SCH.schema_id

    INNER JOIN sys.indexes IDX

    ON OBJS.[object_id] = IDX.[object_id]

    INNER JOIN (SELECT

    [object_id],

    index_id,

    SUM(row_count) AS Rows,

    CONVERT(NUMERIC(19, 3), CONVERT(NUMERIC(19, 3), SUM(in_row_reserved_page_count+lob_reserved_page_count+row_overflow_reserved_page_count))/CONVERT(NUMERIC(19, 3), 128)) AS SizeMB

    FROM sys.dm_db_partition_stats STATS

    GROUP BY

    [object_id],

    index_id) AS partitions

    ON IDX.[object_id] = partitions.[object_id]

    AND IDX.index_id = partitions.index_id

    CROSS APPLY (SELECT

    LEFT(index_columns_key, LEN(index_columns_key) - 1) COLLATE database_default AS index_columns_key,

    LEFT(index_columns_include, LEN(index_columns_include) - 1) COLLATE database_default AS index_columns_include

    FROM (SELECT

    (SELECT

    quotename(colz.[name]) + ',' + ' ' COLLATE database_default

    FROM sys.index_columns IXCOLS

    INNER JOIN sys.columns colz

    ON IXCOLS.column_id = colz.column_id

    AND IXCOLS.[object_id] = colz.[object_id]

    WHERE IXCOLS.is_included_column = 0

    AND IDX.[object_id] = IXCOLS.[object_id]

    AND IDX.index_id = IXCOLS.index_id

    ORDER BY

    key_ordinal

    FOR XML PATH('')) AS index_columns_key,

    (SELECT

    quotename(colz.[name]) + ',' + ' ' COLLATE database_default

    FROM sys.index_columns IXCOLS

    INNER JOIN sys.columns colz

    ON IXCOLS.column_id = colz.column_id

    AND IXCOLS.[object_id] = colz.[object_id]

    WHERE IXCOLS.is_included_column = 1

    AND IDX.[object_id] = IXCOLS.[object_id]

    AND IDX.index_id = IXCOLS.index_id

    ORDER BY

    index_column_id

    FOR XML PATH('')) AS index_columns_include) AS Index_Columns) AS Index_Columns)AllIndexes

    --#################################################################################################

    --STEP_005 primary keys

    --#################################################################################################

    INSERT INTO #Results

    (ExecutionOrder,Command)

    SELECT

    DISTINCT

    50 AS ExecutionOrder,

    IDXZ.c1 AS Command

    FROM #Indexes IDXZ

    LEFT OUTER JOIN #MyAffectedTables TBLZ

    ON IDXZ.object_name = TBLZ.TableName

    WHERE is_primary_key = 1

    AND ( CHARINDEX(quotename(TBLZ.ColumnName) , quotename(IDXZ.index_columns_key) ) > 0

    OR CHARINDEX(quotename(TBLZ.ColumnName) , quotename(IDXZ.index_columns_key) ) > 0 )

    INSERT INTO #Results

    (ExecutionOrder,Command)

    SELECT

    DISTINCT

    500 AS ExecutionOrder,

    IDXZ.c2 AS Command

    FROM #Indexes IDXZ

    LEFT OUTER JOIN #MyAffectedTables TBLZ

    ON IDXZ.object_name = TBLZ.TableName

    WHERE is_primary_key = 1

    AND ( CHARINDEX(quotename(TBLZ.ColumnName) , quotename(IDXZ.index_columns_key) ) > 0

    OR CHARINDEX(quotename(TBLZ.ColumnName) , quotename(IDXZ.index_columns_key) ) > 0 )

    --#################################################################################################

    --STEP_006 unique indexes

    --#################################################################################################

    INSERT INTO #Results

    (ExecutionOrder,Command)

    SELECT

    DISTINCT

    60 AS ExecutionOrder,

    IDXZ.c1 AS Command

    FROM #Indexes IDXZ

    LEFT OUTER JOIN #MyAffectedTables TBLZ

    ON IDXZ.object_name = TBLZ.TableName

    WHERE IDXZ.is_primary_key = 0

    AND IDXZ.is_unique_constraint = 1

    AND ( CHARINDEX(quotename(TBLZ.ColumnName) , quotename(IDXZ.index_columns_key) ) > 0

    OR CHARINDEX(quotename(TBLZ.ColumnName) , quotename(IDXZ.index_columns_key) ) > 0 )

    INSERT INTO #Results

    (ExecutionOrder,Command)

    SELECT

    DISTINCT

    600 AS ExecutionOrder,

    IDXZ.c2 AS Command

    FROM #Indexes IDXZ

    LEFT OUTER JOIN #MyAffectedTables TBLZ

    ON IDXZ.object_name = TBLZ.TableName

    WHERE IDXZ.is_primary_key = 0

    AND IDXZ.is_unique_constraint = 1

    AND ( CHARINDEX(quotename(TBLZ.ColumnName) , quotename(IDXZ.index_columns_key) ) > 0

    OR CHARINDEX(quotename(TBLZ.ColumnName) , quotename(IDXZ.index_columns_key) ) > 0 )

    --#################################################################################################

    --STEP_007 regular indexes(also featuring includes or filtered indexes

    --#################################################################################################

    INSERT INTO #Results

    (ExecutionOrder,Command)

    SELECT

    DISTINCT

    70 AS ExecutionOrder,

    IDXZ.c1 AS Command

    FROM #Indexes IDXZ

    LEFT OUTER JOIN #MyAffectedTables TBLZ

    ON IDXZ.object_name = TBLZ.TableName

    WHERE IDXZ.is_primary_key = 0

    AND IDXZ.is_unique_constraint = 0

    AND ( CHARINDEX(quotename(TBLZ.ColumnName) , quotename(IDXZ.index_columns_key) ) > 0

    OR CHARINDEX(quotename(TBLZ.ColumnName) , quotename(IDXZ.index_columns_key) ) > 0 )

    INSERT INTO #Results

    (ExecutionOrder,Command)

    SELECT

    DISTINCT

    700 AS ExecutionOrder,

    IDXZ.c2 AS Command

    FROM #Indexes IDXZ

    LEFT OUTER JOIN #MyAffectedTables TBLZ

    ON IDXZ.object_name = TBLZ.TableName

    WHERE IDXZ.is_primary_key = 0

    AND IDXZ.is_unique_constraint = 0

    AND ( CHARINDEX(quotename(TBLZ.ColumnName) , quotename(IDXZ.index_columns_key) ) > 0

    OR CHARINDEX(quotename(TBLZ.ColumnName) , quotename(IDXZ.index_columns_key) ) > 0 )

    --#################################################################################################

    --STEP_008 Column Collation definitions

    --#################################################################################################

    INSERT INTO #Results

    (ExecutionOrder,Command)

    SELECT

    DISTINCT

    80 AS ExecutionOrder,

    'ALTER TABLE ' + QUOTENAME(SCHEMA_NAME(objz.schema_id)) + '.' + QUOTENAME(objz.name) + ' ALTER COLUMN '

    + CASE

    WHEN colz.[is_computed] = 0

    THEN QUOTENAME(colz.[name]) + ' ' + ( TYPE_NAME(colz.[user_type_id]) )

    + CASE

    WHEN TYPE_NAME(colz.[user_type_id]) IN ( 'char', 'varchar' )

    THEN

    CASE

    WHEN colz.[max_length] = -1

    THEN '(max)' + SPACE(6 - LEN(CONVERT(VARCHAR, colz.[max_length]))) + SPACE(7) + SPACE(16 - LEN(TYPE_NAME(colz.[user_type_id])))

    ----collate to comment out when not desired

    + CASE

    WHEN colz.collation_name IS NULL

    THEN ''

    ELSE ' COLLATE ' + @NewCollation -- this was the old collation: colz.collation_name

    END + CASE

    WHEN colz.[is_nullable] = 0

    THEN ' NOT NULL'

    ELSE ' NULL'

    END

    ELSE '(' + CONVERT(VARCHAR, colz.[max_length] ) + ') ' + SPACE(6 - LEN(CONVERT(VARCHAR, colz.[max_length]))) + SPACE(7) + SPACE(16 - LEN(TYPE_NAME(colz.[user_type_id])))

    ----collate to comment out when not desired

    + CASE

    WHEN colz.collation_name IS NULL

    THEN ''

    ELSE ' COLLATE ' + @NewCollation

    END

    + CASE

    WHEN colz.[is_nullable] = 0

    THEN ' NOT NULL'

    ELSE ' NULL'

    END

    END

    WHEN TYPE_NAME(colz.[user_type_id]) IN ( 'nchar', 'nvarchar' )

    THEN

    CASE

    WHEN colz.[max_length] = -1

    THEN '(max)' + SPACE(6 - LEN(CONVERT(VARCHAR, (colz.[max_length] / 2)))) + SPACE(7) + SPACE(16 - LEN(TYPE_NAME(colz.[user_type_id])))

    ----collate to comment out when not desired

    + CASE

    WHEN colz.collation_name IS NULL

    THEN ''

    ELSE ' COLLATE ' + @NewCollation -- this was the old collation: colz.collation_name

    END

    + CASE

    WHEN colz.[is_nullable] = 0

    THEN ' NOT NULL'

    ELSE ' NULL'

    END

    ELSE '(' + CONVERT(VARCHAR, (colz.[max_length] / 2)) + ') ' + SPACE(6 - LEN(CONVERT(VARCHAR, (colz.[max_length])))) + SPACE(7) + SPACE(16 - LEN(TYPE_NAME(colz.[user_type_id])))

    + CASE

    WHEN colz.collation_name IS NULL

    THEN ''

    ELSE ' COLLATE ' + @NewCollation -- this was the old collation: colz.collation_name

    END

    + CASE

    WHEN colz.[is_nullable] = 0

    THEN ' NOT NULL'

    ELSE ' NULL'

    END

    END

    END

    END --iscomputed = 0

    + ';' AS Command

    FROM sys.columns colz

    LEFT OUTER JOIN sys.tables objz

    ON colz.object_id = objz.object_id

    INNER JOIN #MyAffectedTables tabz

    ON tabz.object_id = colz.object_id

    AND tabz.column_id = colz.column_id

    WHERE objz.type = 'U'

    AND TYPE_NAME(colz.[user_type_id]) IN ( 'char', 'varchar', 'nchar', 'nvarchar' )

    --#################################################################################################

    --STEP_009 refresh dependent views, procs and functions

    -- refresh them in dependancy order in a single pass.

    --#################################################################################################

    --if there was nothing with the wrong collation, there's no need to refresh:

    IF (SELECT

    OBJECT_ID('Tempdb.dbo.#MyObjectHierarchy')) IS NOT NULL

    DROP TABLE #MyObjectHierarchy

    IF EXISTS(SELECT * FROM #Results WHERE ExecutionOrder > 0)

    BEGIN

    CREATE TABLE #MyObjectHierarchy

    (

    HID int identity(1,1) not null primary key,

    ObjectId int,

    TYPE int,OBJECTTYPE AS CASE

    WHEN TYPE = 1 THEN 'FUNCTION'

    WHEN TYPE = 4 THEN 'VIEW'

    WHEN TYPE = 8 THEN 'TABLE'

    WHEN TYPE = 16 THEN 'PROCEDURE'

    WHEN TYPE =128 THEN 'RULE'

    ELSE ''

    END,

    ONAME varchar(255),

    OOWNER varchar(255),

    SEQ int

    )

    --our list of objects in dependancy order

    INSERT #MyObjectHierarchy (TYPE,ONAME,OOWNER,SEQ)

    -- use this if inside a stored procedure

    -- EXEC sp_MSdependencies @intrans = 1

    --else

    EXEC sp_MSdependencies

    INSERT INTO #Results

    (ExecutionOrder,Command)

    SELECT

    900 + HID AS ExecutionOrder,

    CASE

    WHEN OBJECTTYPE = 'VIEW'

    THEN 'EXEC sp_refreshview ''' + QUOTENAME(OOWNER) + '.' + QUOTENAME(ONAME) + ''';'

    WHEN OBJECTTYPE IN ('FUNCTION' ,'PROCEDURE')

    THEN 'EXEC sp_recompile ''' + QUOTENAME(OOWNER) + '.' + QUOTENAME(ONAME) + ''';'

    END

    FROM #MyObjectHierarchy

    WHERE OBJECTTYPE IN('FUNCTION','VIEW','PROCEDURE')

    ORDER BY HID

    END --Exists

    --#################################################################################################

    --Final Presentation

    --#################################################################################################

    SELECT

    ID,ExecutionOrder,Command + CHAR(13) + CHAR(10) + 'GO' + CHAR(13) + CHAR(10)

    FROM #Results

    ORDER BY

    ExecutionOrder,

    ID

    --#################################################################################################

    --optional cursor to go ahead and run all these scripts

    --don't run this cursor unless you are 100% sure of the scripts.

    --TEST TEST TEST!

    --#################################################################################################

    /*

    declare

    @isql varchar(max)

    declare c1 cursor LOCAL FORWARD_ONLY STATIC READ_ONLY for

    --###############################################################################################

    --cursor definition

    --###############################################################################################

    SELECT

    Command

    FROM #Results

    ORDER BY

    ExecutionOrder,

    ID

    --###############################################################################################

    open c1

    fetch next from c1 into @isql

    While @@fetch_status <> -1

    begin

    print @isql

    exec(@isql)

    fetch next from c1 into @isql

    end

    close c1

    deallocate c1

    */

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • I haven't run the change scripts, but did find these issues in Version 1.0:

    Lines 330, 332, 336 : inconsistent case on column names breaks script under CS collations.

    Line 573 : incorrect case on stored procedure name breaks script under CS collations.

    See corrections:

    My test database for this generated ~80,000 change scripts, including dropping and re-creating ~2600 indexes.

    Thankfully I don't need it to change collation on this.

    MM



    select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);

  • Forum Etiquette: How to post Reporting Services problems
  • [/url]
  • Forum Etiquette: How to post data/code on a forum to get the best help - by Jeff Moden
  • [/url]
  • How to Post Performance Problems - by Gail Shaw
  • [/url]

  • Thanks mister magoo! what tool did you use that helps you identify case sensitivity issues like that?

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • Lowell (3/7/2016)


    Thanks mister magoo! what tool did you use that helps you identify case sensitivity issues like that?

    No tool, just SSMS showing errors for column names not being recognised. Working in BIN collations a lot makes you sensitive to these...

    MM



    select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);

  • Forum Etiquette: How to post Reporting Services problems
  • [/url]
  • Forum Etiquette: How to post data/code on a forum to get the best help - by Jeff Moden
  • [/url]
  • How to Post Performance Problems - by Gail Shaw
  • [/url]

  • I wouldn't do it this way at all - I'd bcp out all the tables to be changed with -c -C<old code page> then bcp in with -c -C<new code page>. A simpler way to do this for those that don't know the correct code page names is to bcp in and out using the -w (unicode) switch.

  • hi lowell ,it is an excellent article and i test it on my machine .

    and i got the same error as igor's , it is caused by table level check constraint .

  • Need to be very careful of joins with other tables, both for same-collation joins that will now have different collations during the migration process, and different-collation joins that will now have to be adjusted.

    As you wrote, a huge problem.

  • you might have saved me a lot of time with this script! 🙂

    I "inherited" 7500 databases - unfortunately one of the server monkeys built a server with a default collation of sql_latin1_general_ci_as... rather than a windows collation.

    I've tried BCP out and back in, but I still have to script FKs and then build the tables in the right order (a painfull try and fail repeatedly exercise)

    my approach here is to use your code to build scripts I can check in to Team foundation server and tackle one table at a time (if possible)

    nice to have tools like this

    MVDBA

  • Nice catches. Also, clever signature.

  • As far as one suggestion that we could just BCP out/in data in appropriate collations...

    This would work if all a database contained were heaps. Unfortunately, that isn't the case for many.

    This is a particularly annoying problem I'm surprised a native tool wasn't written for it. Atlassian's Jira and Confluence products required collation changes at one time due to lazy programmers changing collation to fix some other unrelated issue (from what I can gather in community forums). Unfortunately, this meant performing precisely one of these operations on a database that people didn't even design themselves! Our IT staff is having to look at this since we're behind and they want our (DB OPS) help. We're also going to have to do it for two reasons: on instance, we're leaving their cloud offering for local in-house, and two, we're upgrading versions. It's a nightmare getting involved in a product that you don't own or maintain save for backups.

  • Lowell, Thanks for this, you saved me a bunch of work this week. I had a couple vendor installed databases that had wrong collation. I was able to use your script to fix them. A few issues I ran across testing your script:

    1)Doubling of nvarchar size - I see you were already notifed on this so won't go into detail

    2)Foreign Key creation - I had several foreign keys that were set up with ON DELETE CASCADE. This was lost on your rebuild of the foreign key constraint. I add the following code to the end of the select that builds the statement to fix:

    + CASE

    WHEN conz.delete_referential_action = 1

    THEN ' ON DELETE CASCADE'

    ELSE ''

    END

    3)Index Creation - I had issues with unique indexes that were built using a create index statement vs a unique constraint. Also had issues with clustered indexes that were not set up as a primary key. Your create index build would only create non-unique, nonclustered indexes. In your

    /*pre-quel sequel to gather the data:*/ Select I changed the following code:

    ELSE 'CREATE INDEX ' + +QUOTENAME(index_name) + ' ON ' + +QUOTENAME(SCHEMA_NAME) + '.' + QUOTENAME(OBJECT_NAME) + ' (' + index_columns_key + ')'

    To Be:

    ELSE 'CREATE '

    + CASE

    WHEN is_unique = 1

    THEN 'UNIQUE '

    ELSE ''

    END

    + CASE

    WHEN index_id = 1

    THEN 'CLUSTERED '

    ELSE ''

    END

    + 'INDEX ' + +QUOTENAME(index_name) + ' ON ' + +QUOTENAME(SCHEMA_NAME) + '.' + QUOTENAME(OBJECT_NAME) + ' (' + index_columns_key + ')'

    Thanks again

  • Thanks for the article.

  • Hi all,

    Just when I need it, somebody posts a nice script! It's a great start, however, still found some bugs / copy-paste-errors:

    • AND ( CHARINDEX(quotename(TBLZ.ColumnName) , quotename(IDXZ.index_columns_key) ) > 0

      OR CHARINDEX(quotename(TBLZ.ColumnName) , quotename(IDXZ.[highlight="#ffff11"]index_columns_key[/highlight]) ) > 0 )

      should be

      AND ( CHARINDEX(quotename(TBLZ.ColumnName) , quotename(IDXZ.index_columns_key) ) > 0

      OR CHARINDEX(quotename(TBLZ.ColumnName) , quotename(IDXZ.[highlight="#ffff11"]index_columns_include[/highlight]) ) > 0 )

      times 6...

    • QUOTENAME returns NULL if input is greater than 128 characters. In my case, at least included_columns is regularly greater than that
    • compression is totally ignored
    • Cheers!

  • Viewing 15 posts - 1 through 15 (of 15 total)

    You must be logged in to reply to this topic. Login to reply