This is a follow-up to my post for listing all columns with a specific data type.
The goal of the query below is the quickly create all the needed Alter Table statements for the new user defined data type that I'm going to be replacing the old one with.
As stated previously, we are planning on upgrading an older SQL Server 2005 server to SQL Server 2008. In the process we determined that a couple of the columns would need to have their User Defined Data Types updated.
Instead of manually coding the Alter statements, I spent a few minutes creating a select statement that would allow me to copy the results to another SQL window with all the code needed to make the change.
In the process; I like my code to look pretty, oh so pretty. So I'm using a couple of replicate statements to pad out spaces for the code to be created.
-- Get the Maximum TableName Length for the specificed type I'm going to update
DECLARE @MaxTableName int
SET @MaxTableName = (
SELECT MAX(LEN(o.Name))
FROM sys.columns AS c
JOIN sys.types AS t ON c.user_type_id=t.user_type_id
JOIN sys.tables AS o ON c.Object_id = o.Object_ID
Where t.name = 'Date'
and t.is_user_defined = 1
and o.Type = 'U'
)
-- Get the Maximum Column Name length for the type I'm going to update
DECLARE @maxColumnName int
SET @MaxColumnName =
(
SELECT MAX(LEN(c.Name))
FROM sys.columns AS c
JOIN sys.types AS t ON c.user_type_id=t.user_type_id
JOIN sys.tables AS o ON c.Object_id = o.Object_ID
Where t.name = 'Date'
and t.is_user_defined = 1
and o.Type = 'U'
)
-- Now create the pretty Alter statements
-- Will just need to copy the results to a new sql window and
-- you will have all the code needed to fix your problemSELECT ( 'ALTER TABLE dbo.['
+ RTRIM(LTRIM(o.Name))
+ ']'
+ REPLICATE (' ',@MaxTableName-LEN(o.Name))
+ ' ALTER COLUMN ['
+ RTRIM(LTRIM(c.Name) )
+ ']'
+ REPLICATE (' ',@MaxColumnName-LEN(c.Name))
+ ' DateTime NULL'
)
FROM sys.columns AS c
JOIN sys.types AS t ON c.user_type_id=t.user_type_id
JOIN sys.tables AS o ON c.Object_id = o.Object_ID
Where t.name = 'Date'
and t.is_user_defined = 1
and o.Type = 'U'
ORDER BY c.OBJECT_ID
So using the above code I got the resulting output:
ALTER TABLE dbo.[Test1] ALTER COLUMN [Date1] DateTime NULL
ALTER TABLE dbo.[Test1] ALTER COLUMN [Date20] DateTime NULL
ALTER TABLE dbo.[Test11] ALTER COLUMN [Date300] DateTime NULL
ALTER TABLE dbo.[Test11] ALTER COLUMN [Date4] DateTime NULL
ALTER TABLE dbo.[Test11] ALTER COLUMN [Date50] DateTime NULL
ALTER TABLE dbo.[Test1] ALTER COLUMN [Date20] DateTime NULL
ALTER TABLE dbo.[Test11] ALTER COLUMN [Date300] DateTime NULL
ALTER TABLE dbo.[Test11] ALTER COLUMN [Date4] DateTime NULL
ALTER TABLE dbo.[Test11] ALTER COLUMN [Date50] DateTime NULL
No comments:
Post a Comment