Sunday 21 January 2018

How to make uniform all the collations of table columns for all databases

Clearly, it is of paramount importance to standardise the collations for all databases in a SQL Server instance in order to avoid dealing with unforeseen conflicts of page code compatibility. We may find ourselves in complicated situations because databases with different collations were migrated from other environments and the new consolidated environment was not prepared to host those new databases, but in one way or another we may need to consolidate them in only one server. It may be compounded by the fact that there may be many character columns of a database using different collations and another collation at database level. What’s more, the tempdb database may be using another different collation.  So, it may turn out to be not only a complex issue but also time-consuming.
To give you just an example, we can start finding out what character columns are using different collations from SQL_Latin1_General_CP1_CI_AS that we need to change in order to make everything uniform. I am going to display a useful script to do it. In this example I am assuming that we want to use SQL_Latin1_General_CP1_CI_AS for all objects in the database server.

EXEC sp_MSforeachdb '
USE [?]
select db_name(),c.name
from sys.columns c
inner join sys.types t on t.user_type_id= c.user_type_id
inner join sys.tables tb on  c.object_id=tb.object_id
where c.collation_name is not null 
and t.is_user_defined=0 and tb.is_ms_shipped=0 and tb.name<>''sysdiagrams''
and c.collation_name<>''SQL_Latin1_General_CP1_CI_AS''
order by tb.name, c.column_id'

After that,we can make the decision of changing all character columns for all databases and use SQL_Latin1_General_CP1_CI_AS, and then make that change at database level. Be cautious and make sure as well you have tempdb’s collation set SQL_Latin1_General_CP1_CI_AS.

EXEC sp_MSforeachdb '
USE [?]
if db_name() not in (''master'',''tempdb'',''msdb'',''model'')
begin
    select replace( REPLACE( ''ALTER TABLE '' + QUOTENAME(SCHEMA_NAME(tb.schema_id)) + ''.'' 
    + QUOTENAME(tb.name) + '' ALTER COLUMN '' + QUOTENAME(c.name) +  '' '' 
    + QUOTENAME(t.name) + ''('' + CAST( case when T.NAME=''NVARCHAR'' THEN  c.max_length/2 
      WHEN  T.NAME=''NCHAR'' THEN  c.max_length/2 ELSE c.max_length  END  AS VARCHAR(10)) +'')''  
    + '' COLLATE SQL_Latin1_General_CP1_CI_AS'' + CASE WHEN c.is_nullable =1 THEN '' NULL '' 
     else '' NOT NULL ;'' END, ''-1'', ''MAX'' ), ''[text](16)'', ''[varchar](max)'') as cmd
    INTO #TblTMP
    from sys.columns c
    inner join sys.types t on t.user_type_id= c.user_type_id
    inner join sys.tables tb on  c.object_id=tb.object_id
    where c.collation_name is not null 
    and t.is_user_defined=0 and tb.is_ms_shipped=0 and tb.name<>''sysdiagrams''
    and c.collation_name<>''SQL_Latin1_General_CP1_CI_AS''
    order by tb.name, c.column_id
    
  declare @cmd varchar(max)
  declare c_cmd cursor for 
     select cmd from  #TblTMP
  open c_cmd
  fetch next from c_cmd into @cmd
  while (@@fetch_status=0)
  begin    
    exec( @cmd)
    fetch next from c_cmd into @cmd
  end
  close c_cmd
  deallocate c_cmd
  drop table #TblTMP
end'

It is worth noting that while running the script above some errors may arise because of some indexes might be using one of the columns we are trying to alter. So, in this likely event, it is recommendable to drop those indexes and then run the script again. That is all for the time being. Let me know any remarks you may have.

No comments:

Post a Comment

Let me know any remarks or questions you may have. Please write down your name.

HELLO, I'M PERCY REYES! — a book lover, healthy lifestyle lover... I've been working as a senior SQL Server Database Administrator (DBA) for over 20 years; I'm a three-time awarded Microsoft Data Platform MVP. I'm currently doing a PhD in Computer Science (cryptography) at Loughborough University, England — working on cryptographic Boolean functions, algorithmic cryptanalysis, number theory, and other algebraic aspects of cryptography. READ MORE