-- ============================================= -- Description: -- ============================================= SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO IF OBJECT_ID('[dbo].[sp_DynamicImport]') IS NOT NULL BEGIN DROP PROCEDURE [dbo].[sp_DynamicImport] END GO CREATE PROCEDURE [dbo].[sp_DynamicImport] @pImportJson NVARCHAR(MAX) ,@pIsTorles BIT ,@pUserId INT ,@pInsertAlways BIT = 0 AS BEGIN -- SET NOCOUNT ON added to prevent extra result sets from interfering with SELECT statements. SET NOCOUNT ON; DECLARE @sqlCommand NVARCHAR(MAX) = '' ,@lastChangedDateTime DATETIME = GETDATE() ,@modifierId INT = @pUserId ,@openJsonWithCommand NVARCHAR(MAX) ,@rootElementJsonWithCommand NVARCHAR(300) ,@columnNameFromJsonCommand NVARCHAR(300) ,@columnListForInsert NVARCHAR(MAX) ,@columnListForUpdate NVARCHAR(MAX) ,@sqlInsertCommand NVARCHAR(MAX) ,@sqlUpdateCommand NVARCHAR(MAX) ,@sqlDeleteCommand NVARCHAR(MAX) ,@rootElement NVARCHAR(100) ,@tableNameFromJson NVARCHAR(50) ,@columnCount INT ,@openJsonPath NVARCHAR(300) 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), @modifierId) + ''' WHERE ' + @tableNameFromJson + '.TOROLT = ''F'' AND ' + @tableNameFromJson + '.C_IMPORTALT = ''T'' ' SET @sqlCommand = @sqlDeleteCommand + @sqlCommand 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) + ')' --OSZLOPLISTA INSERTHEZ SELECT @columnListForInsert = ISNULL(@columnListForInsert + ', ', '') + '[' + columnDataTable.ColumnName + ']' --TODO andrejkovicse: Függvény a []-ra FROM @ColumnDataTable columnDataTable WHERE columnDataTable.ColumnName <> 'ID' OR @pInsertAlways = 1 --OSZLOPLISTA UPDATHEZ SELECT @columnListForUpdate = ISNULL(@columnListForUpdate + ', ', '') + '[' + @tableNameFromJson + '].' + '[' + columnDataTable.ColumnName + '] = [ImportData].' + '[' + columnDataTable.ColumnName + ']' FROM @ColumnDataTable columnDataTable WHERE columnDataTable.ColumnName NOT IN ('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 + ') SELECT ' + @columnListForInsert + ' FROM OPENJSON(@pImportJson, ' + @openJsonPath + ') WITH ' + @openJsonWithCommand IF(@pInsertAlways = 0) BEGIN SET @sqlInsertCommand = @sqlInsertCommand + ' WHERE ID IS NULL ' END IF(@pInsertAlways = 0) BEGIN --UPDATE összeállítása SET @sqlUpdateCommand = 'UPDATE ' + @tableNameFromJson + ' SET ' + @columnListForUpdate + ', ' + @tableNameFromJson + '.SERIAL = ' + @tableNameFromJson + '.SERIAL + 1 ' + ' FROM (SELECT * FROM OPENJSON(@pImportJson, ' + @openJsonPath + ') WITH ' + @openJsonWithCommand + ' WHERE ID IS NOT NULL) AS ImportData WHERE ' + @tableNameFromJson + '.ID = ImportData.ID ' END IF(@sqlUpdateCommand IS NULL OR @sqlUpdateCommand = '') BEGIN SET @sqlCommand = @sqlCommand + @sqlInsertCommand END ELSE BEGIN SET @sqlCommand = @sqlCommand + @sqlInsertCommand + @sqlUpdateCommand END END IF(@sqlCommand IS NOT NULL OR @sqlCommand <> '') BEGIN EXEC sp_executesql @sqlCommand, N'@pImportJson NVARCHAR(MAX)', @pImportJson END END END GO