September 25, 2007 at 10:51 am
Comments posted to this topic are about the item Changing Collation
May 15, 2008 at 2:10 am
ALTER DATABASE mydb COLLATE SQL_Latin1_General_CP1_CI_AS
also can do the trick.
May 12, 2010 at 10:52 am
There are a few bugs in this script that'll catch the unwary. First being 'TEXT' types; they can't actually be given a column length (which the script does), so attempts to collate using this would fail (now intercepted).
Second being nvarchar and nchar types; Running the script will double their length (the reported length is in 8 bit bytes; n{var}char's UTF character set uses 16 bits for character storage).
Also, I've changed the way it works a little; default is now to generate output of the SQL code that'll be executed so you can examine it and if necessary check against the original schema, but more specifically so you can save this file and use it as part of a script such that you can do all the tinkering on a 'test' version of the database before running the final script on the live one (when you're sure the generated script does what you want).
If you still want to run it 'live', you can use the lm_changecollation <collation>,'live' to have it run as it originally did.
Also, to just fix things that are broken (if you get tables that have some badly collated columns) you can constrain it to just move away from a particular collation by adding in a third parameter, so that this only detects and fixes columns of that particular collation.
------------------------------------------------------------
-- LM_ChangeCollation - Change collation in all tables
--
--
--
-- made by Luis Monteiro - ljmonteiro@eurociber.pt
-- Patched 20100512 - Rich James (rich reallyat richjames,me)
-- (Fixed text/ntext and n{var}char bugs)
------------------------------------------------------------
CREATE PROCEDURE [LM_ChangeCollation]
@new_collation varchar(100)=NULL,
@mode char(4)=NULL,
@fixcollate varchar(100)=NULL
AS
DECLARE
@tablevarchar(50),
@column varchar(60),
@typevarchar(20),
@lengthvarchar(4),
@nullablevarchar(8),
@sqlvarchar(8000),
@msgvarchar(8000),
@servercollationvarchar(120)
select @servercollation = convert(sysname, serverproperty('collation'))
DECLARE C1 CURSOR FOR
select
'Table'= b.name,
'Column'= a.name,
'Type'= type_name(a.xusertype),
'Length'= CASE
WHEN type_name(a.xusertype)='nchar'
or
type_name(a.xusertype)='nvarchar'
THEN (a.length/2)
ELSE
a.length
END,
'Nullable'= case when a.isnullable = 0 then 'NOT NULL' else ' ' end
from syscolumns a, sysobjects b
where a.number = 0
and a.id =b.id
and b.xtype='U'
and b.name not like 'dt%'
and type_name(a.xusertype) in ('char', 'varchar', 'nchar', 'nvarchar','text','ntext')
and a.collation like coalesce(@fixcollate,'%')
order by b.name,a.colid
OPEN C1
FETCH NEXT FROM C1
INTO @table,@column,@type,@length,@nullable
WHILE @@FETCH_STATUS=0
BEGIN
IF @new_collation is null
set @new_collation=@servercollation
set @sql='ALTER TABLE [' + @table + '] ALTER COLUMN [' + @column + '] ' + @type
if (@type<>'text' AND @type<>'ntext')
set @sql=@sql+'('+@length+')'
set @sql=@sql+' COLLATE '+@new_collation+' '+@nullable
IF (@mode='live')
EXEC (@sql)
ELSE
print @sql
FETCH NEXT FROM C1
INTO @table,@column,@type,@length,@nullable
END
CLOSE C1
DEALLOCATE C1
GO
Thanks Luis for giving a headstart that saved me boat loads of time!
Viewing 3 posts - 1 through 2 (of 2 total)
You must be logged in to reply to this topic. Login to reply