init
This commit is contained in:
@@ -0,0 +1,72 @@
|
||||
--Migration
|
||||
DROP VIEW IF EXISTS V_ENTITYHISTORYBLOB
|
||||
GO
|
||||
|
||||
CREATE VIEW V_ENTITYHISTORYBLOB AS
|
||||
SELECT
|
||||
e.ID
|
||||
,e.C_ENTITYID
|
||||
,e.C_ENTITYNAME
|
||||
,e.C_ALTERATIONDATE
|
||||
,e.C_REASON
|
||||
,e.C_FELHASZNALOID
|
||||
,e.C_INTEZMENYID
|
||||
,e.C_TANEVID
|
||||
,ev.C_ORIGINALVALUE
|
||||
,ev.C_CURRENTVALUE
|
||||
,ev.C_PROPERTYNAME
|
||||
,COALESCE(f.C_NYOMTATASINEV, u.USERNAME) AS C_FELHASZNALONEV
|
||||
,e.HOSTNAME AS C_HOSTNAME
|
||||
FROM T_ENTITYHISTORY e WITH(NOLOCK)
|
||||
INNER JOIN T_ENTITYBLOBVALUES ev WITH(NOLOCK) ON ev.C_ENTITYHISTORYID = e.ID
|
||||
LEFT JOIN T_FELHASZNALO f WITH(NOLOCK) ON f.ID = e.C_FELHASZNALOID
|
||||
LEFT JOIN auditlog.Users u WITH(NOLOCK) ON u.USERID = e.C_FELHASZNALOID
|
||||
GO
|
||||
|
||||
DROP VIEW IF EXISTS V_ENTITYHISTORY
|
||||
GO
|
||||
|
||||
CREATE VIEW V_ENTITYHISTORY AS
|
||||
-- T_ENTITYBLOBVALUES
|
||||
SELECT
|
||||
e.ID
|
||||
,e.C_ENTITYID
|
||||
,e.C_ENTITYNAME
|
||||
,e.C_ALTERATIONDATE
|
||||
,e.C_REASON
|
||||
,e.C_FELHASZNALOID
|
||||
,e.C_INTEZMENYID
|
||||
,e.C_TANEVID
|
||||
,ev.C_ORIGINALVALUE
|
||||
,ev.C_CURRENTVALUE
|
||||
,ev.C_PROPERTYNAME
|
||||
,COALESCE(f.C_NYOMTATASINEV, u.USERNAME) AS C_FELHASZNALONEV
|
||||
,e.HOSTNAME AS C_HOSTNAME
|
||||
FROM T_ENTITYHISTORY e WITH(NOLOCK)
|
||||
INNER JOIN T_ENTITYBLOBVALUES ev WITH(NOLOCK) ON ev.C_ENTITYHISTORYID = e.ID
|
||||
LEFT JOIN T_FELHASZNALO f WITH(NOLOCK) ON f.ID = e.C_FELHASZNALOID
|
||||
LEFT JOIN auditlog.Users u WITH(NOLOCK) ON u.USERID = e.C_FELHASZNALOID
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- T_ENTITYATTRIBUTEHISTORY
|
||||
SELECT
|
||||
e.ID
|
||||
,e.C_ENTITYID
|
||||
,e.C_ENTITYNAME
|
||||
,e.C_ALTERATIONDATE
|
||||
,e.C_REASON
|
||||
,e.C_FELHASZNALOID
|
||||
,e.C_INTEZMENYID
|
||||
,e.C_TANEVID
|
||||
,ea.C_ORIGINALVALUE
|
||||
,ea.C_CURRENTVALUE
|
||||
,ea.C_PROPERTYNAME
|
||||
,COALESCE(f.C_NYOMTATASINEV, u.USERNAME) AS C_FELHASZNALONEV
|
||||
,e.HOSTNAME AS C_HOSTNAME
|
||||
FROM dbo.T_ENTITYHISTORY e WITH(NOLOCK)
|
||||
LEFT JOIN dbo.T_ENTITYATTRIBUTEHISTORY ea WITH(NOLOCK) ON ea.C_ENTITYHISTORYID = e.ID
|
||||
LEFT JOIN dbo.T_FELHASZNALO f WITH(NOLOCK) ON f.ID = e.C_FELHASZNALOID
|
||||
LEFT JOIN auditlog.Users u WITH(NOLOCK) ON u.USERID = e.C_FELHASZNALOID
|
||||
WHERE EXISTS(SELECT * FROM dbo.T_ENTITYATTRIBUTEHISTORY h WITH(NOLOCK) WHERE h.C_ENTITYHISTORYID = e.ID) -- performancia miatt
|
||||
GO
|
@@ -0,0 +1,251 @@
|
||||
-- ============================================================================================
|
||||
-- Schema view-kat generál a paraméterekben megadott táblákhoz és schemákhoz,
|
||||
-- illetve, ha lé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)
|
||||
,@isIdentity nvarchar(10)
|
||||
,@intezmenyId int
|
||||
,@tanevId int
|
||||
,@notExistingObject nvarchar(255)
|
||||
,@osszesView bit
|
||||
,@sql nvarchar(max)
|
||||
,@dbName nvarchar(50)
|
||||
,@tanevColumn nvarchar(50)
|
||||
,@intezmenyColumn nvarchar(50)
|
||||
,@isSpecialTable bit
|
||||
|
||||
CREATE TABLE #Table (
|
||||
TableName nvarchar(255) COLLATE DATABASE_DEFAULT PRIMARY KEY
|
||||
)
|
||||
CREATE TABLE #Schema (
|
||||
SchemaName nvarchar(255) COLLATE DATABASE_DEFAULT PRIMARY KEY
|
||||
,IntezmenyAzonosito nvarchar(255) COLLATE DATABASE_DEFAULT
|
||||
)
|
||||
|
||||
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.name not like 'T[_]DKT[_]%' OR t.name IN ('T_DKT_FILE', 'T_DKT_FELADAT', 'T_DKT_FELADATFILE'))
|
||||
AND t.schema_id = 1
|
||||
-- kivétel táblák, amelyeknek nem kell schema view-t generálni
|
||||
AND t.name NOT IN ('T_ENTITYATTRIBUTEHISTORY', 'T_ENTITYHISTORY', 'T_ENTITYATTRIBUTEHISTORY_ARCHIVE', 'T_ENTITYBLOBVALUES', 'T_ENTITYBLOBVALUES_ARCHIVE')
|
||||
END
|
||||
|
||||
IF @pSchemas IS NOT NULL BEGIN
|
||||
INSERT INTO #Schema (SchemaName, IntezmenyAzonosito)
|
||||
SELECT DISTINCT LTRIM(RTRIM(s.value)),REPLACE(REPLACE(s.value, 'KR_', ''), '_Schema', '')
|
||||
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, IntezmenyAzonosito)
|
||||
SELECT t.name, REPLACE(REPLACE(t.name, 'KR_', ''), '_Schema', '')
|
||||
FROM sys.schemas t
|
||||
WHERE name LIKE 'KR[_]%[_]Schema' OR name = 'dbo'
|
||||
END
|
||||
|
||||
-- normál táblák, ahol van ID, INTEZMENYID, TANEVID oszlopok és a T_EVFOLYAMTIPUS_OKTATASINEVELE tábla
|
||||
DECLARE ViewCursor CURSOR LOCAL FOR
|
||||
SELECT
|
||||
tbl.name AS TableName
|
||||
,COALESCE(cid.is_identity, 2) AS IsIdentity
|
||||
,'[' + s.SchemaName + ']' AS SchemaName
|
||||
,i.ID AS IntezmenyId
|
||||
,tv.ID AS TanevId
|
||||
,ctv.name AS TanevColumn
|
||||
,cin.name AS IntezmenyColumn
|
||||
-- olyan táblák, amelyekre kell schema view generálni, de speciális szerkezetük miatt nem lehet általánosan
|
||||
,CASE WHEN tbl.name IN ('T_OSZTONDIJHISTORY') THEN 1 ELSE 0 END AS SpecialTable
|
||||
FROM sys.tables tbl
|
||||
LEFT JOIN sys.columns cid ON tbl.object_id = cid.object_id AND cid.name = 'ID'
|
||||
LEFT JOIN sys.columns cin ON tbl.object_id = cin.object_id AND cin.name IN ('C_INTEZMENYID', 'C_ALINTEZMENYID')
|
||||
LEFT JOIN sys.columns ctv ON tbl.object_id = ctv.object_id AND ctv.name IN ('C_TANEVID', 'C_ALTANEVID')
|
||||
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 = s.IntezmenyAzonosito 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 tbl.schema_id = 1
|
||||
ORDER BY SchemaName, tbl.name
|
||||
|
||||
OPEN ViewCursor
|
||||
|
||||
FETCH NEXT FROM ViewCursor
|
||||
INTO @tableName, @isIdentity, @schemaName, @intezmenyId, @tanevId, @tanevColumn, @intezmenyColumn, @isSpecialTable
|
||||
|
||||
WHILE @@FETCH_STATUS = 0 BEGIN
|
||||
|
||||
IF @schemaName = '[dbo]' BEGIN
|
||||
|
||||
SET @sql = N'
|
||||
CREATE OR ALTER VIEW ' + @schemaName + '.' + @tableName + '_OSSZES AS
|
||||
SELECT *
|
||||
FROM dbo.' + @tableName + ';'
|
||||
EXEC sp_executesql @sql
|
||||
IF @pDebugMode = 1 OR @@error <> 0 PRINT @schemaName + '.' + @tableName + '_OSSZES (dbo)'
|
||||
|
||||
END
|
||||
ELSE BEGIN
|
||||
|
||||
IF @isSpecialTable = 0 BEGIN
|
||||
SET @sql = N'
|
||||
CREATE OR ALTER VIEW ' + @schemaName + '.' + @tableName + ' AS
|
||||
SELECT *
|
||||
FROM dbo.' + @tableName + '
|
||||
WHERE ' + @intezmenyColumn + ' = ' + CAST(@intezmenyId AS varchar(10)) + '
|
||||
' + ISNULL('AND ' + @tanevColumn + ' = ' + CAST(@tanevId AS varchar(10)), '') + '
|
||||
' + IIF(@isIdentity = 2, '', 'AND TOROLT = ''F''')
|
||||
EXEC sp_executesql @sql
|
||||
IF @pDebugMode = 1 OR @@error <> 0 PRINT @schemaName + '.' + @tableName + ' (normal)'
|
||||
|
||||
SET @sql = N'
|
||||
CREATE OR ALTER VIEW ' + @schemaName + '.' + @tableName + '_OSSZES AS
|
||||
SELECT *
|
||||
FROM dbo.' + @tableName + '
|
||||
WHERE ' + @intezmenyColumn + ' = ' + CAST(@intezmenyId AS varchar(10)) + ';'
|
||||
EXEC sp_executesql @sql
|
||||
IF @pDebugMode = 1 OR @@error <> 0 PRINT @schemaName + '.' + @tableName + '_OSSZES (normal osszes)'
|
||||
|
||||
END
|
||||
ELSE BEGIN -- @isSpecialTable = 1
|
||||
|
||||
IF @tableName = 'T_OSZTONDIJHISTORY' BEGIN
|
||||
|
||||
SET @sql = N'
|
||||
CREATE OR ALTER VIEW ' + @schemaName + '.' + @tableName + ' AS
|
||||
SELECT *
|
||||
FROM dbo.' + @tableName + '
|
||||
WHERE ' + @tanevColumn + ' = ' + CAST(@tanevId AS varchar(10))
|
||||
EXEC sp_executesql @sql
|
||||
IF @pDebugMode = 1 OR @@error <> 0 PRINT @schemaName + '.' + @tableName + ' (special)'
|
||||
|
||||
SET @sql = N'
|
||||
CREATE OR ALTER VIEW ' + @schemaName + '.' + @tableName + '_OSSZES AS
|
||||
SELECT *
|
||||
FROM dbo.' + @tableName + '
|
||||
WHERE ' + @tanevColumn + ' = ' + CAST(@tanevId AS varchar(10)) + ';'
|
||||
EXEC sp_executesql @sql
|
||||
IF @pDebugMode = 1 OR @@error <> 0 PRINT @schemaName + '.' + @tableName + '_OSSZES (special osszes)'
|
||||
|
||||
END
|
||||
END
|
||||
END
|
||||
|
||||
FETCH NEXT FROM ViewCursor
|
||||
INTO @tableName, @isIdentity, @schemaName, @intezmenyId, @tanevId, @tanevColumn, @intezmenyColumn, @isSpecialTable
|
||||
|
||||
END
|
||||
|
||||
CLOSE ViewCursor
|
||||
DEALLOCATE ViewCursor
|
||||
|
||||
-- Kapcsolótáblák + T_INTEZMENY
|
||||
DECLARE ViewCursorKapcs CURSOR LOCAL FOR
|
||||
SELECT tbl.name AS TableName , '[' + s.SchemaName + ']' AS SchemaName, 0 AS OsszesView
|
||||
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 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'
|
||||
AND tbl.name NOT IN ('T_OSZTONDIJHISTORY')
|
||||
|
||||
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 tbl.name NOT IN ('T_OSZTONDIJHISTORY')
|
||||
ORDER BY SchemaName, TableName
|
||||
|
||||
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 + ';'
|
||||
EXEC sp_executesql @sql
|
||||
IF @pDebugMode = 1 OR @@error <> 0 PRINT @schemaName + '.' + @tableName + '_OSSZES (kapcsolótábla)'
|
||||
|
||||
END
|
||||
|
||||
SET @sql = N'
|
||||
CREATE OR ALTER VIEW ' + @schemaName + '.' + @tableName + ' AS
|
||||
SELECT *
|
||||
FROM dbo.' + @tableName + IIF(@osszesView = 1, ' WHERE TOROLT = ''F''', '') + ';'
|
||||
EXEC sp_executesql @sql
|
||||
IF @pDebugMode = 1 OR @@error <> 0 PRINT @schemaName + '.' + @tableName + ' (nem intézményhez köthető tábla)'
|
||||
|
||||
FETCH NEXT FROM ViewCursorKapcs
|
||||
INTO @tableName, @schemaName, @osszesView
|
||||
END
|
||||
|
||||
CLOSE ViewCursorKapcs
|
||||
DEALLOCATE ViewCursorKapcs
|
||||
END
|
||||
GO
|
Reference in New Issue
Block a user