init
This commit is contained in:
commit
e124a47765
19374 changed files with 9806149 additions and 0 deletions
|
@ -0,0 +1,311 @@
|
|||
-- =============================================
|
||||
-- Description: <Dinamikus import>
|
||||
-- =============================================
|
||||
DROP PROCEDURE IF EXISTS [dbo].[uspDynamicImport]
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE [dbo].[uspDynamicImport]
|
||||
@pIntezmenyId INT
|
||||
,@pTanevId INT
|
||||
,@pUserId INT
|
||||
,@pImportJson NVARCHAR(MAX)
|
||||
,@pIsTorles BIT
|
||||
,@pIsSubTable BIT
|
||||
AS BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
DECLARE
|
||||
@sqlCommand NVARCHAR(MAX) = ''
|
||||
|
||||
,@sqlInsertCommand NVARCHAR(MAX) = ''
|
||||
,@sqlUpdateCommand NVARCHAR(MAX) = ''
|
||||
,@sqlDeleteCommand NVARCHAR(MAX) = ''
|
||||
|
||||
,@lastChangedDateTime DATETIME = GETDATE()
|
||||
|
||||
,@openJsonWithCommand NVARCHAR(MAX)
|
||||
,@rootElementJsonWithCommand NVARCHAR(300)
|
||||
,@columnNameFromJsonCommand NVARCHAR(300)
|
||||
|
||||
,@columnListForInsert NVARCHAR(MAX)
|
||||
,@columnListForUpdate NVARCHAR(MAX)
|
||||
|
||||
,@rootElement NVARCHAR(100)
|
||||
,@tableNameFromJson NVARCHAR(50)
|
||||
,@columnCount INT
|
||||
|
||||
,@openJsonPath NVARCHAR(300)
|
||||
|
||||
CREATE TABLE #entityIds
|
||||
(
|
||||
ID INT
|
||||
)
|
||||
|
||||
DECLARE @TableName TABLE
|
||||
(
|
||||
TableName NVARCHAR(50)
|
||||
)
|
||||
|
||||
DECLARE @ColumnTable TABLE
|
||||
(
|
||||
ColumnName NVARCHAR(50)
|
||||
)
|
||||
|
||||
DECLARE @ColumnDataTable TABLE
|
||||
(
|
||||
ColumnName NVARCHAR(50)
|
||||
,ColumnType NVARCHAR(50)
|
||||
,MaxLengthValue NVARCHAR(50)
|
||||
,NumericPrecision NVARCHAR(50)
|
||||
,NumericScale NVARCHAR(50)
|
||||
,IsNullable NVARCHAR(50)
|
||||
)
|
||||
|
||||
-- A Json Root elemének kiszedése változóba @rootElement
|
||||
SELECT
|
||||
@rootElement = [key]
|
||||
FROM
|
||||
OPENJSON(@pImportJson, N'strict $')
|
||||
|
||||
--Az importálandó táblanevének kiszedése JSON-ből (rootelem utáni elem) @tableNameFromJson
|
||||
SET @rootElementJsonWithCommand = '
|
||||
SELECT
|
||||
@tableNameFromJson = [key]
|
||||
FROM
|
||||
OPENJSON (@pImportJson, N''lax $.' + @rootElement + ''')
|
||||
SELECT
|
||||
@tableNameFromJson
|
||||
'
|
||||
|
||||
INSERT INTO @TableName
|
||||
EXEC sp_executesql @rootElementJsonWithCommand, N'@pImportJson NVARCHAR(MAX), @tableNameFromJson NVARCHAR(50)', @pImportJson, @tableNameFromJson
|
||||
|
||||
SELECT @tableNameFromJson = (SELECT TOP 1 TableName FROM @TableName)
|
||||
|
||||
--NOTE: Megvizsgáljuk, hogy létezik-e a tábla neve a Json-ben
|
||||
IF (@tableNameFromJson IS NOT NULL)
|
||||
BEGIN
|
||||
|
||||
--Ha Törölnünk is kell akkor azzal kezdünk!
|
||||
IF @pIsTorles = 1
|
||||
BEGIN
|
||||
--DELETE összeállítása (Igazából update mert csak töröltre állít)
|
||||
SET @sqlDeleteCommand = '
|
||||
UPDATE
|
||||
[' + @tableNameFromJson + ']
|
||||
SET
|
||||
[' + @tableNameFromJson + '].[TOROLT] = ''T'',
|
||||
[' + @tableNameFromJson + '].[SERIAL] = [' + @tableNameFromJson + '].[SERIAL] + 1,
|
||||
[' + @tableNameFromJson + '].[LASTCHANGED] = ''' + CONVERT(NVARCHAR(32), @lastChangedDateTime, 126) + ''',
|
||||
[' + @tableNameFromJson + '].[MODIFIER] = ''' + CONVERT(NVARCHAR(32), @pUserId) + '''
|
||||
OUTPUT DELETED.ID
|
||||
INTO #entityIds
|
||||
WHERE '
|
||||
IF(@pIsSubTable = 0)
|
||||
BEGIN
|
||||
SET @sqlDeleteCommand = @sqlDeleteCommand + '
|
||||
[' + @tableNameFromJson + '].[C_INTEZMENYID] = ''' + CONVERT(NVARCHAR(32), @pIntezmenyId) + '''
|
||||
AND [' + @tableNameFromJson + '].[C_TANEVID] = ''' + CONVERT(NVARCHAR(32), @pTanevId) + ''''
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
SET @sqlDeleteCommand = @sqlDeleteCommand + '
|
||||
[' + @tableNameFromJson + '].[C_ALINTEZMENYID] = ''' + CONVERT(NVARCHAR(32), @pIntezmenyId) + '''
|
||||
AND [' + @tableNameFromJson + '].[C_ALTANEVID] = ''' + CONVERT(NVARCHAR(32), @pTanevId) + ''''
|
||||
END
|
||||
SET @sqlDeleteCommand = @sqlDeleteCommand + '
|
||||
AND [' + @tableNameFromJson + '].[TOROLT] = ''F''
|
||||
AND [' + @tableNameFromJson + '].[C_IMPORTALT] = ''T''
|
||||
'
|
||||
END
|
||||
|
||||
--Oszlopok nevei a Json-ben
|
||||
SET @columnNameFromJsonCommand = '
|
||||
SELECT
|
||||
[key] ColumnNameList
|
||||
INTO
|
||||
#ColumnList
|
||||
FROM
|
||||
OPENJSON (@pImportJson, N''lax $.' + @rootElement + '.' + @tableNameFromJson + '[0]'')
|
||||
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
#ColumnList
|
||||
'
|
||||
|
||||
INSERT INTO @ColumnTable
|
||||
EXEC sp_executesql @columnNameFromJsonCommand, N'@pImportJson NVARCHAR(MAX)', @pImportJson
|
||||
|
||||
SELECT @columnCount = (SELECT COUNT(*) FROM @ColumnTable)
|
||||
|
||||
--NOTE: Megvizsgáljuk, hogy van-e oszlop a Json-ben
|
||||
IF (@columnCount <> 0)
|
||||
BEGIN
|
||||
|
||||
INSERT INTO
|
||||
@ColumnDataTable
|
||||
SELECT
|
||||
COLUMN_NAME
|
||||
,DATA_TYPE
|
||||
,CHARACTER_MAXIMUM_LENGTH
|
||||
,NUMERIC_PRECISION
|
||||
,NUMERIC_SCALE
|
||||
,IS_NULLABLE
|
||||
FROM
|
||||
INFORMATION_SCHEMA.columns
|
||||
WHERE
|
||||
TABLE_NAME = @tableNameFromJson
|
||||
AND TABLE_SCHEMA = 'dbo'
|
||||
AND COLUMN_NAME IN (SELECT ColumnName FROM @ColumnTable)
|
||||
|
||||
SELECT @openJsonWithCommand =
|
||||
ISNULL(@openJsonWithCommand + CHAR(13) + CHAR(10) + CHAR(9) + ',', CHAR(9) + SPACE(1) + '')
|
||||
+ '[' + ColumnName + '] ' + ColumnType
|
||||
+ CASE
|
||||
WHEN ColumnType IN ('DECIMAL', 'NUMERIC')
|
||||
THEN ISNULL('(' + CONVERT(VARCHAR(2), NumericPrecision) + ', ' + CONVERT(VARCHAR(2), NumericScale) + ') ', ' ')
|
||||
WHEN ColumnType IN ('NVARCHAR', 'VARCHAR', 'NCHAR', 'CHAR')
|
||||
THEN ISNULL('(' + CONVERT(VARCHAR(4), IIF(MaxLengthValue = -1, 'MAX', MaxLengthValue)) + ') ', ' ')
|
||||
ELSE
|
||||
' '
|
||||
END
|
||||
+ '''$.' + ColumnName + ''''
|
||||
FROM @ColumnDataTable
|
||||
|
||||
SET @openJsonWithCommand = '(' + CHAR(13) + CHAR(10) + @openJsonWithCommand + CHAR(13) + CHAR(10) + ' ,[Operation] int ''$.Operation''' + CHAR(13) + CHAR(10) + ')'
|
||||
|
||||
--OSZLOPLISTA INSERTHEZ
|
||||
SELECT
|
||||
@columnListForInsert = ISNULL(@columnListForInsert + ',', '') + '[' + columnDataTable.ColumnName + ']' --TODO andrejkovicse: Függvény a []-ra
|
||||
FROM
|
||||
@ColumnDataTable columnDataTable
|
||||
WHERE
|
||||
@pIsSubTable = 0 AND columnDataTable.ColumnName NOT IN ('Operation', 'ID') OR
|
||||
@pIsSubTable = 1 AND columnDataTable.ColumnName NOT IN ('Operation')
|
||||
|
||||
--OSZLOPLISTA UPDATHEZ
|
||||
SELECT
|
||||
@columnListForUpdate = ISNULL(@columnListForUpdate + ',', '') + '[' + @tableNameFromJson + '].' + '[' + columnDataTable.ColumnName + '] = [ImportData].' + '[' + columnDataTable.ColumnName + ']'
|
||||
FROM
|
||||
@ColumnDataTable columnDataTable
|
||||
WHERE
|
||||
columnDataTable.ColumnName NOT IN ('Operation', 'ID', 'SERIAL', 'CREATOR', 'CREATED', 'C_IMPORTALT')
|
||||
|
||||
-- OPENJSON path beállítása (ez megegyezik mindhárom műveletnél)
|
||||
SET @openJsonPath = N'''strict $.' + @rootElement + '.' + @tableNameFromJson + ''''
|
||||
|
||||
--INSERT összeállítása
|
||||
SET @sqlInsertCommand = '
|
||||
INSERT INTO
|
||||
[' + @tableNameFromJson + '] (
|
||||
' + @columnListForInsert + '
|
||||
)
|
||||
OUTPUT INSERTED.ID
|
||||
INTO #entityIds
|
||||
SELECT
|
||||
' + @columnListForInsert + '
|
||||
FROM
|
||||
OPENJSON (@pImportJson, ' + @openJsonPath + ')
|
||||
WITH '
|
||||
+ @openJsonWithCommand + '
|
||||
WHERE
|
||||
[Operation] = 1 --NOTE: ImportItemOperationEnum.Insert
|
||||
'
|
||||
|
||||
--UPDATE összeállítása
|
||||
SET @sqlUpdateCommand = '
|
||||
UPDATE
|
||||
[' + @tableNameFromJson + ']
|
||||
SET
|
||||
' + @columnListForUpdate + ',[' + @tableNameFromJson + '].[SERIAL] = [' + @tableNameFromJson + '].[SERIAL] + 1 ' + '
|
||||
OUTPUT DELETED.ID
|
||||
INTO #entityIds
|
||||
FROM (
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
OPENJSON (@pImportJson, ' + @openJsonPath + ')
|
||||
WITH '
|
||||
+ @openJsonWithCommand + '
|
||||
WHERE
|
||||
[Operation] = 2 --NOTE: ImportItemOperationEnum.Update
|
||||
) AS ImportData
|
||||
WHERE '
|
||||
IF(@pIsSubTable = 0)
|
||||
BEGIN
|
||||
SET @sqlUpdateCommand = @sqlUpdateCommand + '
|
||||
[' + @tableNameFromJson + '].[C_INTEZMENYID] = ''' + CONVERT(NVARCHAR(32), @pIntezmenyId) + '''
|
||||
AND [' + @tableNameFromJson + '].[C_TANEVID] = ''' + CONVERT(NVARCHAR(32), @pTanevId) + ''''
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
SET @sqlUpdateCommand = @sqlUpdateCommand + '
|
||||
[' + @tableNameFromJson + '].[C_ALINTEZMENYID] = ''' + CONVERT(NVARCHAR(32), @pIntezmenyId) + '''
|
||||
AND [' + @tableNameFromJson + '].[C_ALTANEVID] = ''' + CONVERT(NVARCHAR(32), @pTanevId) + ''''
|
||||
END
|
||||
SET @sqlUpdateCommand = @sqlUpdateCommand + '
|
||||
AND [' + @tableNameFromJson + '].[TOROLT] = ''F''
|
||||
AND [' + @tableNameFromJson + '].[ID] = ImportData.ID
|
||||
'
|
||||
|
||||
SET @sqlCommand = @sqlDeleteCommand + @sqlInsertCommand + @sqlUpdateCommand
|
||||
|
||||
END
|
||||
|
||||
IF(@sqlCommand IS NOT NULL OR @sqlCommand <> '')
|
||||
BEGIN
|
||||
EXEC sp_executesql @sqlCommand, N'@pImportJson NVARCHAR(MAX)', @pImportJson
|
||||
IF @tableNameFromJson IN ('T_TEREM_OSSZES','T_ESZKOZ_OSSZES','T_TANTARGY_OSSZES')
|
||||
BEGIN
|
||||
DECLARE @entityId int
|
||||
,@entityTanevId int
|
||||
,@intezmenyId int
|
||||
,@kovTanevId int
|
||||
DECLARE @sql nvarchar(400) = 'SELECT TOP 1 @entityTanevId = C_TANEVID FROM ' + @tableNameFromJson + ' WHERE ID = ' + (SELECT TOP 1 CAST(ID AS varchar(9)) FROM #entityIds)
|
||||
EXEC sp_executesql @sql, N'@entityTanevId int output', @entityTanevId = @entityTanevId output
|
||||
SELECT @intezmenyId = C_INTEZMENYID FROM T_TANEV WHERE ID = @entityTanevId
|
||||
SELECT @kovTanevId = ID FROM T_TANEV_OSSZES WHERE C_INTEZMENYID = @intezmenyId AND C_KOVETKEZO = 'T' AND TOROLT = 'F'
|
||||
IF @entityTanevId <> @kovTanevId AND @kovTanevId IS NOT NULL
|
||||
BEGIN
|
||||
DECLARE entityCur CURSOR FOR
|
||||
SELECT ID FROM #entityIds
|
||||
OPEN entityCur
|
||||
FETCH NEXT FROM entityCur
|
||||
INTO @entityId
|
||||
WHILE @@FETCH_STATUS = 0
|
||||
BEGIN
|
||||
IF @tableNameFromJson = 'T_TEREM_OSSZES' BEGIN
|
||||
EXEC sp_FollowUpTerem
|
||||
@intezmenyId = @intezmenyId
|
||||
,@aktTanevId = @entityTanevId
|
||||
,@kovetkezoTanevId = @kovTanevId
|
||||
,@teremId = @entityId
|
||||
END
|
||||
ELSE IF @tableNameFromJson = 'T_ESZKOZ_OSSZES' BEGIN
|
||||
EXEC sp_FollowUpEszkoz
|
||||
@intezmenyId = @intezmenyId
|
||||
,@aktTanevId = @entityTanevId
|
||||
,@kovetkezoTanevId = @kovTanevId
|
||||
,@eszkozId = @entityId
|
||||
END
|
||||
ELSE IF @tableNameFromJson = 'T_TANTARGY_OSSZES' BEGIN
|
||||
EXEC sp_FollowUpTantargy
|
||||
@intezmenyId = @intezmenyId
|
||||
,@aktTanevId = @entityTanevId
|
||||
,@kovetkezoTanevId = @kovTanevId
|
||||
,@tantargyId = @entityId
|
||||
END
|
||||
FETCH NEXT FROM entityCur INTO @entityId
|
||||
END
|
||||
CLOSE entityCur
|
||||
DEALLOCATE entityCur
|
||||
END
|
||||
END
|
||||
END
|
||||
END
|
||||
END
|
||||
|
||||
|
||||
GO
|
||||
|
|
@ -0,0 +1,314 @@
|
|||
-- =============================================
|
||||
-- Description: <Gondviselö import>
|
||||
-- =============================================
|
||||
DROP PROCEDURE IF EXISTS uspGondviseloImport
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE uspGondviseloImport
|
||||
@pIntezmenyId int
|
||||
,@pTanevId int
|
||||
,@pUserId int
|
||||
,@pImportJson nvarchar(MAX)
|
||||
AS BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
DECLARE
|
||||
@tableNameList nvarchar(2000) = 'T_GONDVISELO_OSSZES'
|
||||
,@actualJson nvarchar(MAX) = ''
|
||||
,@lastChangedDateTime datetime = GETDATE()
|
||||
|
||||
--NOTE: A törlés azért false, mert a gondviselö importálásoknál soha nem törlünk!
|
||||
EXECUTE [dbo].[uspDynamicImportJsonSplit] @pIntezmenyId = @pIntezmenyId, @pTanevId = @pTanevId, @pUserId = @pUserId, @pImportJson = @pImportJson, @pIsTorles = 0, @pIsSubTable = 0, @pTableNameList = @tableNameList
|
||||
|
||||
--NOTE: Telefon temp tábla incializálása
|
||||
CREATE TABLE #TelefonTempTable (
|
||||
ID int
|
||||
,C_TELEFONTIPUSA int
|
||||
,C_TELEFONSZAM nvarchar(100)
|
||||
,C_LEIRAS nvarchar(50)
|
||||
,C_ALAPERTELMEZETT char(1)
|
||||
,C_ISPUBLIC char(1)
|
||||
,C_FELHASZNALOID int
|
||||
,C_GONDVISELOID int
|
||||
|
||||
,C_INTEZMENYID int
|
||||
,C_TANEVID int
|
||||
,TOROLT char(1)
|
||||
,SERIAL int
|
||||
,LASTCHANGED DATETIME
|
||||
,CREATED DATETIME
|
||||
,MODIFIER int
|
||||
,CREATOR int
|
||||
,ELOZOTANEVIREKORDID int
|
||||
,NNID int
|
||||
,Operation int
|
||||
)
|
||||
|
||||
INSERT INTO
|
||||
#TelefonTempTable
|
||||
SELECT
|
||||
tf.ID
|
||||
,tf.C_TELEFONTIPUSA
|
||||
,tf.C_TELEFONSZAM
|
||||
,tf.C_LEIRAS
|
||||
,tf.C_ALAPERTELMEZETT
|
||||
,tf.C_ISPUBLIC
|
||||
,tf.C_FELHASZNALOID
|
||||
,g.ID
|
||||
|
||||
,tf.C_INTEZMENYID
|
||||
,tf.C_TANEVID
|
||||
,tf.TOROLT
|
||||
,tf.SERIAL
|
||||
,tf.LASTCHANGED
|
||||
,tf.CREATED
|
||||
,tf.MODIFIER
|
||||
,tf.CREATOR
|
||||
,tf.ELOZOTANEVIREKORDID
|
||||
,tf.NNID
|
||||
,tf.Operation
|
||||
FROM OPENJSON(@pImportJson, N'lax $.ImportJson.T_TELEFON_OSSZES')
|
||||
WITH (
|
||||
ID int '$.ID'
|
||||
,C_TELEFONTIPUSA int '$.C_TELEFONTIPUSA'
|
||||
,C_TELEFONSZAM nvarchar(100) '$.C_TELEFONSZAM'
|
||||
,C_LEIRAS nvarchar(50) '$.C_LEIRAS'
|
||||
,C_ALAPERTELMEZETT char(1) '$.C_ALAPERTELMEZETT'
|
||||
,C_ISPUBLIC char(1) '$.C_ISPUBLIC'
|
||||
,C_FELHASZNALOID int '$.C_FELHASZNALOID'
|
||||
|
||||
,C_INTEZMENYID int '$.C_INTEZMENYID'
|
||||
,C_TANEVID int '$.C_TANEVID'
|
||||
,TOROLT char(1) '$.TOROLT'
|
||||
,SERIAL int '$.SERIAL'
|
||||
,LASTCHANGED DATETIME '$.LASTCHANGED'
|
||||
,CREATED DATETIME '$.CREATED'
|
||||
,MODIFIER int '$.MODIFIER'
|
||||
,CREATOR int '$.CREATOR'
|
||||
,ELOZOTANEVIREKORDID int '$.ELOZOTANEVIREKORDID'
|
||||
,NNID int '$.NNID'
|
||||
,Operation int '$.Operation'
|
||||
|
||||
,Nev nvarchar(200) '$.Nev'
|
||||
,RokonsagiFokId int '$.RokonsagiFokId'
|
||||
) tf
|
||||
LEFT JOIN T_GONDVISELO_OSSZES g ON
|
||||
--NOTE: A leküldött adat már teljesen jól formázott, de a db-ben lehetnek rossz adatok. Az összehasonlításhoz ezt csináljuk:
|
||||
-- Kisbetûsítjük -> Lecseréljük a NO BREAK SPACE-eket, SPACE-ekre -> Lecseréljük az összes többszörös szóközt egyre -> Trimmelünk
|
||||
LTRIM(RTRIM(REPLACE(REPLACE(REPLACE(REPLACE(LOWER(g.C_NEV),char(160),char(32)),char(32),'(¤¤)'),'¤)(¤',''),'(¤¤)',char(32)))) = LOWER(tf.Nev)
|
||||
AND g.C_ROKONSAGFOKA = tf.RokonsagiFokId
|
||||
AND g.C_TANULOID = tf.C_FELHASZNALOID
|
||||
AND g.C_INTEZMENYID = tf.C_INTEZMENYID
|
||||
AND g.C_TANEVID = tf.C_TANEVID
|
||||
AND g.TOROLT = 'F'
|
||||
|
||||
--NOTE: Email temp tábla incializálása
|
||||
CREATE TABLE #EmailTempTable (
|
||||
ID int
|
||||
,C_EMAILTIPUSA int
|
||||
,C_EMAILCIM nvarchar(200)
|
||||
,C_ALAPERTELMEZETT char(1)
|
||||
,C_ISPUBLIC char(1)
|
||||
,C_FELHASZNALOID int
|
||||
,C_GONDVISELOID int
|
||||
|
||||
,C_INTEZMENYID int
|
||||
,C_TANEVID int
|
||||
,TOROLT char(1)
|
||||
,SERIAL int
|
||||
,LASTCHANGED datetime
|
||||
,CREATED datetime
|
||||
,MODIFIER int
|
||||
,CREATOR int
|
||||
,ELOZOTANEVIREKORDID int
|
||||
,NNID int
|
||||
,Operation int
|
||||
)
|
||||
|
||||
INSERT INTO
|
||||
#EmailTempTable
|
||||
SELECT
|
||||
e.ID
|
||||
,e.C_EMAILTIPUSA
|
||||
,e.C_EMAILCIM
|
||||
,e.C_ALAPERTELMEZETT
|
||||
,e.C_ISPUBLIC
|
||||
,e.C_FELHASZNALOID
|
||||
,g.ID
|
||||
|
||||
,e.C_INTEZMENYID
|
||||
,e.C_TANEVID
|
||||
,e.TOROLT
|
||||
,e.SERIAL
|
||||
,e.LASTCHANGED
|
||||
,e.CREATED
|
||||
,e.MODIFIER
|
||||
,e.CREATOR
|
||||
,e.ELOZOTANEVIREKORDID
|
||||
,e.NNID
|
||||
,e.Operation
|
||||
FROM OPENJSON(@pImportJson, N'lax $.ImportJson.T_EMAIL_OSSZES')
|
||||
WITH (
|
||||
ID int '$.ID'
|
||||
,C_EMAILTIPUSA int '$.C_EMAILTIPUSA'
|
||||
,C_EMAILCIM nvarchar(200) '$.C_EMAILCIM'
|
||||
,C_ALAPERTELMEZETT char(1) '$.C_ALAPERTELMEZETT'
|
||||
,C_ISPUBLIC char(1) '$.C_ISPUBLIC'
|
||||
,C_FELHASZNALOID int '$.C_FELHASZNALOID'
|
||||
|
||||
,C_INTEZMENYID int '$.C_INTEZMENYID'
|
||||
,C_TANEVID int '$.C_TANEVID'
|
||||
,TOROLT char(1) '$.TOROLT'
|
||||
,SERIAL int '$.SERIAL'
|
||||
,LASTCHANGED datetime '$.LASTCHANGED'
|
||||
,CREATED datetime '$.CREATED'
|
||||
,MODIFIER int '$.MODIFIER'
|
||||
,CREATOR int '$.CREATOR'
|
||||
,ELOZOTANEVIREKORDID int '$.ELOZOTANEVIREKORDID'
|
||||
,NNID int '$.NNID'
|
||||
,Operation int '$.Operation'
|
||||
|
||||
,Nev nvarchar(200) '$.Nev'
|
||||
,RokonsagiFokId int '$.RokonsagiFokId'
|
||||
) e
|
||||
LEFT JOIN T_GONDVISELO_OSSZES g ON
|
||||
--NOTE: A leküldött adat már teljesen jól formázott, de a db-ben lehetnek rossz adatok. Az összehasonlításhoz ezt csináljuk:
|
||||
-- Kisbetûsítjük -> Lecseréljük a NO BREAK SPACE-eket, SPACE-ekre -> Lecseréljük az összes többszörös szóközt egyre -> Trimmelünk
|
||||
LTRIM(RTRIM(REPLACE(REPLACE(REPLACE(REPLACE(LOWER(g.C_NEV),char(160),char(32)),char(32),'(¤¤)'),'¤)(¤',''),'(¤¤)',char(32)))) = LOWER(e.Nev)
|
||||
AND g.C_ROKONSAGFOKA = e.RokonsagiFokId
|
||||
AND g.C_TANULOID = e.C_FELHASZNALOID
|
||||
AND g.C_INTEZMENYID = e.C_INTEZMENYID
|
||||
AND g.C_TANEVID = e.C_TANEVID
|
||||
AND g.TOROLT = 'F'
|
||||
|
||||
--NOTE: Ha van bejövõ telefon a json-ben, akkor az ehhez a telefonhoz tartozó felhasználó összes telefonjának C_ALAPERTELMEZETT mezõjét false-ra állítjuk és a bejövõ lesz a egyedül true!
|
||||
UPDATE tf SET
|
||||
tf.C_ALAPERTELMEZETT = 'F'
|
||||
,tf.SERIAL = tf.SERIAL + 1
|
||||
,tf.LASTCHANGED = @lastChangedDateTime
|
||||
,tf.MODIFIER = @pUserId
|
||||
FROM T_FELHASZNALO_OSSZES fh
|
||||
INNER JOIN #TelefonTempTable ON
|
||||
#TelefonTempTable.C_INTEZMENYID = fh.C_INTEZMENYID
|
||||
AND #TelefonTempTable.C_TANEVID = fh.C_TANEVID
|
||||
AND #TelefonTempTable.TOROLT = 'F'
|
||||
AND #TelefonTempTable.C_FELHASZNALOID = fh.ID
|
||||
INNER JOIN T_TELEFON_OSSZES tf ON
|
||||
tf.C_INTEZMENYID = fh.C_INTEZMENYID
|
||||
AND tf.C_TANEVID = fh.C_TANEVID
|
||||
AND tf.TOROLT = 'F'
|
||||
AND tf.C_FELHASZNALOID = fh.ID
|
||||
AND tf.C_ALAPERTELMEZETT = 'T'
|
||||
AND tf.C_GONDVISELOID = #TelefonTempTable.C_GONDVISELOID
|
||||
WHERE fh.C_INTEZMENYID = @pIntezmenyId
|
||||
AND fh.C_TANEVID = @pTanevId
|
||||
AND fh.TOROLT = 'F'
|
||||
|
||||
--NOTE: Ha van bejövõ email a json-ben, akkor az ehhez a email-hez tartozó felhasználó összes email-jének C_ALAPERTELMEZETT mezõjét false-ra állítjuk és a bejövõ lesz a egyedül true!
|
||||
UPDATE e SET
|
||||
e.C_ALAPERTELMEZETT = 'F'
|
||||
,e.SERIAL = e.SERIAL + 1
|
||||
,e.LASTCHANGED = @lastChangedDateTime
|
||||
,e.MODIFIER = @pUserId
|
||||
FROM T_FELHASZNALO_OSSZES fh
|
||||
INNER JOIN #EmailTempTable ON
|
||||
#EmailTempTable.C_INTEZMENYID = fh.C_INTEZMENYID
|
||||
AND #EmailTempTable.C_TANEVID = fh.C_TANEVID
|
||||
AND #EmailTempTable.TOROLT = 'F'
|
||||
AND #EmailTempTable.C_FELHASZNALOID = fh.ID
|
||||
INNER JOIN T_EMAIL_OSSZES e ON
|
||||
e.C_INTEZMENYID = fh.C_INTEZMENYID
|
||||
AND e.C_TANEVID = fh.C_TANEVID
|
||||
AND e.TOROLT = 'F'
|
||||
AND e.C_FELHASZNALOID = fh.ID
|
||||
AND e.C_ALAPERTELMEZETT = 'T'
|
||||
AND e.C_GONDVISELOID = #EmailTempTable.C_GONDVISELOID
|
||||
WHERE fh.C_INTEZMENYID = @pIntezmenyId
|
||||
AND fh.C_TANEVID = @pTanevId
|
||||
AND fh.TOROLT = 'F'
|
||||
|
||||
--Telefonok beszúrása
|
||||
SET @actualJson = ' { "ImportJson":{ "T_TELEFON_OSSZES":' + (
|
||||
SELECT
|
||||
tf.ID
|
||||
,tf.C_TELEFONTIPUSA
|
||||
,tf.C_TELEFONSZAM
|
||||
,tf.C_LEIRAS
|
||||
,tf.C_ALAPERTELMEZETT
|
||||
,tf.C_ISPUBLIC
|
||||
,tf.C_FELHASZNALOID
|
||||
,tf.C_GONDVISELOID
|
||||
|
||||
,tf.C_INTEZMENYID
|
||||
,tf.C_TANEVID
|
||||
,tf.TOROLT
|
||||
,tf.SERIAL
|
||||
,tf.LASTCHANGED
|
||||
,tf.CREATED
|
||||
,tf.MODIFIER
|
||||
,tf.CREATOR
|
||||
,tf.ELOZOTANEVIREKORDID
|
||||
,tf.NNID
|
||||
,tf.Operation
|
||||
FROM #TelefonTempTable AS tf
|
||||
FOR JSON PATH,INCLUDE_NULL_VALUES
|
||||
)
|
||||
|
||||
SET @actualJson = @actualJson + ' } }'
|
||||
|
||||
EXECUTE [dbo].[uspDynamicImport] @pIntezmenyId = @pIntezmenyId, @pTanevId = @pTanevId, @pUserId = @pUserId, @pImportJson = @actualJson, @pIsTorles = 0, @pIsSubTable = 0
|
||||
|
||||
--Emailek beszúrása
|
||||
SET @actualJson = ' { "ImportJson":{ "T_EMAIL_OSSZES":' + (
|
||||
SELECT
|
||||
e.ID
|
||||
,e.C_EMAILTIPUSA
|
||||
,e.C_EMAILCIM
|
||||
,e.C_ALAPERTELMEZETT
|
||||
,e.C_ISPUBLIC
|
||||
,e.C_FELHASZNALOID
|
||||
,e.C_GONDVISELOID
|
||||
|
||||
,e.C_INTEZMENYID
|
||||
,e.C_TANEVID
|
||||
,e.TOROLT
|
||||
,e.SERIAL
|
||||
,e.LASTCHANGED
|
||||
,e.CREATED
|
||||
,e.MODIFIER
|
||||
,e.CREATOR
|
||||
,e.ELOZOTANEVIREKORDID
|
||||
,e.NNID
|
||||
,e.Operation
|
||||
FROM #EmailTempTable AS e
|
||||
FOR JSON PATH,INCLUDE_NULL_VALUES
|
||||
)
|
||||
|
||||
SET @actualJson = @actualJson + ' } }'
|
||||
|
||||
EXECUTE [dbo].[uspDynamicImport] @pIntezmenyId = @pIntezmenyId, @pTanevId = @pTanevId, @pUserId = @pUserId, @pImportJson = @actualJson, @pIsTorles = 0, @pIsSubTable = 0
|
||||
|
||||
--NOTE: Vissza kell térnünk az ID-kkal a fájlletöltéshez és az emailküldéshez!
|
||||
SELECT g.ID
|
||||
FROM OPENJSON(@pImportJson, N'lax $.ImportJson.T_GONDVISELO_OSSZES')
|
||||
WITH (
|
||||
C_NEV nvarchar(200) '$.C_NEV'
|
||||
,C_ROKONSAGFOKA int '$.C_ROKONSAGFOKA'
|
||||
,C_TANULOID int '$.C_TANULOID'
|
||||
,C_INTEZMENYID int '$.C_INTEZMENYID'
|
||||
,C_TANEVID int '$.C_TANEVID'
|
||||
) GondviseloJsonData
|
||||
LEFT JOIN T_GONDVISELO_OSSZES g ON
|
||||
--NOTE: A leküldött adat már teljesen jól formázott, de a db-ben lehetnek rossz adatok. Az összehasonlításhoz ezt csináljuk:
|
||||
-- Kisbetûsítjük -> Lecseréljük a NO BREAK SPACE-eket, SPACE-ekre -> Lecseréljük az összes többszörös szóközt egyre -> Trimmelünk
|
||||
LTRIM(RTRIM(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(LOWER(g.C_NEV),char(160),char(32)),char(9),char(32)),char(32),'(¤¤)'),'¤)(¤',''),'(¤¤)',char(32)))) = LOWER(GondviseloJsonData.C_NEV)
|
||||
AND g.C_ROKONSAGFOKA = GondviseloJsonData.C_ROKONSAGFOKA
|
||||
AND g.C_TANULOID = GondviseloJsonData.C_TANULOID
|
||||
AND g.C_INTEZMENYID = GondviseloJsonData.C_INTEZMENYID
|
||||
AND g.C_TANEVID = GondviseloJsonData.C_TANEVID
|
||||
AND g.TOROLT = 'F'
|
||||
END
|
||||
|
||||
|
||||
GO
|
||||
|
Loading…
Add table
Add a link
Reference in a new issue