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

204 lines
8.5 KiB
Transact-SQL

IF OBJECT_ID('T_TANARTARGYATLAG') IS NOT NULL BEGIN
DROP VIEW T_TANARTARGYATLAG
END
GO
CREATE VIEW T_TANARTARGYATLAG AS
SELECT AVG(d.C_VALUE * ISNULL(s.C_SULY / 100.0, 1.0)) AS C_ATLAG,
oe.C_ALINTEZMENYID AS C_INTEZMENYID, oe.C_ALTANEVID AS C_TANEVID,
te.C_TANTARGYID AS C_TANTARGYIATLAGOKID, te.C_ERTEKELOID AS C_TANARIATLAGOKID
FROM T_OSZTALYZATERTEKELES oe
INNER JOIN T_TANULOERTEKELES te ON te.ID = oe.ID
INNER JOIN T_DICTIONARYITEMBASE d ON d.ID = te.C_OSZTALYZAT AND oe.C_ALINTEZMENYID = d.C_INTEZMENYID AND oe.C_ALTANEVID = d.C_TANEVID
LEFT JOIN T_TANARIATLAGSULY s ON s.C_ERTEKELESMODJA = oe.C_ERTEKELESMODJA
GROUP BY oe.C_ALINTEZMENYID, oe.C_ALTANEVID, te.C_TANTARGYID, te.C_ERTEKELOID
GO
--IF OBJECT_ID('T_TANARTARGYATLAG_OSSZES') IS NOT NULL BEGIN
-- DROP VIEW T_TANARTARGYATLAG_OSSZES
--END
--GO
--CREATE VIEW T_TANARTARGYATLAG_OSSZES AS
-- SELECT AVG(d.C_VALUE * ISNULL(s.C_SULY / 100.0, 1.0)) AS C_ATLAG,
-- oe.C_ALINTEZMENYID AS C_INTEZMENYID, oe.C_ALTANEVID AS C_TANEVID,
-- te.C_TANTARGYID AS C_TANTARGYIATLAGOKID, te.C_ERTEKELOID AS C_TANARIATLAGOKID
-- FROM T_OSZTALYZATERTEKELES_OSSZES oe
-- INNER JOIN T_TANULOERTEKELES_OSSZES te ON te.ID = oe.ID
-- INNER JOIN T_DICTIONARYITEMBASE_OSSZES d ON d.ID = oe.C_OSZTALYZAT AND oe.C_ALINTEZMENYID = d.C_INTEZMENYID AND oe.C_ALTANEVID = d.C_TANEVID
-- LEFT JOIN T_TANARIATLAGSULY s ON s.C_ERTEKELESMODJA = oe.C_ERTEKELESMODJA AND s.C_TANEVID = oe.C_ALTANEVID
-- GROUP BY oe.C_ALINTEZMENYID, oe.C_ALTANEVID, te.C_TANTARGYID, te.C_ERTEKELOID
--GO
IF OBJECT_ID('T_TARGYOSZTALYATLAG') IS NOT NULL BEGIN
DROP VIEW T_TARGYOSZTALYATLAG
END
GO
CREATE VIEW T_TARGYOSZTALYATLAG AS
SELECT AVG(d.C_VALUE * d.C_VALUE * ISNULL(s.C_SULY / 100.0, 1.0)) AS C_ATLAG, oe.C_ALINTEZMENYID AS C_INTEZMENYID, oe.C_ALTANEVID AS C_TANEVID,
te.C_TANTARGYID AS C_TARGYATLAGOKID, ISNULL(cso.C_OSZTALYOKID, te.C_OSZTALYCSOPORTID) AS C_OSZTALYATLAGOKID
FROM T_OSZTALYZATERTEKELES oe
INNER JOIN T_TANULOERTEKELES te ON te.ID = oe.ID
LEFT JOIN T_CSOPORTOK_OSZTALYOK cso ON cso.C_CSOPORTOKID = te.C_OSZTALYCSOPORTID
INNER JOIN T_DICTIONARYITEMBASE d ON d.ID = te.C_OSZTALYZAT AND oe.C_ALINTEZMENYID = d.C_INTEZMENYID AND oe.C_ALTANEVID = d.C_TANEVID
LEFT JOIN T_TANARIATLAGSULY s ON s.C_ERTEKELESMODJA = oe.C_ERTEKELESMODJA
GROUP BY oe.C_ALINTEZMENYID, oe.C_ALTANEVID, te.C_TANTARGYID, ISNULL(cso.C_OSZTALYOKID, te.C_OSZTALYCSOPORTID)
GO
--IF OBJECT_ID('T_TARGYOSZTALYATLAG_OSSZES') IS NOT NULL BEGIN
-- DROP VIEW T_TARGYOSZTALYATLAG_OSSZES
--END
--GO
--CREATE VIEW T_TARGYOSZTALYATLAG_OSSZES AS
-- SELECT AVG(d.C_VALUE * ISNULL(s.C_SULY / 100.0, 1.0)) AS C_ATLAG, oe.C_ALINTEZMENYID AS C_INTEZMENYID, oe.C_ALTANEVID AS C_TANEVID,
-- te.C_TANTARGYID AS C_TARGYATLAGOKID, ISNULL(cso.C_OSZTALYOKID, te.C_OSZTALYCSOPORTID) AS C_OSZTALYATLAGOKID
-- FROM T_OSZTALYZATERTEKELES_OSSZES oe
-- INNER JOIN T_TANULOERTEKELES_OSSZES te ON te.ID = oe.ID
-- LEFT JOIN T_CSOPORTOK_OSZTALYOK cso ON cso.C_CSOPORTOKID = te.C_OSZTALYCSOPORTID
-- INNER JOIN T_DICTIONARYITEMBASE_OSSZES d ON d.ID = oe.C_OSZTALYZAT AND oe.C_ALINTEZMENYID = d.C_INTEZMENYID AND oe.C_ALTANEVID = d.C_TANEVID
-- LEFT JOIN T_TANARIATLAGSULY s ON s.C_ERTEKELESMODJA = oe.C_ERTEKELESMODJA AND s.C_TANEVID = oe.C_ALTANEVID
-- GROUP BY oe.C_ALINTEZMENYID, oe.C_ALTANEVID, te.C_TANTARGYID, ISNULL(cso.C_OSZTALYOKID, te.C_OSZTALYCSOPORTID)
--GO
IF OBJECT_ID('T_TARGYTANULOATLAG') IS NOT NULL BEGIN
DROP VIEW T_TARGYTANULOATLAG
END
GO
CREATE VIEW T_TARGYTANULOATLAG AS
SELECT C_TANULOID, C_TANTARGYID, [9] AS C_SZEPTEMBER, [10] AS C_OKTOBER, [11] AS C_NOVEMBER,
[12] AS C_DECEMBER, [1] AS C_JANUAR, [2] AS C_FEBRUAR, [3] AS C_MARCIUS, [4] AS C_APRILIS,
[5] AS C_MAJUS, [6] AS C_JUNIUS, [7] AS C_JULIUS, [8] AS C_AUGUSZTUS,
[ev] AS C_EVVEGIATLAG, [I] AS C_BONTOTTELSOFELEVATLAG, [II] AS C_BONTOTTMASODIKFELEVATLAG
FROM (
SELECT i.period, te.C_TANULOID, te.C_TANTARGYID, AVG(d.C_VALUE * ISNULL(s.C_SULY / 100.0, 1.0)) AS atlag
FROM (
SELECT
CAST(MONTH(n.C_NAPDATUMA) AS varchar(3)) AS period
,DATEFROMPARTS ( YEAR(n.C_NAPDATUMA), MONTH(n.C_NAPDATUMA), 1 ) AS startDate
,DATEADD(m, 1, DATEFROMPARTS ( YEAR(n.C_NAPDATUMA), MONTH(n.C_NAPDATUMA), 1 )) AS endDate
FROM T_NAPTARINAP n
GROUP BY YEAR(n.C_NAPDATUMA), MONTH(n.C_NAPDATUMA)
UNION ALL
SELECT 'ev', C_KEZDONAP, CAST(C_UTOLSONAP + 1 AS date)
FROM T_TANEV
UNION ALL
SELECT 'I', C_KEZDONAP, C_DATUM + 1
FROM T_TANEV t
INNER JOIN T_TANEVRENDJE r ON r.C_TANEVID = t.ID
WHERE C_NAPTIPUSA= 1400 --Első félév vége
UNION ALL
SELECT 'II', C_DATUM + 1, CAST(C_UTOLSONAP + 1 AS date)
FROM T_TANEV t
INNER JOIN T_TANEVRENDJE r ON r.C_TANEVID = t.ID
WHERE C_NAPTIPUSA= 1400 --Első félév vége
) i
INNER JOIN T_TANULOERTEKELES te ON te.C_ERTEKELESDATUM >= i.startDate AND te.C_ERTEKELESDATUM < i.endDate
INNER JOIN T_OSZTALYZATERTEKELES oe ON oe.ID = te.ID
INNER JOIN T_DICTIONARYITEMBASE d ON d.ID = te.C_OSZTALYZAT AND d.C_INTEZMENYID = oe.C_ALINTEZMENYID AND d.C_TANEVID = oe.C_ALTANEVID
LEFT JOIN T_TANARIATLAGSULY s ON s.C_ERTEKELESMODJA = oe.C_ERTEKELESMODJA
GROUP BY i.period, te.C_TANULOID, te.C_TANTARGYID
) x
PIVOT (
MAX (atlag)
FOR period IN ([9], [10], [11], [12], [1], [2], [3], [4], [5], [6], [7], [8], [ev], [I], [II])
) AS pvt
GO
--IF OBJECT_ID('T_TARGYTANULOATLAG_OSSZES') IS NOT NULL BEGIN
-- DROP VIEW T_TARGYTANULOATLAG_OSSZES
--END
--GO
--CREATE VIEW T_TARGYTANULOATLAG_OSSZES AS
-- SELECT C_TANULOID, C_TANTARGYID, [9] AS C_SZEPTEMBER, [10] AS C_OKTOBER, [11] AS C_NOVEMBER,
-- [12] AS C_DECEMBER, [1] AS C_JANUAR, [2] AS C_FEBRUAR, [3] AS C_MARCIUS, [4] AS C_APRILIS,
-- [5] AS C_MAJUS, [6] AS C_JUNIUS, [7] AS C_JULIUS, [8] AS C_AUGUSZTUS,
-- [ev] AS C_EVVEGIATLAG, [I] AS C_BONTOTTELSOFELEVATLAG, [II] AS C_BONTOTTMASODIKFELEVATLAG
-- FROM (
-- SELECT i.period, te.C_TANULOID, te.C_TANTARGYID, AVG(d.C_VALUE * ISNULL(s.C_SULY / 100.0, 1.0)) AS atlag
-- FROM (
-- SELECT
-- CAST(MONTH(n.C_NAPDATUMA) AS varchar(3)) AS period
-- ,DATEFROMPARTS ( YEAR(n.C_NAPDATUMA), MONTH(n.C_NAPDATUMA), 1 ) AS startdate
-- ,DATEADD(m, 1, DATEFROMPARTS ( YEAR(n.C_NAPDATUMA), MONTH(n.C_NAPDATUMA), 1 )) AS enddate
-- FROM T_NAPTARINAP_OSSZES n
-- GROUP BY YEAR(n.C_NAPDATUMA), MONTH(n.C_NAPDATUMA)
-- UNION ALL
-- SELECT 'ev', C_KEZDONAP, CAST(C_UTOLSONAP + 1 AS date)
-- FROM T_TANEV_OSSZES
-- UNION ALL
-- SELECT 'I', C_KEZDONAP, C_DATUM + 1
-- FROM T_TANEV_OSSZES t
-- INNER JOIN T_TANEVRENDJE_OSSZES r ON r.C_TANEVID = t.ID
-- WHERE C_NAPTIPUSA= 1400 --Első félév vége
-- UNION ALL
-- SELECT 'II', C_DATUM + 1, CAST(C_UTOLSONAP + 1 AS date)
-- FROM T_TANEV_OSSZES t
-- INNER JOIN T_TANEVRENDJE_OSSZES r ON r.C_TANEVID = t.ID
-- WHERE C_NAPTIPUSA= 1400 --Első félév vége
-- ) i
-- INNER JOIN T_TANULOERTEKELES_OSSZES te ON te.C_ERTEKELESDATUM >= i.startdate AND te.C_ERTEKELESDATUM < i.enddate
-- INNER JOIN T_OSZTALYZATERTEKELES_OSSZES oe ON oe.ID = te.ID
-- INNER JOIN T_DICTIONARYITEMBASE_OSSZES d ON d.ID = oe.C_OSZTALYZAT AND d.C_INTEZMENYID = oe.C_ALINTEZMENYID AND d.C_TANEVID = oe.C_ALTANEVID
-- LEFT JOIN T_TANARIATLAGSULY s ON s.C_ERTEKELESMODJA = oe.C_ERTEKELESMODJA AND s.C_TANEVID = oe.C_ALTANEVID
-- GROUP BY i.period, te.C_TANULOID, te.C_TANTARGYID
-- ) x
-- PIVOT (
-- MAX (atlag)
-- FOR period IN ([9], [10], [11], [12], [1], [2], [3], [4], [5], [6], [7], [8], [ev], [I], [II])
-- ) AS pvt
--GO
--------------------------- #TABLE#_OSSZES VIEW-K LÉTREHOZÁSA A DBO SCHEMA_BAN ---------------------------
DECLARE @tableName NVARCHAR(200)
DECLARE @viewName NVARCHAR(200)
DECLARE @sql NVARCHAR(max)
DECLARE tableCursor CURSOR LOCAL FOR
SELECT t.name
FROM sys.tables t
INNER JOIN sys.schemas s ON s.schema_id = t.schema_id
WHERE s.name ='dbo'
ORDER BY s.name
OPEN tableCursor
FETCH NEXT FROM tableCursor INTO @tableName
WHILE @@FETCH_STATUS = 0
BEGIN
PRINT @tableName
SET @viewName = @tableName + N'_OSSZES'
SET @sql = N'IF OBJECT_ID(''' + @viewName + ''') IS NOT NULL
BEGIN
DROP VIEW ' + @viewName + '
END'
--PRINT @sql
EXECUTE sp_executesql @sql
SET @sql = N'CREATE VIEW dbo.' + @viewName + '
AS
SELECT *
FROM dbo.' + @tableName
--PRINT @sql
EXECUTE sp_executesql @sql
FETCH NEXT FROM tableCursor INTO @tableName
END
CLOSE tableCursor
DEALLOCATE tableCursor
GO