November 2, 2021 at 4:55 pm
I would like to change definition of all views and want to replace all tables used in view definition with prefix.
if my view is create view ki_co as select * from co
I would like this to be changed to select * from Mst_co.
I want to update all my views automatically. is this possible ?
November 2, 2021 at 6:13 pm
Not automatically. You could view object details right click to generate alter scripts (or create & then replace "CREATE VIEW" with "ALTER VIEW"), and then just do find-and-replace.
Easy if everything is separated by a space; more complicated if there are variations with CR/LF, indents, tab instead of space, or multiple spaces.
Would this apply to joins in views too (e.g., JOIN co, INNER JOIN co, LEFT OUTER JOIN co, etc.)?
You might want to take the opportunity to prefix table names with schema too while you're at it (presumably dbo?).
November 2, 2021 at 6:31 pm
Below is some code that will probably do what you want. I strongly recommend you run it first with the EXEC() commented out. If all of the output looks ok, then uncomment the EXEC() and run it again.
Instead, if table co is going away, you could create a synonym for co that points to Mst_co.
SET ANSI_NULLS ON;
SET QUOTED_IDENTIFIER ON;
DECLARE @location int;
DECLARE @object_id int;
DECLARE @object_name nvarchar(128);
DECLARE @sql nvarchar(max);
DECLARE view_cursor CURSOR LOCAL FAST_FORWARD FOR
SELECT referencing_id AS object_id, OBJECT_NAME(referencing_id) AS object_name
FROM sys.sql_expression_dependencies sed
WHERE OBJECTPROPERTYEX(sed.referencing_id, 'BaseType') = 'V' AND
referenced_entity_name = 'co'
OPEN view_cursor
WHILE 1 = 1
BEGIN
FETCH NEXT FROM view_cursor INTO @object_id, @object_name
IF @@FETCH_STATUS <> 0
BREAK;
SET @sql = OBJECT_DEFINITION(@object_id)
SET @sql = REPLACE(REPLACE(@sql, ' FROM co', ' FROM Mst_co'), 'FROM dbo.co', 'FROM dbo.Mst_co')
SET @location = CHARINDEX('CREATE VIEW ', @sql)
IF @location < CHARINDEX('ALTER VIEW ', @sql)
SET @sql = STUFF(@sql, @location, 11, 'ALTER VIEW')
SELECT @sql AS [/*sql_to_exec*/]
--EXEC(@sql)
END
DEALLOCATE view_cursor
SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".
November 2, 2021 at 9:14 pm
Sorry... post withdrawn. Wrong post.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 4 posts - 1 through 3 (of 3 total)
You must be logged in to reply to this topic. Login to reply