kreta/Kreta.DataAccess.Migrations/Scripts/Archive/20170327110702_Init/sp_Global_DeleteViews.sql
2024-03-13 00:33:46 +01:00

67 lines
1.7 KiB
Transact-SQL

-- =============================================
-- Description: a megadott view-k törlése a megadott vagy összes sémában
-- =============================================
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
IF OBJECT_ID('dbo.sp_Global_DeleteViews') IS NOT NULL BEGIN
DROP PROCEDURE [dbo].[sp_Global_DeleteViews]
END
GO
CREATE PROCEDURE [dbo].[sp_Global_DeleteViews]
@pSchemaName NVARCHAR(100), -- pl: 'KR_BEDO_Schema' | NULL esetén az összes sémán végigmegy
@pViewNames XML -- pl: '<ViewNames><ViewName>T_TANARTARGYATLAG</ViewName></ViewNames>'
AS
BEGIN
DECLARE @viewName NVARCHAR(4000)
DECLARE @schemaName NVARCHAR(100)
DECLARE @deleteViewSQL NVARCHAR(4000)
DECLARE @schemaNames CURSOR
IF @pSchemaName IS NOT NULL
SET @schemaNames = CURSOR LOCAL FOR
SELECT @pSchemaName
ELSE
SET @schemaNames = CURSOR LOCAL FOR
SELECT name FROM sys.schemas
WHERE principal_id = 1
ORDER BY name
DECLARE @views CURSOR
SET @views = CURSOR LOCAL FOR
SELECT DISTINCT ViewName.value('(.)[1]', 'varchar(100)') FROM @pViewNames.nodes('ViewNames/ViewName') AS ViewNames(ViewName)
OPEN @views
FETCH NEXT FROM @views INTO @viewName
WHILE @@FETCH_STATUS = 0 BEGIN
OPEN @schemaNames
FETCH NEXT FROM @schemaNames INTO @schemaName
WHILE @@FETCH_STATUS = 0 BEGIN
SET @deleteViewSQL = 'IF OBJECT_ID(''[' + @schemaName + '].' + @viewName + ''') IS NOT NULL
DROP VIEW [' + @schemaName + '].' + @viewName
PRINT @viewName + ' ' + @schemaName
EXEC sp_executesql @deleteViewSQL
FETCH NEXT FROM @schemaNames INTO @schemaName
END
CLOSE @schemaNames
FETCH NEXT FROM @views INTO @viewName
END
CLOSE @views
DEALLOCATE @views
DEALLOCATE @schemaNames
END