-- ============================================================================================ -- Schema view-kat generál a paraméterekben megadott táblákhoz és schemákhoz, -- illetve, ha kéteznek akkor frissíti őket. -- -- Ha a @pTables vagy a @pSchemas paraméter értéke NULL, akkor az összes -- táblára/schemára megcsinálja a view-kat -- Amennyiben a dbo-ban van olyan KRÉTAidegen tábla, ami T_-sal kezdődik, van benne -- C_INTEZMENYID oszlop, de nincs benne TOROLT oszlop, valószínüleg el fog szállni az SP. -- @pTables: tábla nevek vesszővel elválasztva, pl.: 'T_TANEV, T_UJTABLA,T_TANULO' -- @pSchemas: schema nevek vesszővel elválasztva, pl.: 'KR_asd_Schema,dbo, KR_dobokata_Schema' -- ============================================================================================ DROP PROCEDURE IF EXISTS dev.uspCreateSchemaViews GO CREATE PROCEDURE dev.uspCreateSchemaViews @pTables nvarchar(max) ,@pSchemas nvarchar(max) = NULL ,@pDebugMode bit = 0 AS BEGIN SET NOCOUNT ON; DECLARE @tableName nvarchar(255) ,@schemaName nvarchar(255) ,@identity nvarchar(10) ,@intezmenyId int ,@tanevId int ,@notExistingObject nvarchar(255) ,@osszesView bit ,@sql nvarchar(max) ,@dbName nvarchar(50) CREATE TABLE #Table ( TableName nvarchar(255) COLLATE DATABASE_DEFAULT PRIMARY KEY ) CREATE TABLE #Schema ( SchemaName nvarchar(255) COLLATE DATABASE_DEFAULT PRIMARY KEY ) IF @pTables IS NOT NULL BEGIN INSERT INTO #Table (TableName) SELECT DISTINCT LTRIM(RTRIM(s.value)) FROM STRING_SPLIT(@pTables, ',') s SET @notExistingObject = NULL SELECT @notExistingObject = ISNULL(@notExistingObject + ', ', '') + s.TableName FROM #Table s WHERE NOT EXISTS ( SELECT 1 FROM sys.tables t WHERE s.TableName COLLATE HUNGARIAN_CI_AS = t.name COLLATE HUNGARIAN_CI_AS AND t.name LIKE 'T[_]%' AND t.schema_id = 1 ) IF @notExistingObject IS NOT NULL BEGIN SET @dbName = DB_NAME() RAISERROR('A paraméterekben megadott táblák közül a követtkezők nem léteznek a %s adatbázisban: %s', 16, 1, @dbName, @notExistingObject) RETURN END END ELSE BEGIN INSERT INTO #Table (TableName) SELECT t.name FROM sys.tables t WHERE t.name like 'T[_]%' AND t.schema_id = 1 AND t.name NOT IN ('T_ENTITYATTRIBUTEHISTORY', 'T_ENTITYHISTORY') END IF @pSchemas IS NOT NULL BEGIN INSERT INTO #Schema (SchemaName) SELECT DISTINCT LTRIM(RTRIM(s.value)) FROM STRING_SPLIT(@pSchemas, ',') s SET @notExistingObject = NULL SELECT @notExistingObject = ISNULL(@notExistingObject + ', ', '') + s.SchemaName FROM #Schema s WHERE NOT EXISTS (SELECT 1 FROM sys.schemas t WHERE s.SchemaName COLLATE HUNGARIAN_CI_AS = t.name COLLATE HUNGARIAN_CI_AS) IF @notExistingObject IS NOT NULL BEGIN SET @dbName = DB_NAME() RAISERROR('A paraméterekben megadott schemák közül a követtkezők nem léteznek a %s adatbázisban: %s', 16, 1, @dbName, @notExistingObject) RETURN END END ELSE BEGIN INSERT INTO #Schema (SchemaName) SELECT t.name FROM sys.schemas t WHERE name LIKE 'KR[_]%[_]Schema' OR name = 'dbo' END -- normál táblák, ahol van ID, INTEZMENYID oszlopok és a T_EVFOLYAMTIPUS_OKTATASINEVELE tábla DECLARE ViewCursor CURSOR LOCAL FOR SELECT tbl.name, COALESCE(c.is_identity, 2), '[' + s.SchemaName + ']', i.ID, tv.ID FROM sys.tables tbl LEFT JOIN sys.columns c ON tbl.object_id = c.object_id AND c.name = 'ID' INNER JOIN #Table t ON t.TableName COLLATE HUNGARIAN_CI_AS = tbl.name COLLATE HUNGARIAN_CI_AS CROSS JOIN #Schema s LEFT JOIN T_INTEZMENY i ON i.C_AZONOSITO = REPLACE(REPLACE(s.SchemaName, 'KR_', ''), '_Schema', '') AND i.TOROLT = 'F' LEFT JOIN T_TANEV tv ON tv.C_INTEZMENYID = i.ID AND tv.C_AKTIV = 'T' AND tv.TOROLT = 'F' WHERE (EXISTS (SELECT 1 FROM sys.columns x WHERE x.object_id = tbl.object_id AND x.name = 'C_INTEZMENYID') OR EXISTS (SELECT 1 FROM sys.columns x WHERE x.object_id = tbl.object_id AND x.name = 'C_ALINTEZMENYID')) AND tbl.schema_id = 1 ORDER BY tbl.name OPEN ViewCursor FETCH NEXT FROM ViewCursor INTO @tableName, @identity, @schemaName, @intezmenyId, @tanevId WHILE @@FETCH_STATUS = 0 BEGIN IF @schemaName = '[dbo]' BEGIN SET @sql = N' CREATE OR ALTER VIEW ' + @schemaName + '.' + @tableName + '_OSSZES AS SELECT * FROM dbo.' + @tableName + ';' IF @pDebugMode = 1 PRINT @schemaName + '.' + @tableName + '_OSSZES 1' EXEC sp_executesql @sql END ELSE BEGIN IF @tableName IN ('T_TANEV', 'T_MOBILDBINFO') BEGIN SET @sql = N' CREATE OR ALTER VIEW ' + @schemaName + '.' + @tableName + ' AS SELECT * FROM dbo.' + @tableName + ' WHERE C_INTEZMENYID = ' + CAST(@intezmenyId AS varchar(10)) + ' AND TOROLT = ''F'';' IF @pDebugMode = 1 PRINT @schemaName + '.' + @tableName + ' 2' EXEC sp_executesql @sql SET @sql = N' CREATE OR ALTER VIEW ' + @schemaName + '.' + @tableName + '_OSSZES AS SELECT * FROM dbo.' + @tableName + ' WHERE C_INTEZMENYID = ' + CAST(@intezmenyId AS varchar(10)) + ';' IF @pDebugMode = 1 PRINT @schemaName + '.' + @tableName + '_OSSZES 3' EXEC sp_executesql @sql END ELSE BEGIN SET @sql = N' CREATE OR ALTER VIEW ' + @schemaName + '.' + @tableName + ' AS SELECT * FROM dbo.' + @tableName + ' WHERE C_' + IIF(@identity = 0, 'AL', '') + 'TANEVID = ' + CAST(@tanevId AS varchar(10)) + ' AND C_' + IIF(@identity = 0, 'AL', '') + 'INTEZMENYID = ' + CAST(@intezmenyId AS varchar(10)) + ' ' + IIF(@identity = 2, '', 'AND TOROLT = ''F''') + ';' IF @pDebugMode = 1 PRINT @schemaName + '.' + @tableName + ' 4' EXEC sp_executesql @sql SET @sql = N' CREATE OR ALTER VIEW ' + @schemaName + '.' + @tableName + '_OSSZES AS SELECT * FROM dbo.' + @tableName + ' WHERE C_' + IIF(@identity = 0, 'AL', '') + 'INTEZMENYID = ' + CAST(@intezmenyId AS varchar(10)) + ';' IF @pDebugMode = 1 PRINT @schemaName + '.' + @tableName + '_OSSZES 5' EXEC sp_executesql @sql END END FETCH NEXT FROM ViewCursor INTO @tableName, @identity, @schemaName, @intezmenyId, @tanevId END CLOSE ViewCursor DEALLOCATE ViewCursor -- Kapcsolótáblák + T_INTEZMENY DECLARE ViewCursorKapcs CURSOR LOCAL FOR SELECT tbl.name, '[' + s.SchemaName + ']', 0 FROM sys.tables tbl INNER JOIN #Table t ON t.TableName COLLATE HUNGARIAN_CI_AS = tbl.name COLLATE HUNGARIAN_CI_AS CROSS JOIN #Schema s WHERE NOT EXISTS (SELECT 1 FROM sys.columns x WHERE x.object_id = tbl.object_id AND x.name = 'ID') AND tbl.schema_id = 1 AND s.SchemaName <> 'dbo' UNION ALL SELECT tbl.name, '[' + s.SchemaName + ']', 1 FROM sys.tables tbl INNER JOIN #Table t ON t.TableName COLLATE HUNGARIAN_CI_AS = tbl.name COLLATE HUNGARIAN_CI_AS CROSS JOIN #Schema s WHERE NOT EXISTS (SELECT 1 FROM sys.columns x WHERE x.object_id = tbl.object_id AND x.name = 'C_INTEZMENYID') AND NOT EXISTS (SELECT 1 FROM sys.columns x WHERE x.object_id = tbl.object_id AND x.name = 'C_ALINTEZMENYID') AND EXISTS (SELECT 1 FROM sys.columns x WHERE x.object_id = tbl.object_id AND x.name = 'ID') AND tbl.schema_id = 1 AND s.SchemaName <> 'dbo' AND t.TableName NOT IN ('T_TANEV') OPEN ViewCursorKapcs FETCH NEXT FROM ViewCursorKapcs INTO @tableName, @schemaName, @osszesView WHILE @@FETCH_STATUS = 0 BEGIN IF @osszesView = 1 BEGIN SET @sql = N' CREATE OR ALTER VIEW ' + @schemaName + '.' + @tableName + '_OSSZES AS SELECT * FROM dbo.' + @tableName + ';' IF @pDebugMode = 1 PRINT @schemaName + '.' + @tableName + '_OSSZES 6' EXEC sp_executesql @sql END SET @sql = N' CREATE OR ALTER VIEW ' + @schemaName + '.' + @tableName + ' AS SELECT * FROM dbo.' + @tableName + IIF(@osszesView = 1, ' WHERE TOROLT = ''F''', '') + ';' IF @pDebugMode = 1 PRINT @schemaName + '.' + @tableName + ' 7' EXEC sp_executesql @sql FETCH NEXT FROM ViewCursorKapcs INTO @tableName, @schemaName, @osszesView END CLOSE ViewCursorKapcs DEALLOCATE ViewCursorKapcs END GO