Technical Article

Generate script to change column length of string datatypes in a DB

,

Step 1: Run the script in Part 1 and identify the column data type and size of the column and the column property (NULL / NOT NULL)  and number of columns to be changed.

Step 2: Select the target database and run Part 2, which will generate the script required.

Step 3: Copy the script and execute on the target database and change the column size.

This script can be used for char,nchar,varchar,nvarchar to any size including MAX column length (Refer to Part 3)

One of the use case I can think of this script is changing company name. Due to recent acquisitions, we have to keep changing the company name. Ex:- Company column in the HR / Finance / Revenue / DW databases is declared as varchar(10) / char(8) as you know your company name, now that you have to update your company to the new company which has more charcters then 10 then this script will be handy :).

For me it used to update my jdbc URL column length as we want to add the failover string to the actual jdbc url through out our configuration tables.

email me incase you need more information: cusvenus@gmail.com

PART 1:
======

SELECT OBJECT_NAME(c.OBJECT_ID) tablename, c.name columnname,t.name,c.max_length, 'isnullable' = case
WHEN c.is_nullable = 1 THEN 'NULL'
ELSE 'NOT NULL' END
FROM sys.columns AS c
JOIN sys.types AS t ON c.user_type_id=t.user_type_id
WHERE t.name like '%char' -- data type that has to be changed.
and c.max_length > 400  -- size of the column can be changed.
and OBJECT_NAME(c.OBJECT_ID) not like 'sys%' -- to avoid systables
ORDER BY c.OBJECT_ID;

PART 2:
======

DECLARE @tablename VARCHAR(256)
DECLARE @columnname VARCHAR(256)
DECLARE @isnullable VARCHAR(10)
DECLARE @sqlexec NVARCHAR(500)
DECLARE @datatype VARCHAR(50)
DECLARE @srcsize VARCHAR(5)
DECLARE @targetsize VARCHAR(50)
DECLARE db_cursor CURSOR FOR
SELECT OBJECT_NAME(c.OBJECT_ID) tablename, c.name columnname,t.name,c.max_length, 'isnullable' = case
WHEN c.is_nullable = 1 THEN 'NULL'
ELSE 'NOT NULL' END
FROM sys.columns AS c
JOIN sys.types AS t ON c.user_type_id=t.user_type_id
WHERE t.name like '%char' -- data type that has to be changed.
and c.max_length > 400  -- size of the column can be changed.
and OBJECT_NAME(c.OBJECT_ID) not like 'sys%' -- to avoid systables (This can also be used to avoid any configuration tables)
ORDER BY c.OBJECT_ID;
set @targetsize = '600' -- Target column size to be set
OPEN db_cursor
FETCH NEXT FROM db_cursor INTO @tablename,@columnname,@datatype,@srcsize,@isnullable
WHILE @@FETCH_STATUS = 0
BEGIN
SET @sqlexec = 'alter table ' + @tablename + ' alter column ' +  @columnname +' '+ @datatype + ' ('+@targetsize+') ' + @isnullable
print @sqlexec
FETCH NEXT FROM db_cursor INTO @tablename,@columnname,@datatype,@srcsize,@isnullable
END
CLOSE db_cursor
DEALLOCATE db_cursor

Part 3:
=======
-- For changing the column length to MAX 

DECLARE @tablename VARCHAR(256)
DECLARE @columnname VARCHAR(256)
DECLARE @isnullable VARCHAR(10)
DECLARE @sqlexec NVARCHAR(500)
DECLARE @datatype VARCHAR(50)
DECLARE @srcsize VARCHAR(5)
DECLARE @targetsize VARCHAR(50)
DECLARE db_cursor CURSOR FOR
SELECT OBJECT_NAME(c.OBJECT_ID) tablename, c.name columnname,t.name,c.max_length, 'isnullable' = case
WHEN c.is_nullable = 1 THEN 'NULL'
ELSE 'NOT NULL' END
FROM sys.columns AS c
JOIN sys.types AS t ON c.user_type_id=t.user_type_id
WHERE t.name like '%varchar' -- data type that has to be changed.
and c.max_length > 400  -- size of the column can be changed.
and OBJECT_NAME(c.OBJECT_ID) not like 'sys%' -- to avoid systables (This can also be used to avoid any configuration tables)
ORDER BY c.OBJECT_ID;
set @targetsize = 'MAX' -- Target column size to be set to MAX
OPEN db_cursor
FETCH NEXT FROM db_cursor INTO @tablename,@columnname,@datatype,@srcsize,@isnullable
WHILE @@FETCH_STATUS = 0
BEGIN
SET @sqlexec = 'alter table ' + @tablename + ' alter column ' +  @columnname +' '+ @datatype + ' ('+@targetsize+') ' + @isnullable
print @sqlexec
FETCH NEXT FROM db_cursor INTO @tablename,@columnname,@datatype,@srcsize,@isnullable
END
CLOSE db_cursor
DEALLOCATE db_cursor

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating