├── .gitattributes ├── .gitignore ├── AdventureWorks.zip ├── ArrayInArrayJsonDataFromTable.sql ├── BatchToSaveDataToDisk.sql ├── Benchmark_Test-harness.sql ├── CreateJSONArrayInArraySchemaFromTable.sql ├── CreateJSONSchemaFromTable.sql ├── ExampleofCreateJSONSchemaFromTable.sql ├── GenerateSQLMergeScripts.ps1 ├── JsonResultToJsonArray.sql ├── OpenJSONExpressions.sql ├── ReadMe.md ├── SaveAllTables as ArrayinArrayJSON.sql ├── SaveExtendedJsonDataFromTable.sql ├── SaveJSONDataToTable.sql ├── SaveJSONToFile.sql ├── SaveJsonDataFromTable.sql ├── SaveMergeStatementFromTable.sql ├── SaveMultiRowSelectStatementFromTable.sql ├── SelectJSONIntoTable.sql ├── TablesFromJSON.sql ├── UnwrapJSON.sql └── ValidateViaJSONSchema.ps1 /.gitattributes: -------------------------------------------------------------------------------- 1 | # Auto detect text files and perform LF normalization 2 | * text=auto 3 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | ArrayInArray2JsonDataFromTable.sql 2 | -------------------------------------------------------------------------------- /AdventureWorks.zip: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Phil-Factor/JSONSQLServerRoutines/a591e97101156496eb205905c18afe4918c5d907/AdventureWorks.zip -------------------------------------------------------------------------------- /ArrayInArrayJsonDataFromTable.sql: -------------------------------------------------------------------------------- 1 | CREATE OR ALTER PROCEDURE #ArrayInArrayJsonDataFromTable 2 | /** 3 | Summary: > 4 | This gets the JSON data from a query or table into 5 | Array-in-Array JSON Format 6 | Author: phil factor 7 | Date: 26/10/2018 8 | 9 | Examples: > 10 | 11 | - use Adventureworks2016 12 | DECLARE @Json NVARCHAR(MAX) 13 | EXECUTE #ArrayInArrayJsonDataFromTable 14 | @query = 'Select * from person.addresstype;', 15 | @JSONData=@json OUTPUT 16 | PRINT @Json 17 | 18 | - use Adventureworks2016 19 | DECLARE @Json NVARCHAR(MAX) 20 | EXECUTE #ArrayInArrayJsonDataFromTable 21 | @query = ' 22 | SELECT AccountNumber, PersonType, Title, FirstName, MiddleName, LastName, 23 | Suffix, AddressLine1, AddressLine2, City, PostalCode, Name 24 | FROM Sales.Customer 25 | INNER JOIN Person.Person 26 | ON Customer.PersonID = Person.BusinessEntityID 27 | INNER JOIN Person.BusinessEntityAddress 28 | ON Person.BusinessEntityID = BusinessEntityAddress.BusinessEntityID 29 | INNER JOIN Person.Address 30 | ON BusinessEntityAddress.AddressID = Address.AddressID 31 | INNER JOIN Person.AddressType 32 | ON BusinessEntityAddress.AddressTypeID = AddressType.AddressTypeID ;', 33 | @JSONData=@json OUTPUT 34 | PRINT @Json 35 | 36 | 37 | - use Adventureworks2016 38 | DECLARE @Json NVARCHAR(MAX) 39 | EXECUTE #ArrayInArrayJsonDataFromTable 40 | @database='Adventureworks2016', 41 | @Schema ='person', 42 | @table= 'PersonPhone', 43 | @JSONData=@json OUTPUT 44 | PRINT @Json 45 | 46 | - DECLARE @Json NVARCHAR(MAX) 47 | EXECUTE #ArrayInArrayJsonDataFromTable 48 | @TableSpec='Adventureworks2016.[production].[document]', 49 | @JSONData=@json OUTPUT 50 | PRINT @Json 51 | Returns: > 52 | The JSON data 53 | 54 | **/ 55 | (@database sysname = NULL, @Schema sysname = NULL, @table sysname = NULL, 56 | @Tablespec sysname = NULL, --this means 57 | @Query NVARCHAR(MAX) = NULL, @jsonData NVARCHAR(MAX) OUTPUT 58 | ) 59 | AS 60 | BEGIN 61 | DECLARE @SourceCode NVARCHAR(4000); 62 | IF @database IS NULL SELECT @database = 63 | Coalesce(ParseName(@Tablespec, 3), Db_Name()); 64 | IF @Query IS NULL 65 | BEGIN 66 | IF Coalesce(@table, @Tablespec) IS NULL 67 | OR Coalesce(@Schema, @Tablespec) IS NULL 68 | RAISERROR('{"error":"must have the table details"}', 16, 1); 69 | 70 | IF @table IS NULL SELECT @table = ParseName(@Tablespec, 1); 71 | IF @Schema IS NULL SELECT @Schema = ParseName(@Tablespec, 2); 72 | IF @table IS NULL OR @Schema IS NULL OR @database IS NULL 73 | RAISERROR('{"error":"must have the table details"}', 16, 1); 74 | SELECT @SourceCode = 75 | N'USE ' + @database + N'; SELECT * FROM ' + QuoteName(@database) 76 | + N'.' + QuoteName(@Schema) + N'.' + QuoteName(@table); 77 | END; 78 | ELSE 79 | BEGIN 80 | SELECT @SourceCode = N'USE ' + @database + N';' + @Query; 81 | END; 82 | DECLARE @list NVARCHAR(4000); 83 | DECLARE @AllErrors NVARCHAR(4000); 84 | DECLARE @params NVARCHAR(MAX); 85 | -- SQL Prompt formatting off 86 | SELECT @params='''[''+' 87 | +String_Agg( 88 | CASE 89 | --hierarchyid, geometry,and geography types can be coerced. 90 | WHEN system_type_id IN (240) 91 | THEN 'Coalesce(''"''+convert(nvarchar(max),' + QuoteName(name) + ')+''"'',''null'')' 92 | --text and ntext 93 | WHEN system_type_id IN (35,99) 94 | THEN 'Coalesce(''"''+convert(nvarchar(max),' + QuoteName(name) + ')+''"'',''null'')' 95 | --image varbinary 96 | WHEN system_type_id IN (34,165) 97 | THEN 'Coalesce(''"''+convert(nvarchar(max),' + QuoteName(name) + ',2)+''"'',''null'')' 98 | --dates 99 | --WHEN r.system_type_id IN (165) THEN 'Coalesce(''"''+convert(varbinary(max),' + QuoteName(name) + ')+''"'',''null'')' 100 | WHEN r.system_type_id IN (40,41,42,43,58,61) 101 | THEN 'Coalesce(''"''+convert(nvarchar(max),'+QuoteName(name)+',126)+''"'',''null'')' 102 | --numbers 103 | WHEN r.system_type_id IN (48,52,56,59,60,62,106,108,122,127) 104 | THEN 'Coalesce(convert(nvarchar(max),'+QuoteName(name)+'),''null'')' 105 | --uniqueIdentifier 106 | WHEN system_type_id IN (36) 107 | THEN 'Coalesce(''"''+convert(nvarchar(max),' + QuoteName(name) + ')+''"'',''null'')' 108 | --bit 109 | WHEN system_type_id =104 110 | THEN 'Coalesce(case when '+QuoteName(name)+ '>0 then ''true'' else ''false'' end,''null'') ' 111 | --xml 112 | WHEN system_type_id = 241 113 | THEN 'Coalesce(''"''+String_Escape(convert(nvarchar(max),'+QuoteName(name)+'),''json'')+''"'',''null'')' 114 | ELSE 'Coalesce(''"''+String_Escape('+QuoteName(name)+',''json'') + ''"'',''null'')' END,'+'', ''+' 115 | ) +'+'']''', 116 | @list=String_Agg(QuoteName(name),', '), 117 | @allErrors=String_Agg([error_message],', ') 118 | FROM sys.dm_exec_describe_first_result_set(@SourceCode, NULL, 1)r WHERE Coalesce(is_hidden,0)=0 119 | 120 | -- SQL Prompt formatting on 121 | DECLARE @expression NVARCHAR(4000); 122 | IF @params IS NULL 123 | BEGIN 124 | RAISERROR( 'Source Code %s couldn''t be executed because %s',16,1,@SourceCode, @AllErrors); 125 | END; 126 | IF @Query IS NULL 127 | BEGIN 128 | SELECT @expression = 129 | N' 130 | USE ' + @database + N' 131 | Select @TheData= ''[''+String_Agg(' + @params + N','','')+'']'' 132 | FROM ' + QuoteName(@database) + N'.' + QuoteName(@Schema) + N'.' 133 | + QuoteName(@table) + N';'; 134 | END; 135 | ELSE 136 | BEGIN --take out any trailing semicolon 137 | SELECT @Query = 138 | CASE WHEN Lastsemi < LastText 139 | THEN Left(query, Len(query + ';' COLLATE SQL_Latin1_General_CP1_CI_AI) - Lastsemi - 1) 140 | ELSE query END 141 | FROM 142 | ( 143 | SELECT query, 144 | PatIndex 145 | ( 146 | SemicolonWildcard, 147 | Reverse(';' + query COLLATE SQL_Latin1_General_CP1_CI_AI) 148 | COLLATE SQL_Latin1_General_CP1_CI_AI 149 | ) AS Lastsemi, 150 | PatIndex( 151 | sqltextWildcard, 152 | Reverse(query) COLLATE SQL_Latin1_General_CP1_CI_AI) AS LastText 153 | FROM 154 | ( 155 | SELECT @Query AS query, '%;%' AS SemicolonWildcard, 156 | '%[A-Z1-0_-]%' AS sqltextWildcard 157 | ) AS f 158 | ) AS g; 159 | SELECT @expression = 160 | N'USE ' + @database + N'; 161 | Select @TheData= ''[''+String_Agg(' + @params + N','','')+'']'' 162 | FROM (' + @Query + N')f(' + @list + N')'; 163 | END; 164 | EXECUTE sp_executesql @expression, N'@TheData nvarchar(max) output', 165 | @TheData = @jsonData OUTPUT; 166 | IF IsJson(@jsonData) = 0 RAISERROR( 167 | '{"Table %s did not produce valid JSON"}', 16, 1, @table 168 | ); 169 | END; 170 | GO 171 | -------------------------------------------------------------------------------- /BatchToSaveDataToDisk.sql: -------------------------------------------------------------------------------- 1 | CREATE OR ALTER PROCEDURE #CreateJSONSchemaFromTable 2 | /** 3 | Summary: > 4 | This creates a JSON schema from a table that 5 | matches the JSON you will get from doing a 6 | classic FOR JSON select * statemenmt on the entire table 7 | 8 | Author: phil factor 9 | Date: 26/10/2018 10 | 11 | Examples: > 12 | DECLARE @Json NVARCHAR(MAX) 13 | EXECUTE #CreateJSONSchemaFromTable @database='pubs', @Schema ='dbo', @table= 'authors',@JSONSchema=@json OUTPUT 14 | PRINT @Json 15 | SELECT @json='' 16 | EXECUTE #CreateJSONSchemaFromTable @TableSpec='pubs.dbo.authors',@JSONSchema=@json OUTPUT 17 | PRINT @Json 18 | Returns: > 19 | nothing 20 | **/ 21 | (@database sysname=null, @Schema sysname=NULL, @table sysname=null, @Tablespec sysname=NULL,@jsonSchema NVARCHAR(MAX) output) 22 | 23 | --WITH ENCRYPTION|SCHEMABINDING, ... 24 | AS 25 | 26 | DECLARE @required NVARCHAR(max), @NoColumns INT, @properties NVARCHAR(max); 27 | 28 | IF Coalesce(@table,@Tablespec) IS NULL 29 | OR Coalesce(@schema,@Tablespec) IS NULL 30 | RAISERROR ('{"error":"must have the table details"}',16,1) 31 | 32 | IF @table is NULL SELECT @table=ParseName(@Tablespec,1) 33 | IF @Schema is NULL SELECT @schema=ParseName(@Tablespec,2) 34 | IF @Database is NULL SELECT @Database=ParseName(@Tablespec,3) 35 | IF @table IS NULL OR @schema IS NULL OR @database IS NULL 36 | RAISERROR ('{"error":"must have the table details"}',16,1) 37 | 38 | DECLARE @SourceCode NVARCHAR(255)= 39 | (SELECT 'SELECT * FROM '+QuoteName(@database)+ '.'+ QuoteName(@Schema)+'.'+QuoteName(@table)) 40 | SELECT 41 | @properties= String_Agg(' 42 | "'+f.name+'": {"type":["'+Replace(type,' ','","')+'"],"sqltype":"'+sqltype+'", "columnNo":'+ Convert(VARCHAR(3), f.column_ordinal) 43 | +', "nullable":'+Convert(CHAR(1),f.is_nullable)+', "Description":"' 44 | +String_Escape(Coalesce(Convert(NvARCHAR(875),EP.value),''),'json')+'"}',','), 45 | @NoColumns=Max(f.column_ordinal), 46 | @required=String_Agg('"'+f.Name+'"',',') 47 | FROM 48 | ( --the basic columns we need. (the type is used more than once in the outer query) 49 | SELECT 50 | r.name, 51 | r.system_type_name AS sqltype, 52 | r.source_column, 53 | r.is_nullable,r.column_ordinal, 54 | CASE WHEN r.system_type_id IN (48, 52, 56, 58, 59, 60, 62, 106, 108, 122, 127) 55 | THEN 'number' 56 | WHEN system_type_id = 104 THEN 'boolean' ELSE 'string' END 57 | + CASE WHEN r.is_nullable = 1 THEN ' null' ELSE '' END AS type, 58 | Object_Id(r.source_database + '.' + r.source_schema + '.' + r.source_table) AS table_id 59 | FROM sys.dm_exec_describe_first_result_set 60 | (@sourcecode, NULL, 1) AS r 61 | ) AS f 62 | LEFT OUTER JOIN sys.extended_properties AS EP -- to get the extended properties 63 | ON EP.major_id = f.table_id 64 | AND EP.minor_id = ColumnProperty(f.table_id, f.source_column, 'ColumnId') 65 | AND EP.name = 'MS_Description' 66 | AND EP.class = 1 67 | 68 | SELECT @JSONschema = 69 | Replace( 70 | Replace( 71 | Replace( 72 | Replace( 73 | Replace('{ 74 | "$id": "https://mml.uk/jsonSchema/<-schema->-<-table->.json", 75 | "$schema": "http://json-schema.org/draft-07/schema#", 76 | "title": "<-table->", 77 | "SQLtablename":"'+quotename(@schema)+'.'+quotename(@table)+'", 78 | "SQLschema":"<-schema->", 79 | "type": "array", 80 | "items": { 81 | "type": "object", 82 | "required": [<-Required->], 83 | "maxProperties": <-MaxColumns->, 84 | "minProperties": <-MinColumns->, 85 | "properties":{'+@properties+'} 86 | } 87 | }', '<-minColumns->', Convert(VARCHAR(5),@NoColumns) COLLATE DATABASE_DEFAULT 88 | ) , '<-maxColumns->',Convert(VARCHAR(5),@NoColumns +1) COLLATE DATABASE_DEFAULT 89 | ) , '<-Required->',@required COLLATE DATABASE_DEFAULT 90 | ) ,'<-schema->',@Schema COLLATE DATABASE_DEFAULT 91 | ) ,'<-table->', @table COLLATE DATABASE_DEFAULT 92 | ); 93 | 94 | 95 | IF(IsJson(@jsonschema)=0) 96 | RAISERROR ('invalid schema "%s"',16,1,@jsonSchema) 97 | IF @jsonschema IS NULL RAISERROR ('Null schema',16,1) 98 | GO 99 | 100 | CREATE OR ALTER PROCEDURE #SaveJSONToFile 101 | @TheString NVARCHAR(MAX), @Filename NVARCHAR(255), 102 | @Unicode INT=8 --0 for not unicode, 8 for utf8 and 16 for utf16 103 | AS 104 | SET NOCOUNT ON 105 | DECLARE @MySpecialTempTable sysname, @Command NVARCHAR(4000) , @RESULT INT 106 | 107 | --firstly we create a global temp table with a unique name 108 | SELECT @MySpecialTempTable = '##temp' 109 | + CONVERT(VARCHAR(12), CONVERT(INT, RAND() * 1000000)) 110 | --then we create it using dynamic SQL, & insert a single row 111 | --in it with the MAX Varchar stocked with the string we want 112 | SELECT @Command = 'create table [' 113 | + @MySpecialTempTable 114 | + '] (MyID int identity(1,1), Bulkcol nvarchar(MAX)) 115 | insert into [' 116 | + @MySpecialTempTable 117 | + '](BulkCol) select @TheString' 118 | EXECUTE sp_ExecuteSQL @command, N'@TheString nvarchar(MAX)', 119 | @TheString 120 | SELECT @command 121 | --then we execute the BCP to save the file 122 | SELECT @Command = 'bcp "select BulkCol from [' 123 | + @MySpecialTempTable + ']' 124 | + '" queryout ' 125 | + @Filename + ' ' 126 | + CASE @Unicode 127 | WHEN 0 THEN '-c' 128 | WHEN 8 THEN '-c -C 65001' 129 | ELSE '-w' END 130 | + ' -T -S' + @@ServerName 131 | SELECT @command 132 | 133 | EXECUTE @RESULT= MASTER..xp_cmdshell @command 134 | EXECUTE ( 'Drop table ' + @MySpecialTempTable ) 135 | RETURN @result 136 | go 137 | CREATE OR ALTER PROCEDURE #SaveJsonDataFromTable 138 | /** 139 | Summary: > 140 | This gets the JSON data from a table 141 | Author: phil factor 142 | Date: 26/10/2018 143 | 144 | Examples: > 145 | USE bigpubs 146 | DECLARE @Json NVARCHAR(MAX) 147 | EXECUTE #SaveJsonDataFromTable 148 | @database='pubs', 149 | @Schema ='dbo', 150 | @table= 'authors', 151 | @JSONData=@json OUTPUT 152 | PRINT @Json 153 | Returns: > 154 | The JSON data 155 | **/ 156 | (@database sysname = NULL, @Schema sysname = NULL, @table sysname = NULL, 157 | @Tablespec sysname = NULL, @jsonData NVARCHAR(MAX) OUTPUT 158 | ) 159 | AS 160 | BEGIN 161 | DECLARE @Data NVARCHAR(MAX); 162 | IF Coalesce(@table, @Tablespec) IS NULL 163 | OR Coalesce(@Schema, @Tablespec) IS NULL 164 | RAISERROR('{"error":"must have the table details"}', 16, 1); 165 | 166 | IF @table IS NULL SELECT @table = ParseName(@Tablespec, 1); 167 | IF @Schema IS NULL SELECT @Schema = ParseName(@Tablespec, 2); 168 | IF @database IS NULL SELECT @database = ParseName(@Tablespec, 3); 169 | IF @table IS NULL OR @Schema IS NULL OR @database IS NULL 170 | RAISERROR('{"error":"must have the table details"}', 16, 1); 171 | 172 | DECLARE @SourceCode NVARCHAR(255) = 173 | ( 174 | SELECT 'SELECT * FROM ' + QuoteName(@database) + '.' 175 | + QuoteName(@Schema) + '.' + QuoteName(@table) 176 | ); 177 | 178 | 179 | DECLARE @params NVARCHAR(MAX) = 180 | ( 181 | SELECT 182 | String_Agg( 183 | CASE WHEN user_type_id IN (128, 129, 130) THEN 184 | 'convert(nvarchar(max),' + name 185 | + ') as "' + name + '"' 186 | --hierarchyid (128) geometry (130) and geography types (129) can be coerced. 187 | WHEN user_type_id IN (35) THEN 188 | 'convert(varchar(max),' + name + ') as "' 189 | + name + '"' 190 | WHEN user_type_id IN (99) THEN 191 | 'convert(nvarchar(max),' + name + ') as "' 192 | + name + '"' 193 | WHEN user_type_id IN (34) THEN 194 | 'convert(varbinary(max),' + name 195 | + ') as "' + name + '"' ELSE 196 | QuoteName(name) END, ', ' ) 197 | FROM sys.dm_exec_describe_first_result_set(@SourceCode, NULL, 1) 198 | ); 199 | DECLARE @expression NVARCHAR(800) = 200 | ' 201 | USE ' + @database + ' 202 | SELECT @TheData=(SELECT ' + @params + ' FROM ' + QuoteName(@database) + '.' 203 | + QuoteName(@Schema) + '.' + QuoteName(@table) 204 | + ' FOR JSON auto, INCLUDE_NULL_VALUES)'; 205 | EXECUTE sp_executesql @expression, N'@TheData nvarchar(max) output', 206 | @TheData = @jsonData OUTPUT; 207 | END; 208 | GO 209 | 210 | 211 | USE WideWorldImporters 212 | 213 | DECLARE @TheCommand NVARCHAR(4000) 214 | SELECT @TheCommand=' 215 | Declare @Path sysname =''C:\data\RawData\'+Db_Name()+'Data\'' 216 | DECLARE @destination NVARCHAR(MAX) = 217 | (Select @path+Replace(Replace(Replace(''?'',''.'',''-''),'']'',''''),''['','''')+''.json'') 218 | DECLARE @Json NVARCHAR(MAX) 219 | EXECUTE #SaveJsonDataFromTable 220 | @database='''+Db_Name()+''', 221 | @tablespec= ''?'', 222 | @JSONData=@json OUTPUT 223 | Execute #SaveJSONToFile @theString=@Json, @filename=@destination' 224 | EXECUTE sp_MSforeachtable @command1=@TheCommand 225 | 226 | DECLARE @TheCommand NVARCHAR(4000) 227 | SELECT @TheCommand=' 228 | DECLARE @TheJSONSchema NVARCHAR(MAX) --our JSON Schema 229 | EXECUTE #CreateJSONSchemaFromTable @TableSpec='''+Db_Name()+'.?'',@JSONSchema=@TheJSONSchema OUTPUT 230 | DECLARE @destination NVARCHAR(MAX) = (Select ''C:\data\RawData\'+Db_Name()+'SchemaData\''+Replace(Replace(Replace(''?'',''.'',''-''),'']'',''''),''['','''')+''.json'') 231 | DECLARE @TheJsonData NVARCHAR(MAX) 232 | EXECUTE #SaveJsonDataFromTable 233 | @database='''+Db_Name()+''', @tablespec= ''?'', @JSONData=@TheJsonData OUTPUT 234 | DECLARE @TheJSON NVARCHAR(MAX)= 235 | (SELECT * 236 | FROM (VALUES(Json_Query(@Thejsonschema), Json_Query(@TheJSONData)))f([schema],[data]) 237 | FOR JSON AUTO, WITHOUT_ARRAY_WRAPPER); 238 | Execute #SaveJSONToFile @theString=@TheJSON, @filename=@destination' 239 | 240 | EXECUTE sp_MSforeachtable @command1=@TheCommand 241 | 242 | 243 | 244 | 245 | 246 | 247 | -------------------------------------------------------------------------------- /Benchmark_Test-harness.sql: -------------------------------------------------------------------------------- 1 | CREATE OR ALTER PROCEDURE #ArrayInArrayJsonDataFromTable 2 | /** 3 | Summary: > 4 | This gets the JSON data from a query or table into 5 | Array-in-Array JSON Format 6 | Author: phil factor 7 | Date: 26/10/2018 8 | 9 | Examples: > 10 | 11 | - use Adventureworks2016 12 | DECLARE @Json NVARCHAR(MAX) 13 | EXECUTE #ArrayInArrayJsonDataFromTable 14 | @query = 'Select * from person.addresstype;', 15 | @JSONData=@json OUTPUT 16 | PRINT @Json 17 | 18 | - use Adventureworks2016 19 | DECLARE @Json NVARCHAR(MAX) 20 | EXECUTE #ArrayInArrayJsonDataFromTable 21 | @query = ' 22 | SELECT AccountNumber, PersonType, Title, FirstName, MiddleName, LastName, 23 | Suffix, AddressLine1, AddressLine2, City, PostalCode, Name 24 | FROM Sales.Customer 25 | INNER JOIN Person.Person 26 | ON Customer.PersonID = Person.BusinessEntityID 27 | INNER JOIN Person.BusinessEntityAddress 28 | ON Person.BusinessEntityID = BusinessEntityAddress.BusinessEntityID 29 | INNER JOIN Person.Address 30 | ON BusinessEntityAddress.AddressID = Address.AddressID 31 | INNER JOIN Person.AddressType 32 | ON BusinessEntityAddress.AddressTypeID = AddressType.AddressTypeID ;', 33 | @JSONData=@json OUTPUT 34 | PRINT @Json 35 | 36 | 37 | - use Adventureworks2016 38 | DECLARE @Json NVARCHAR(MAX) 39 | EXECUTE #ArrayInArrayJsonDataFromTable 40 | @database='Adventureworks2016', 41 | @Schema ='person', 42 | @table= 'PersonPhone', 43 | @JSONData=@json OUTPUT 44 | PRINT @Json 45 | 46 | - DECLARE @Json NVARCHAR(MAX) 47 | EXECUTE #ArrayInArrayJsonDataFromTable 48 | @TableSpec='Adventureworks2016.[production].[document]', 49 | @JSONData=@json OUTPUT 50 | PRINT @Json 51 | Returns: > 52 | The JSON data 53 | 54 | **/ 55 | (@database sysname = NULL, @Schema sysname = NULL, @table sysname = NULL, 56 | @Tablespec sysname = NULL, --this means 57 | @Query NVARCHAR(MAX) = NULL, @jsonData NVARCHAR(MAX) OUTPUT 58 | ) 59 | AS 60 | BEGIN 61 | DECLARE @SourceCode NVARCHAR(4000); 62 | IF @database IS NULL SELECT @database = 63 | Coalesce(ParseName(@Tablespec, 3), Db_Name()); 64 | IF @Query IS NULL 65 | BEGIN 66 | IF Coalesce(@table, @Tablespec) IS NULL 67 | OR Coalesce(@Schema, @Tablespec) IS NULL 68 | RAISERROR('{"error":"must have the table details"}', 16, 1); 69 | 70 | IF @table IS NULL SELECT @table = ParseName(@Tablespec, 1); 71 | IF @Schema IS NULL SELECT @Schema = ParseName(@Tablespec, 2); 72 | IF @table IS NULL OR @Schema IS NULL OR @database IS NULL 73 | RAISERROR('{"error":"must have the table details"}', 16, 1); 74 | SELECT @SourceCode = 75 | N'USE ' + @database + N'; SELECT * FROM ' + QuoteName(@database) 76 | + N'.' + QuoteName(@Schema) + N'.' + QuoteName(@table); 77 | END; 78 | ELSE BEGIN 79 | SELECT @SourceCode = N'USE ' + @database + N';' + @Query; 80 | END; 81 | DECLARE @list NVARCHAR(4000); 82 | DECLARE @AllErrors NVARCHAR(4000); 83 | DECLARE @params NVARCHAR(MAX); 84 | -- SQL Prompt formatting off 85 | SELECT @params='''[''+' 86 | +String_Agg( 87 | CASE 88 | --hierarchyid, geometry,and geography types can be coerced. 89 | WHEN system_type_id IN (240) 90 | THEN 'Coalesce(''"''+convert(nvarchar(max),' + QuoteName(name) + ')+''"'',''null'')' 91 | --text and ntext 92 | WHEN system_type_id IN (35,99) 93 | THEN 'Coalesce(''"''+convert(nvarchar(max),' + QuoteName(name) + ')+''"'',''null'')' 94 | --image varbinary 95 | WHEN system_type_id IN (34,165) 96 | THEN 'Coalesce(''"''+convert(nvarchar(max),' + QuoteName(name) + ',2)+''"'',''null'')' 97 | --dates 98 | --WHEN r.system_type_id IN (165) THEN 'Coalesce(''"''+convert(varbinary(max),' + QuoteName(name) + ')+''"'',''null'')' 99 | WHEN r.system_type_id IN (40,41,42,43,58,61) 100 | THEN 'Coalesce(''"''+convert(nvarchar(max),'+QuoteName(name)+',126)+''"'',''null'')' 101 | --numbers 102 | WHEN r.system_type_id IN (48,52,56,59,60,62,106,108,122,127) 103 | THEN 'Coalesce(convert(nvarchar(max),'+QuoteName(name)+'),''null'')' 104 | --uniqueIdentifier 105 | WHEN system_type_id IN (36) 106 | THEN 'Coalesce(''"''+convert(nvarchar(max),' + QuoteName(name) + ')+''"'',''null'')' 107 | --bit 108 | WHEN system_type_id =104 109 | THEN 'Coalesce(case when '+QuoteName(name)+ '>0 then ''true'' else ''false'' end,''null'') ' 110 | --xml 111 | WHEN system_type_id = 241 112 | THEN 'Coalesce(''"''+String_Escape(convert(nvarchar(max),'+QuoteName(name)+'),''json'')+''"'',''null'')' 113 | ELSE 'Coalesce(''"''+String_Escape('+QuoteName(name)+',''json'') + ''"'',''null'')' END,'+'', ''+' 114 | ) +'+'']''', 115 | @list=String_Agg(QuoteName(name),', '), 116 | @allErrors=String_Agg([error_message],', ') 117 | FROM sys.dm_exec_describe_first_result_set(@SourceCode, NULL, 1)r WHERE Coalesce(is_hidden,0)=0 118 | 119 | -- SQL Prompt formatting on 120 | DECLARE @expression NVARCHAR(4000); 121 | IF @params IS NULL 122 | BEGIN 123 | RAISERROR( 'Source Code %s couldn''t be executed because %s',16,1,@SourceCode, @AllErrors); 124 | END; 125 | IF @Query IS NULL 126 | BEGIN 127 | SELECT @expression = 128 | N' 129 | USE ' + @database + N' 130 | Select @TheData= ''[''+String_Agg(' + @params + N','','')+'']'' 131 | FROM ' + QuoteName(@database) + N'.' + QuoteName(@Schema) + N'.' 132 | + QuoteName(@table) + N';'; 133 | END; 134 | ELSE 135 | BEGIN --take out any trailing semicolon 136 | SELECT @Query = 137 | CASE WHEN Lastsemi < LastText 138 | THEN Left(query, Len(query + ';' COLLATE SQL_Latin1_General_CP1_CI_AI) - Lastsemi - 1) 139 | ELSE query END 140 | FROM 141 | ( 142 | SELECT query, 143 | PatIndex 144 | ( 145 | SemicolonWildcard, 146 | Reverse(';' + query COLLATE SQL_Latin1_General_CP1_CI_AI) 147 | COLLATE SQL_Latin1_General_CP1_CI_AI 148 | ) AS Lastsemi, 149 | PatIndex( 150 | sqltextWildcard, 151 | Reverse(query) COLLATE SQL_Latin1_General_CP1_CI_AI) AS LastText 152 | FROM 153 | ( 154 | SELECT @Query AS query, '%;%' AS SemicolonWildcard, 155 | '%[A-Z1-0_-]%' AS sqltextWildcard 156 | ) AS f 157 | ) AS g; 158 | SELECT @expression = 159 | N'USE ' + @database + N'; 160 | Select @TheData= ''[''+String_Agg(' + @params + N','','')+'']'' 161 | FROM (' + @Query + N')f(' + @list + N')'; 162 | END; 163 | EXECUTE sp_executesql @expression, N'@TheData nvarchar(max) output', 164 | @TheData = @jsonData OUTPUT; 165 | IF IsJson(@jsonData) = 0 RAISERROR( 166 | '{"Table %s did not produce valid JSON"}', 16, 1, @table 167 | ); 168 | END; 169 | GO 170 | 171 | CREATE OR ALTER PROCEDURE #SaveExtendedJsonDataFromTable 172 | /** 173 | Summary: > 174 | This gets the Extended JSON data from a table. You can specify 175 | it either by the database.schema.table 'tablespec, or do it 176 | individually. 177 | Author: phil factor 178 | Date: 04/02/2019 179 | 180 | Examples: > 181 | USE pubs 182 | DECLARE @Json NVARCHAR(MAX) 183 | EXECUTE #SaveExtendedJsonDataFromTable 184 | @database='pubs', 185 | @Schema ='dbo', 186 | @table= 'jobs', 187 | @JSONData=@json OUTPUT 188 | PRINT @Json 189 | Returns: > 190 | The JSON data 191 | **/ 192 | (@database sysname = NULL, @Schema sysname = NULL, @table sysname = NULL, 193 | @tableSpec sysname, @jsonData NVARCHAR(MAX) OUTPUT 194 | ) 195 | AS 196 | BEGIN 197 | DECLARE @Data NVARCHAR(MAX); 198 | IF Coalesce(@table, @Tablespec) IS NULL 199 | OR Coalesce(@Schema, @Tablespec) IS NULL 200 | RAISERROR('{"error":"must have the table details"}', 16, 1); 201 | 202 | IF @table IS NULL SELECT @table = ParseName(@Tablespec, 1); 203 | IF @Schema IS NULL SELECT @Schema = ParseName(@Tablespec, 2); 204 | IF @database IS NULL 205 | SELECT @database = Coalesce(ParseName(@Tablespec, 3), Db_Name()); 206 | IF @table IS NULL OR @Schema IS NULL OR @database IS NULL 207 | RAISERROR('{"error":"must have the table details"}', 16, 1); 208 | 209 | DECLARE @SourceCode NVARCHAR(255) = 210 | ( 211 | SELECT 'SELECT * FROM ' + QuoteName(@database) + '.' 212 | + QuoteName(@Schema) + '.' + QuoteName(@table) 213 | ); 214 | 215 | DECLARE @a_unique_key bit 216 | DECLARE @HowManyUniqueKeys INT 217 | SELECT @HowManyUniqueKeys= Sum(Convert(INT,is_part_of_unique_key)) 218 | FROM sys.dm_exec_describe_first_result_set(@SourceCode, NULL, 1) 219 | SELECT @a_unique_key= CASE WHEN @HowManyUniqueKeys = 1 THEN 1 ELSE 0 END 220 | 221 | DECLARE @params NVARCHAR(MAX); 222 | SELECT @params = 223 | String_Agg( 224 | CASE WHEN system_type_id IN 225 | ( 35, -- text 226 | 99, -- ntext 227 | 98, -- sql_variant 228 | 167, -- varchar 229 | 231, -- nvarchar 230 | 239, -- nchar 231 | 175, -- char 232 | 36, -- uniqueidentifier 233 | 59, -- real 234 | 62, -- float 235 | 104, -- bit 236 | 241 237 | ) -- xml 238 | THEN 239 | CASE WHEN @a_unique_key=1 AND is_part_of_unique_key =1 THEN name+ ' as "_id", ' 240 | ELSE '' END +QuoteName(name) 241 | WHEN user_type_id IN (128, 129, 130) THEN 242 | 'convert(nvarchar(100),' + name + ') as "' + name + '"' 243 | --hierarchyid (128) geometry (130) and geography types (129) can be coerced. 244 | --------binary 245 | WHEN system_type_id IN 246 | ( 165, -- varbinary 247 | 173-- binary 248 | ) 249 | --THEN name + ' as "' + name + '.$binary.hex", ''80'' as "' + name + '.$binary.subType"' 250 | THEN name --I gave up. Extended json binary form is just awful 251 | WHEN system_type_id = 34 THEN --image 252 | 'convert(varbinary(max),' + name + ') as "' + name + '"' 253 | WHEN system_type_id IN (35) THEN --35 is text 254 | 'convert(varchar(max),' + name + ') as "' + name + '"' 255 | WHEN system_type_id IN (99) THEN --ntext 256 | 'convert(nvarchar(max),' + name + ') as "' + name + '"' 257 | --------numberInt 258 | WHEN system_type_id IN 259 | ( 48, -- tinyint 260 | 56, -- int 261 | 52 -- smallint 262 | ) 263 | THEN 264 | CASE WHEN @a_unique_key=1 AND is_part_of_unique_key =1 THEN name+ ' as "_id", ' 265 | ELSE '' END + 266 | 'convert(varchar(50),' + name + ') as "' + name + '.$numberInt"' 267 | --------numberLong 268 | WHEN system_type_id = 127 -- bigint 269 | THEN 270 | CASE WHEN @a_unique_key=1 AND is_part_of_unique_key =1 THEN name+ ' as "_id", ' 271 | ELSE '' END + 272 | 'convert(varchar(50),' + name + ') as "' + name + '.$numberLong"' 273 | --------date 274 | WHEN system_type_id IN 275 | ( 40, -- date 276 | 41, -- time 277 | 42, -- datetime2 278 | 43, -- datetimeoffset 279 | 58, -- smalldatetime 280 | 61, -- datetime 281 | 189 282 | ) -- timestamp 283 | THEN 284 | 'convert(datetimeoffset,convert(datetime2(0),' + name + ')) as "' + name + '.$date"' 285 | -------numberDecimal 286 | WHEN system_type_id IN 287 | ( 106, -- decimal 288 | 108, -- numeric 289 | 122, -- smallmoney 290 | 60 291 | ) -- money 292 | THEN 293 | 'convert(varchar(50),' + name + ') as "' + name + '.$numberDecimal"' 294 | ELSE QuoteName(name) 295 | END, 296 | ', ' 297 | ) 298 | FROM sys.dm_exec_describe_first_result_set(@SourceCode, NULL, 1); 299 | DECLARE @expression NVARCHAR(max) = 300 | ' 301 | USE ' + @database + ' 302 | SELECT @TheData=(SELECT ' + @params + ' FROM ' + QuoteName(@database) + '.' 303 | + QuoteName(@Schema) + '.' + QuoteName(@table) 304 | + ' FOR JSON PATH)'; 305 | PRINT @Expression 306 | EXECUTE sp_executesql @expression, N'@TheData nvarchar(max) output', 307 | @TheData = @jsonData OUTPUT; 308 | END; 309 | GO 310 | 311 | CREATE OR ALTER PROCEDURE #SaveJsonDataFromTable 312 | /** 313 | Summary: > 314 | This gets the JSON data from a table 315 | Author: phil factor 316 | Date: 26/10/2018 317 | 318 | Examples: > 319 | USE bigpubs 320 | DECLARE @Json NVARCHAR(MAX) 321 | EXECUTE #SaveJsonDataFromTable 322 | @database='pubs', 323 | @Schema ='dbo', 324 | @table= 'authors', 325 | @JSONData=@json OUTPUT 326 | PRINT @Json 327 | Returns: > 328 | The JSON data 329 | **/ 330 | (@database sysname = NULL, @Schema sysname = NULL, @table sysname = NULL, 331 | @Tablespec sysname = NULL, @jsonData NVARCHAR(MAX) OUTPUT 332 | ) 333 | AS 334 | BEGIN 335 | DECLARE @Data NVARCHAR(MAX); 336 | IF Coalesce(@table, @Tablespec) IS NULL 337 | OR Coalesce(@Schema, @Tablespec) IS NULL 338 | RAISERROR('{"error":"must have the table details"}', 16, 1); 339 | 340 | IF @table IS NULL SELECT @table = ParseName(@Tablespec, 1); 341 | IF @Schema IS NULL SELECT @Schema = ParseName(@Tablespec, 2); 342 | IF @database IS NULL SELECT @database = Coalesce(ParseName(@Tablespec, 3),Db_Name()); 343 | IF @table IS NULL OR @Schema IS NULL OR @database IS NULL 344 | RAISERROR('{"error":"must have the table details"}', 16, 1); 345 | 346 | DECLARE @SourceCode NVARCHAR(255) = 347 | ( 348 | SELECT 'SELECT * FROM ' + QuoteName(@database) + '.' 349 | + QuoteName(@Schema) + '.' + QuoteName(@table) 350 | ); 351 | 352 | 353 | DECLARE @params NVARCHAR(MAX) = 354 | ( 355 | SELECT 356 | String_Agg( 357 | CASE WHEN user_type_id IN (128, 129, 130) THEN 358 | 'convert(nvarchar(100),' + name 359 | + ') as "' + name + '"' 360 | --hierarchyid (128) geometry (130) and geography types (129) can be coerced. 361 | WHEN user_type_id IN (35) THEN 362 | 'convert(varchar(max),' + name + ') as "' 363 | + name + '"' 364 | WHEN user_type_id IN (99) THEN 365 | 'convert(nvarchar(max),' + name + ') as "' 366 | + name + '"' 367 | WHEN user_type_id IN (34) THEN 368 | 'convert(varbinary(max),' + name 369 | + ') as "' + name + '"' ELSE 370 | QuoteName(name) END, ', ' ) 371 | FROM sys.dm_exec_describe_first_result_set(@SourceCode, NULL, 1) 372 | ); 373 | DECLARE @expression NVARCHAR(800) = 374 | ' 375 | USE ' + @database + ' 376 | SELECT @TheData=(SELECT ' + @params + ' FROM ' + QuoteName(@database) + '.' 377 | + QuoteName(@Schema) + '.' + QuoteName(@table) 378 | + ' FOR JSON auto, INCLUDE_NULL_VALUES)'; 379 | EXECUTE sp_executesql @expression, N'@TheData nvarchar(max) output', 380 | @TheData = @jsonData OUTPUT; 381 | END; 382 | GO 383 | 384 | 385 | /* lets just check the config and make sure that xp_cmdshell is enabled. */ 386 | DECLARE @Settings TABLE ( 387 | name sysname, minimum INT, Maximum INT, config_value INT, run_value INT); 388 | INSERT INTO @Settings (name, minimum, Maximum, config_value, run_value) 389 | EXECUTE sp_configure @configname = 'show advanced options'; 390 | IF NOT EXISTS ( 391 | SELECT * FROM @Settings WHERE name = 'show advanced options' 392 | AND run_value = 1) 393 | BEGIN 394 | EXECUTE sp_configure 'show advanced options', 1; 395 | RECONFIGURE; 396 | END; 397 | INSERT INTO @Settings (name, minimum, Maximum, config_value, run_value) 398 | EXECUTE sp_configure @configname = 'xp_cmdshell'; 399 | IF NOT EXISTS ( 400 | SELECT * FROM @Settings WHERE name = 'xp_cmdshell' 401 | AND run_value = 1) 402 | BEGIN 403 | EXECUTE sp_configure 'xp_cmdshell', 1; 404 | RECONFIGURE; 405 | END; 406 | go 407 | /* start of timed run */ 408 | DECLARE @log TABLE 409 | (TheOrder INT IDENTITY(1,1), 410 | WhatHappened varchar(200), 411 | WHENItDid Datetime2 DEFAULT GETDATE()) 412 | USE adventureworks2016 413 | ----start of timing 414 | INSERT INTO @log(WhatHappened) SELECT 'Starting Writing out every table' 415 | --place at the start 416 | DECLARE @ourPath9 sysname = 'C:\Data\RawData\AdventureWorks\XML\'; 417 | Declare @command9 NVARCHAR(4000)= 418 | 'EXEC xp_cmdshell ''bcp "SELECT * FROM ? FOR XML AUTO" queryout "' 419 | +@ourPath9+'?.xml" -S '+@@Servername+' -T -c -C 65001 -t'', NO_OUTPUT;' 420 | EXECUTE sp_msforeachtable @command9 421 | INSERT INTO @log(WhatHappened) 422 | SELECT 'Writing out every table as XML took ' 423 | --log the time taken to get to this point 424 | /* first lets try using JSON array--in-array format */ 425 | DECLARE @ourPath1 sysname = 'C:\Data\RawData\AdventureWorks\JSONArrayInArray\'; 426 | Declare @command1 NVARCHAR(4000)= ' 427 | DECLARE @Json NVARCHAR(MAX) 428 | EXECUTE #ArrayInArrayJsonDataFromTable @TableSpec=''?'',@JSONData=@json OUTPUT 429 | CREATE TABLE ##myTemp (Bulkcol nvarchar(MAX)) 430 | INSERT INTO ##myTemp (Bulkcol) SELECT @JSON 431 | EXECUTE xp_cmdshell ''bcp ##myTemp out "'+@ourPath1 432 | +'?.JSON" -c -C 65001 -S '+@@Servername+' -T '', NO_OUTPUT; 433 | DROP TABLE ##myTemp' 434 | EXECUTE sp_msforeachtable @command1 435 | INSERT INTO @log(WhatHappened) 436 | SELECT 'Writing out every table as Array-in-Array JSON took ' 437 | --log the time taken to get to this point 438 | DECLARE @ourPath2 sysname = 'C:\Data\RawData\AdventureWorks\JSONObjectInArray\'; 439 | DECLARE @command2 NVARCHAR(4000)= ' 440 | DECLARE @Json NVARCHAR(MAX) 441 | EXECUTE #SaveJsonDataFromTable @TableSpec=''?'',@JSONData=@json OUTPUT 442 | CREATE TABLE ##myTemp (Bulkcol nvarchar(MAX)) 443 | INSERT INTO ##myTemp (Bulkcol) SELECT @JSON 444 | EXECUTE xp_cmdshell ''bcp ##myTemp out '+@ourPath2 445 | +'?.JSON -c -C 65001 -S '+@@Servername+' -T '', NO_OUTPUT; 446 | DROP TABLE ##myTemp' 447 | EXECUTE sp_msforeachtable @command2 448 | INSERT INTO @log(WhatHappened) 449 | SELECT 'Writing out every table as Object-in-Array JSON took ' 450 | --log the time taken to get to this point 451 | DECLARE @ourPath3 sysname = 'C:\Data\RawData\AdventureWorks\TabDelimited\'; 452 | DECLARE @Database3 sysname = Db_Name(); --over-ride this if you need to. 453 | DECLARE @command3 NVARCHAR(4000)= ' 454 | EXECUTE xp_cmdshell ''bcp ? out '+@ourPath3+'?.Tab -c -C 65001 -d' 455 | +@Database3+' -S '+@@Servername+' -T '', NO_OUTPUT;' 456 | EXECUTE sp_msforeachtable @command3 457 | INSERT INTO @log(WhatHappened) 458 | SELECT 'Writing out every table as tab-delimited BCP took ' 459 | --log the time taken to get to this point 460 | DECLARE @ourPath4 sysname = 'C:\Data\RawData\AdventureWorks\NativeBCP\'; 461 | DECLARE @Database4 sysname = Db_Name(); --over-ride this if you need to. 462 | DECLARE @command4 NVARCHAR(4000)= ' 463 | EXECUTE xp_cmdshell ''bcp ? out '+@ourPath4+'?.data -N -d' 464 | +@Database4+' -S '+@@Servername+' -T '', NO_OUTPUT;' 465 | EXECUTE sp_msforeachtable @command4 466 | INSERT INTO @log(WhatHappened) 467 | SELECT 'Writing out every table as native BCP took ' 468 | --log the time taken to get to this point 469 | DECLARE @ourPath6 sysname = 'C:\Data\RawData\AdventureWorks\CSV\'; 470 | DECLARE @Database6 sysname = Db_Name(); --over-ride this if you need to. 471 | DECLARE @command6 NVARCHAR(4000)= ' 472 | EXECUTE xp_cmdshell ''sqlcmd -d ' 473 | +@Database6+' -u -E -h -1 -s, -W -Q "set nocount on; SELECT * FROM ?" -S ' 474 | +@@Servername+' -o '+@ourPath6++'?.CSV'', NO_OUTPUT;' 475 | EXECUTE sp_msforeachtable @command6 476 | INSERT INTO @log(WhatHappened) 477 | SELECT 'Writing out every table as SQLCMD comedy-limited took ' 478 | --log the time taken to get to this point 479 | DECLARE @ourPath7 sysname = 'C:\Data\RawData\AdventureWorks\ExtendedJSON\'; 480 | Declare @command7 NVARCHAR(4000)= ' 481 | DECLARE @Json NVARCHAR(MAX) 482 | EXECUTE #SaveExtendedJsonDataFromTable @TableSpec=''?'',@JSONData=@json OUTPUT 483 | CREATE TABLE ##myTemp (Bulkcol nvarchar(MAX)) 484 | INSERT INTO ##myTemp (Bulkcol) SELECT @JSON 485 | EXECUTE xp_cmdshell ''bcp ##myTemp out "'+@ourPath7 486 | +'?.JSON" -c -C 65001 -S '+@@Servername+' -T '', NO_OUTPUT; 487 | DROP TABLE ##myTemp' 488 | EXECUTE sp_msforeachtable @command7 489 | INSERT INTO @log(WhatHappened) 490 | SELECT 'Writing out every table as Extended JSON took ' 491 | 492 | --log the time taken to get to this point 493 | SELECT ending.whathappened, 494 | DateDiff(ms, starting.whenItDid,ending.WhenItDid) AS ms 495 | FROM @log starting 496 | INNER JOIN @log ending ON ending.theorder=starting.TheOrder+1 497 | UNION all 498 | SELECT 'Total', DateDiff(ms,Min(WhenItDid),Max(WhenItDid)) 499 | FROM @log 500 | ORDER BY ms asc 501 | --list out all the timings 502 | go 503 | DECLARE @Settings TABLE 504 | (name sysname, minimum INT, Maximum INT, config_value INT, run_value INT); 505 | INSERT INTO @Settings (name, minimum, Maximum, config_value, run_value) 506 | EXECUTE sp_configure @configname = 'show advanced options'; 507 | IF NOT EXISTS ( 508 | SELECT * FROM @Settings WHERE name = 'show advanced options' 509 | AND run_value = 1) 510 | BEGIN 511 | EXECUTE sp_configure 'show advanced options', 1; 512 | RECONFIGURE; 513 | END; 514 | INSERT INTO @Settings (name, minimum, Maximum, config_value, run_value) 515 | EXECUTE sp_configure @configname = 'xp_cmdshell'; 516 | IF NOT EXISTS ( 517 | SELECT * FROM @Settings WHERE name = 'xp_cmdshell' 518 | AND run_value = 0) 519 | BEGIN 520 | EXECUTE sp_configure 'xp_cmdshell', 0; 521 | RECONFIGURE; 522 | END; -------------------------------------------------------------------------------- /CreateJSONArrayInArraySchemaFromTable.sql: -------------------------------------------------------------------------------- 1 | CREATE OR ALTER PROCEDURE #CreateJSONArrayInArraySchemaFromTable 2 | /** 3 | Summary: > 4 | This creates a JSON schema from a table that 5 | matches the JSON you will get from doing a 6 | classic FOR JSON select * statemenmt on the entire table 7 | 8 | Author: phil factor 9 | Date: 4/12/2018 10 | 11 | Examples: > 12 | DECLARE @Json NVARCHAR(MAX) 13 | EXECUTE #CreateJSONArrayInArraySchemaFromTable @database='pubs', @Schema ='dbo', @table= 'authors',@JSONSchema=@json OUTPUT 14 | PRINT @Json 15 | SELECT @json='' 16 | EXECUTE #CreateJSONArrayInArraySchemaFromTable @TableSpec='pubs.dbo.authors',@JSONSchema=@json OUTPUT 17 | PRINT @Json 18 | Returns: > 19 | nothing 20 | **/ 21 | (@database sysname=null, @Schema sysname=NULL, @table sysname=null, @Tablespec sysname=NULL,@jsonSchema NVARCHAR(MAX) output) 22 | 23 | --WITH ENCRYPTION|SCHEMABINDING, ... 24 | AS 25 | 26 | DECLARE @required NVARCHAR(max), @NoColumns INT, @properties NVARCHAR(max); 27 | 28 | IF Coalesce(@table,@Tablespec) IS NULL 29 | OR Coalesce(@schema,@Tablespec) IS NULL 30 | RAISERROR ('{"error":"must have the table details"}',16,1) 31 | 32 | IF @table is NULL SELECT @table=ParseName(@Tablespec,1) 33 | IF @Schema is NULL SELECT @schema=ParseName(@Tablespec,2) 34 | IF @Database is NULL SELECT @Database=Coalesce(ParseName(@Tablespec,3),Db_Name()) 35 | IF @table IS NULL OR @schema IS NULL OR @database IS NULL 36 | RAISERROR ('{"error":"must have the table details"}',16,1) 37 | 38 | DECLARE @SourceCode NVARCHAR(255)= 39 | 'SELECT * FROM '+QuoteName(@database)+ '.'+ QuoteName(@Schema)+'.'+QuoteName(@table) 40 | 41 | SELECT @jsonschema= 42 | (SELECT 43 | 'https://mml.uk/jsonSchema/'+@table+'.json' AS id,--just a unique reference to a real place 44 | 'http://json-schema.org/draft-04/schema#' AS [schema],--the minimum standard you want to use 45 | 'Array (rows) within an array (table) of'+@Schema+'.'+@table AS description, 46 | 'array' AS type, 'array' AS [items.type], 47 | ( 48 | SELECT 49 | f.name, --the individual columns as an array of objects with standard and custom fields 50 | CASE WHEN f.is_nullable = 1 THEN Json_Query('["null","'+f.type+'"]') -- must be array! 51 | ELSE Json_Query('["'+f.type+'"]') END AS [type],--must be an array! 52 | f.SQLtype, f.is_nullable, Coalesce(EP.value,'') AS description 53 | FROM 54 | (--the basic columns we need. (the type is used more than once in the outer query) 55 | SELECT r.name, r.system_type_name AS sqltype, r.source_column, r.is_nullable, 56 | CASE WHEN r.system_type_id IN (58,52,56,58,59,60,62,106,108,122,127) THEN 'number' 57 | WHEN system_type_id =104 THEN 'boolean' ELSE 'string' END AS type, 58 | Object_Id(r.source_database + '.' + r.source_schema + '.' + r.source_table) 59 | AS table_id 60 | FROM sys.dm_exec_describe_first_result_set 61 | (@SourceCode, NULL, 1) AS r 62 | ) AS f 63 | LEFT OUTER JOIN sys.extended_properties AS EP -- to get the extended properties 64 | ON EP.major_id = f.table_id 65 | AND EP.minor_id = ColumnProperty(f.table_id, f.source_column, 'ColumnId') 66 | AND EP.name = 'MS_Description' 67 | AND EP.class = 1 68 | FOR JSON PATH 69 | ) AS [items.items] 70 | FOR JSON PATH, WITHOUT_ARRAY_WRAPPER); 71 | IF(IsJson(@jsonschema)=0) 72 | RAISERROR ('invalid schema "%s"',16,1,@jsonSchema) 73 | IF @jsonschema IS NULL RAISERROR ('Null schema',16,1) 74 | GO 75 | 76 | /* 77 | USE Adventureworks2016 78 | DECLARE @ourPath sysname = 'C:\data\RawData\JsonSchema\AdventureWorks\'; 79 | Declare @command NVARCHAR(4000)= ' 80 | print ''Creating JSON file for ?'' 81 | DECLARE @Json NVARCHAR(MAX) 82 | EXECUTE #CreateJSONArrayInArraySchemaFromTable @TableSpec=''?'',@JSONSchema=@json OUTPUT 83 | CREATE TABLE ##myTemp (Bulkcol nvarchar(MAX)) 84 | INSERT INTO ##myTemp (Bulkcol) SELECT @JSON 85 | print ''Writing out ?'' 86 | EXECUTE xp_cmdshell ''bcp ##myTemp out '+@ourPath+'?.JSON -c -C 65001 -T'' 87 | DROP TABLE ##myTemp' 88 | EXECUTE sp_msforeachtable @command 89 | */ 90 | GO 91 | 92 | 93 | 94 | 95 | 96 | 97 | 98 | 99 | 100 | 101 | 102 | 103 | 104 | 105 | -------------------------------------------------------------------------------- /CreateJSONSchemaFromTable.sql: -------------------------------------------------------------------------------- 1 | CREATE OR ALTER PROCEDURE #CreateJSONSchemaFromTable 2 | /** 3 | Summary: > 4 | This creates a JSON schema from a table that 5 | matches the JSON you will get from doing a 6 | classic FOR JSON select * statemenmt on the entire table 7 | 8 | Author: phil factor 9 | Date: 26/10/2018 10 | 11 | Examples: > 12 | DECLARE @Json NVARCHAR(MAX) 13 | EXECUTE #CreateJSONSchemaFromTable @database='pubs', @Schema ='dbo', @table= 'authors',@JSONSchema=@json OUTPUT 14 | PRINT @Json 15 | SELECT @json='' 16 | EXECUTE #CreateJSONSchemaFromTable @TableSpec='pubs.dbo.authors',@JSONSchema=@json OUTPUT 17 | PRINT @Json 18 | Returns: > 19 | nothing 20 | **/ 21 | (@database sysname=null, @Schema sysname=NULL, @table sysname=null, @Tablespec sysname=NULL,@jsonSchema NVARCHAR(MAX) output) 22 | 23 | --WITH ENCRYPTION|SCHEMABINDING, ... 24 | AS 25 | 26 | DECLARE @required NVARCHAR(max), @NoColumns INT, @properties NVARCHAR(max); 27 | 28 | IF Coalesce(@table,@Tablespec) IS NULL 29 | OR Coalesce(@schema,@Tablespec) IS NULL 30 | RAISERROR ('{"error":"must have the table details"}',16,1) 31 | 32 | IF @table is NULL SELECT @table=ParseName(@Tablespec,1) 33 | IF @Schema is NULL SELECT @schema=ParseName(@Tablespec,2) 34 | IF @Database is NULL SELECT @Database=Coalesce(ParseName(@Tablespec,3),Db_Name()) 35 | IF @table IS NULL OR @schema IS NULL OR @database IS NULL 36 | RAISERROR ('{"error":"must have the table details"}',16,1) 37 | 38 | DECLARE @SourceCode NVARCHAR(255)= 39 | (SELECT 'SELECT * FROM '+QuoteName(@database)+ '.'+ QuoteName(@Schema)+'.'+QuoteName(@table)) 40 | SELECT 41 | @properties= String_Agg(' 42 | "'+f.name+'": {"type":["'+Replace(type,' ','","')+'"],"sqltype":"'+sqltype+'", "columnNo":'+ Convert(VARCHAR(3), f.column_ordinal) 43 | +', "nullable":'+Convert(CHAR(1),f.is_nullable)+', "Description":"' 44 | +String_Escape(Coalesce(Convert(NvARCHAR(875),EP.value),''),'json')+'"}',','), 45 | @NoColumns=Max(f.column_ordinal), 46 | @required=String_Agg('"'+f.Name+'"',',') 47 | FROM 48 | ( --the basic columns we need. (the type is used more than once in the outer query) 49 | SELECT 50 | r.name, 51 | r.system_type_name AS sqltype, 52 | r.source_column, 53 | r.is_nullable,r.column_ordinal, 54 | CASE WHEN r.system_type_id IN (48, 52, 56, 58, 59, 60, 62, 106, 108, 122, 127) 55 | THEN 'number' 56 | WHEN system_type_id = 104 THEN 'boolean' ELSE 'string' END 57 | + CASE WHEN r.is_nullable = 1 THEN ' null' ELSE '' END AS type, 58 | Object_Id(r.source_database + '.' + r.source_schema + '.' + r.source_table) AS table_id 59 | FROM sys.dm_exec_describe_first_result_set 60 | (@sourcecode, NULL, 1) AS r 61 | ) AS f 62 | LEFT OUTER JOIN sys.extended_properties AS EP -- to get the extended properties 63 | ON EP.major_id = f.table_id 64 | AND EP.minor_id = ColumnProperty(f.table_id, f.source_column, 'ColumnId') 65 | AND EP.name = 'MS_Description' 66 | AND EP.class = 1 67 | 68 | SELECT @JSONschema = 69 | Replace( 70 | Replace( 71 | Replace( 72 | Replace( 73 | Replace('{ 74 | "$id": "https://mml.uk/jsonSchema/<-schema->-<-table->.json", 75 | "$schema": "http://json-schema.org/draft-07/schema#", 76 | "title": "<-table->", 77 | "SQLtablename":"'+quotename(@schema)+'.'+quotename(@table)+'", 78 | "SQLschema":"<-schema->", 79 | "type": "array", 80 | "items": { 81 | "type": "object", 82 | "required": [<-Required->], 83 | "maxProperties": <-MaxColumns->, 84 | "minProperties": <-MinColumns->, 85 | "properties":{'+@properties+'} 86 | } 87 | }', '<-minColumns->', Convert(VARCHAR(5),@NoColumns) COLLATE DATABASE_DEFAULT 88 | ) , '<-maxColumns->',Convert(VARCHAR(5),@NoColumns +1) COLLATE DATABASE_DEFAULT 89 | ) , '<-Required->',@required COLLATE DATABASE_DEFAULT 90 | ) ,'<-schema->',@Schema COLLATE DATABASE_DEFAULT 91 | ) ,'<-table->', @table COLLATE DATABASE_DEFAULT 92 | ); 93 | 94 | 95 | IF(IsJson(@jsonschema)=0) 96 | RAISERROR ('invalid schema "%s"',16,1,@jsonSchema) 97 | IF @jsonschema IS NULL RAISERROR ('Null schema',16,1) 98 | GO 99 | 100 | 101 | 102 | 103 | 104 | 105 | 106 | 107 | 108 | 109 | 110 | 111 | 112 | 113 | 114 | -------------------------------------------------------------------------------- /ExampleofCreateJSONSchemaFromTable.sql: -------------------------------------------------------------------------------- 1 | 2 | 3 | DECLARE @TheJSONSchema NVARCHAR(MAX); 4 | EXECUTE #CreateJSONSchemaFromTable @Tablespec = 'adventureworks2016.HumanResources.Employee', 5 | @jsonSchema = @TheJSONSchema OUTPUT; 6 | DECLARE @TheJSONdata NVARCHAR(MAX) = 7 | ( 8 | SELECT * 9 | FROM AdventureWorks2016.HumanResources.Employee 10 | FOR JSON AUTO, INCLUDE_NULL_VALUES 11 | ); 12 | DECLARE @TheJSON NVARCHAR(MAX) = 13 | ( 14 | SELECT * 15 | FROM (VALUES (Json_Query(@TheJSONSchema), Json_Query(@TheJSONdata))) AS f ( 16 | [schema], data 17 | ) 18 | FOR JSON AUTO, WITHOUT_ARRAY_WRAPPER 19 | ); 20 | EXECUTE #SaveJSONToFile @TheJSON, 21 | 'C:\data\RawData\HumanResources-Employee.json', 8; -------------------------------------------------------------------------------- /GenerateSQLMergeScripts.ps1: -------------------------------------------------------------------------------- 1 | import-Module sqlserver 2 | <# a list of connection strings 3 | for each of the target databaseinstances on which you'd like to run the code 4 | #> 5 | $ServerAndDatabaseList = 6 | @( 7 | <# list of connection strings for each of the SQLservers that you need to execute code on #> 8 | @{ #provide a connection string for the instance 9 | 'ServerConnectionString' = 'Server=MyServer;User Id=PhilFactor;Persist Security Info=False'; 10 | #and a list of databases. Make target the same as source if the database you use it on has the same name 11 | 'Databases' = @(@{'Source'='NorthWind';'Target'='WestWind'}) # do all 12 | } 13 | ) 14 | $FileNameEnd = 'DataMerge'#'AllObjects' #the unique part of the file you save the single string result in 15 | # the file and path in which is your SQL Code 16 | $SQLPerServerFileName = 'MyGithubDirectoryPath\JSONSQLServerRoutines\SaveMergeStatementFromTable.sql' 17 | $FinalBatch="EXEC sp_msforeachtable 'ALTER TABLE ? WITH CHECK CHECK CONSTRAINT all'" 18 | $RootDirectoryForOutputFile = "$env:USERPROFILE\JSONDocumentation" #the directory you want it in 19 | $minimumCompatibilityLevel=130 #specify the minimum database compatibility level 20 | $fileType='SQL' #the filetype of the file you save for each database. 21 | $slash='+' #the string that you want to replace for the 'slash' in an instance name for files etc 22 | # end of data area 23 | 24 | $SQLPerServerContent = [IO.File]::ReadAllText($SQLPerServerFileName) #read the file into a variable in one gulp 25 | if ($SQLPerTableFileName -ne $null) 26 | {$SQLPerTableContent = [IO.File]::ReadAllText($SQLPerTableFileName)} 27 | #read the file into a variable in one gulp} 28 | else 29 | {$SQLPerTableContent=$SQLEachTable;} 30 | # now create the directory (folder) for the output files if it doesn't exist 31 | if (!(Test-Path -path $RootDirectoryForOutputFile -PathType Container)) 32 | { $null = New-Item -ItemType directory -Path $RootDirectoryForOutputFile } 33 | #Now for each instance and associated list of databases 34 | $ServerAndDatabaseList | foreach { 35 | #for each instance/sever 36 | $csb = New-Object System.Data.Common.DbConnectionStringBuilder 37 | $csb.set_ConnectionString($_.ServerConnectionString) 38 | # create an SMO connection get credentials if necessary 39 | if ($csb.'user id' -ne '') #then it is using SQL Server Credentials 40 | { <# Oh dear, we need to get the password, if we don't already know it #> 41 | $SqlEncryptedPasswordFile = ` 42 | "$env:USERPROFILE\$($csb.'user id')-$($csb.server.Replace('\', $slash)).xml" 43 | # test to see if we know about the password in a secure string stored in the user area 44 | if (Test-Path -path $SqlEncryptedPasswordFile -PathType leaf) 45 | { 46 | #has already got this set for this login so fetch it 47 | $SqlCredentials = Import-CliXml $SqlEncryptedPasswordFile 48 | 49 | } 50 | else #then we have to ask the user for it (once only) 51 | { 52 | #hasn't got this set for this login 53 | $SqlCredentials = get-credential -Credential $csb.'user id' 54 | $SqlCredentials | Export-CliXml -Path $SqlEncryptedPasswordFile 55 | } 56 | $ServerConnection = 57 | new-object ` 58 | "Microsoft.SqlServer.Management.Common.ServerConnection"` 59 | ($csb.server, $SqlCredentials.UserName, $SqlCredentials.GetNetworkCredential().password) 60 | $csb.Add('password',$SqlCredentials.GetNetworkCredential().password) 61 | } 62 | else 63 | { 64 | $ServerConnection = 65 | new-object ` 66 | "Microsoft.SqlServer.Management.Common.ServerConnection" ` 67 | ($csb.server) 68 | } 69 | <# all this work just to maintain passwords ! #> 70 | try # now we make an SMO connection to the server, using the connection string 71 | { 72 | $srv = new-object ("Microsoft.SqlServer.Management.Smo.Server") $ServerConnection 73 | } 74 | catch 75 | { 76 | Write-error "Could not connect to SQL Server instance $($csb.server) $($error[0]). Script is aborted" 77 | exit -1 78 | } 79 | $Databasesthere = $srv.Databases.name 80 | $_.Databases | 81 | foreach { 82 | 83 | write-output "now doing $($_.source) on $($csb.server) " 84 | $Db = $_.source 85 | $Destination=$_.Target 86 | $ReturnedStringFromBatch='' 87 | $CompatibilityLevel=$srv.ConnectionContext.ExecuteScalar(" 88 | SELECT top 1 compatibility_level FROM sys.databases WHERE name = '$db'"); 89 | if ($databasesThere -notcontains $db) { 90 | Write-Error "The Server $($csb.Server) does not have a database called $db"} 91 | if ($CompatibilityLevel -lt $minimumCompatibilityLevel) { 92 | Write-Error "The Server database called $db on $($csb.Server) at level $CompatibilityLevel is below the minimum compatibility level $minimumCompatibilityLevel"} 93 | try #to execute the SQL in the file 94 | { 95 | $ds=Invoke-Sqlcmd -QueryTimeout 65535 -connectionstring $csb.ConnectionString -MaxCharLength ([int32]::MaxValue) -OutputSqlErrors $true -OutputAs DataRows -query "use $db 96 | $SQLPerServerContent 97 | DECLARE @TotalScript NVARCHAR(MAX) 98 | DECLARE @DestinationDatabase sysname='$Destination' 99 | DROP TABLE IF exists ##myTemp 100 | CREATE TABLE ##myTemp (Bulkcol nvarchar(MAX), TheRightOrder INT IDENTITY) 101 | DECLARE @DisableConstraints nvarchar(4000)='Print ''Disabling all table constraints''' 102 | SELECT @DisableConstraints=@DisableConstraints+' 103 | ALTER TABLE [$Db].'+Object_Schema_Name(object_id)+'.'+QuoteName(name)+' NOCHECK CONSTRAINT ALL 104 | ' FROM sys.tables 105 | INSERT INTO ##myTemp (BulkCol) SELECT @DisableConstraints 106 | DECLARE @command NVARCHAR(4000)= ' 107 | print ''Creating SQL Merge file for ?'' 108 | DECLARE @CreatedScript NVARCHAR(MAX) 109 | EXECUTE #SaveMergeStatementFromTable @TableSpec=''?'',@DestinationDatabase='''+@DestinationDatabase+''',@Statement=@CreatedScript OUTPUT 110 | INSERT INTO ##myTemp (Bulkcol) SELECT coalesce(@CreatedScript,'''')+'' 111 | '' 112 | ' 113 | EXECUTE sp_msforeachtable @command 114 | Select Bulkcol from ##myTemp order by TheRightOrder 115 | DROP TABLE ##myTemp 116 | " 117 | $ReturnedStringFromBatch += $ds.BulkCol 118 | } 119 | catch 120 | { 121 | Write-error ` 122 | "Could not execute the main code on $($csb.server) $($error[0].Exception). Script is aborted" 123 | exit -1 124 | } } 125 | #make sure that the folder exists for the subdirectory orresponding to the server 126 | if (!(Test-Path -path "$RootDirectoryForOutputFile\$($csb.server.Replace('\', $slash))" -PathType Container)) 127 | { $null = New-Item -ItemType directory -Path "$RootDirectoryForOutputFile\$($csb.server.Replace('\', $slash))" } 128 | #output it to the file 129 | if ($FinalBatch -ne $null) {$ReturnedStringFromBatch += ' 130 | '+ $FinalBatch} 131 | $ReturnedStringFromBatch>"$RootDirectoryForOutputFile\$($csb.server.Replace('\', $slash))\$db$FileNameEnd.$FileType" 132 | 133 | } 134 | -------------------------------------------------------------------------------- /JsonResultToJsonArray.sql: -------------------------------------------------------------------------------- 1 | CREATE OR ALTER FUNCTION JsonResultToJsonArray 2 | (@JSONResult AS NVARCHAR(MAX)) 3 | /** 4 | Summary: > 5 | converts a JSON array-on-array document from a JSON result 6 | produced using FOR JSON AUTO ,INCLUDE_NULL_VALUES 7 | it must include null values! 8 | 9 | Author: Phil Factor 10 | Date: 01/10/2018 11 | Examples: > 12 | DECLARE @JSONResult NVARCHAR(MAX)= 13 | (SELECT * FROM adventureworks2016.person.person 14 | FOR JSON AUTO, INCLUDE_NULL_VALUES) 15 | SELECT dbo.JsonResultToJsonArray(@JSONresult) 16 | Returns: > 17 | JSON Array-on-array document 18 | **/ 19 | RETURNS NVARCHAR(MAX) --JSON Array-on-array document 20 | --WITH ENCRYPTION|SCHEMABINDING, ... 21 | AS 22 | BEGIN 23 | DECLARE @JSON NVARCHAR(MAX)=( 24 | SELECT '['+ String_Agg(f.EachLine,',')+']' 25 | FROM 26 | (SELECT '['+String_Agg ( 27 | CASE WHEN shredded.type=1 28 | THEN '"'+String_Escape(Coalesce(shredded.value,'null'),'json')+'"' 29 | ELSE Coalesce(shredded.value,'null') 30 | END, ',') +']' 31 | AS TheValue 32 | FROM OpenJson(@JSONResult) f 33 | CROSS apply OpenJson(f.value) shredded 34 | GROUP BY f.[Key])f(EachLine) 35 | ) 36 | RETURN @json 37 | END 38 | GO 39 | -------------------------------------------------------------------------------- /OpenJSONExpressions.sql: -------------------------------------------------------------------------------- 1 | CREATE OR alter FUNCTION [dbo].[OpenJSONExpressions] 2 | /** 3 | summary: > 4 | This inline table-valued function talkes a JSON string and 5 | locates every table structure. Then it creates an OpenJSON 6 | Statement that can then be executed to create that table 7 | from the original JSON. 8 | Author: Phil Factor 9 | Revision: 1.0 10 | date: 1 Nov 2020 11 | example: 12 | - SELECT * FROM OpenJSONExpressions (N'[ 13 | {"name":"Phil", "email":"PhilipFactor@gmail.com"}, 14 | {"name":"Bob", "email":"bob32@gmail.com"} 15 | ]') 16 | returns: > 17 | expression 18 | 19 | **/ 20 | ( 21 | @JSON NVARCHAR(MAX) 22 | 23 | ) 24 | RETURNS TABLE AS RETURN 25 | ( 26 | WITH UnwrappedJSON (id, [level], [key], [Value], [type], SQLDatatype, parent, 27 | [path] 28 | ) 29 | AS (SELECT id, [level], [key], [Value], [type], SQLDatatype, parent, [path] 30 | FROM dbo.UnwrapJson(@json) ) 31 | SELECT 'Select * from openjson(@json,''' + path + ''') 32 | WITH (' + String_Agg( 33 | [name] + ' ' + datatype + ' ' --the WITH statement 34 | -- SQL Prompt formatting off 35 | + case when datatype='nvarchar' then '('+length+')' 36 | WHEN datatype='numeric' then '(14,4)' ELSE '' end,', ') 37 | WITHIN GROUP ( ORDER BY TheOrder ASC ) +')' as expression 38 | -- SQL Prompt formatting on 39 | FROM 40 | ( 41 | SELECT Parent.path, GrandChild.[key] AS [name], Min(GrandChild.id) AS TheOrder, 42 | Max(GrandChild.SQLDatatype) AS datatype, 43 | Convert(NVARCHAR(100), Max(Len(GrandChild.Value))) AS length 44 | FROM 45 | (SELECT path, id FROM UnwrappedJSON WHERE type = 4) Parent 46 | INNER JOIN UnwrappedJSON Child 47 | ON Child.parent = Parent.id AND child.type IN (4, 5) 48 | INNER JOIN UnwrappedJSON GrandChild 49 | ON GrandChild.parent = Child.id AND GrandChild.type NOT IN (4, 5) 50 | GROUP BY Parent.path, GrandChild.[key] 51 | ) TheFields 52 | GROUP BY path 53 | ) 54 | GO -------------------------------------------------------------------------------- /ReadMe.md: -------------------------------------------------------------------------------- 1 | # SQL Server and JSON: Data import, export and validation 2 | 3 | This repository contains several stored procedures and PowerShell routines that can be used for inserting JSON data into SQL Server, validate the data or to export the data from SQL Server. They are described in a series of articles on the Red-Gate site and in Simple-Talk. Some use ordinary JSON files and others show how to include the schema and data in one document. I use 4 | them as temporary procedures because these are better for cross-database work, and as I 5 | generally script them there is little point in maintaining a permanent procedure on every server. 6 | 7 | ## Schema creation 8 | 9 | ### CreateJSONSchemaFromTable.sql 10 | 11 | This temporary procedure creates a JSON schema from a table that 12 | matches the JSON you will get from doing a 13 | classic `select * from ... FOR JSON` statement on the entire table. This procedure needs SQL Server 2017 or later since it relies on `string_agg()`. 14 | 15 | ### CreateJSONArrayInArraySchemaFromTable.sql 16 | 17 | This will produce a JSON Array-in-Array schema from a table. 18 | This procedure needs SQL Server 2017 or later since it relies on `string_agg()`. 19 | 20 | ## JSON Data creation 21 | 22 | ### SaveJsonDataFromTable.sql 23 | 24 | This gets the JSON data from a table, taking into account all the problems that can come about such as dealing with CLR data types 25 | 26 | ### SaveExtendedJsonDataFromTable.sql 27 | 28 | This temporary procedure This gets the JSON data from a table, taking into account all the problems that can come about such as dealing with CLR data types 29 | 30 | ### ArrayInArrayJSONDataFromTable.sql 31 | 32 | This will produce a JSON Array-in-Array schema from either a table or a query. 33 | This can't be done, unfortunately, from SQL Server's implementation of JSON. 34 | This procedure needs SQL Server 2017 or later since it relies on `string_agg()`. It was 35 | first written to check out how much more economical on space the array-in-Array 36 | format was for storing tabular data as a document 37 | 38 | ## Importing JSON Data 39 | 40 | ### SaveJSONDataToTable.sql 41 | 42 | This saves a JSON file to a table, dealing with the complications of having old deprecated data types and CLR data types 43 | 44 | ### SelectJSONIntoTable.sql 45 | 46 | This is a way of taking a JSON string that contains both the schema 47 | and the data, and inserting it into a table in the database you wish 48 | 49 | ## Utilities 50 | 51 | ### SaveJSONToFile.sql 52 | 53 | This is a utility stored procedure for 54 | saving text to a file It is designed to save 55 | as utf-8 for JSON files but will do any file 56 | 57 | ### SaveMultiRowSelectStatementFromTable.sql 58 | 59 | This gets a multirow derived table SELECT * from (VALUES) statement 60 | from a table or a query. If you provide a destination, it will create 61 | the entire statement to stock the table with data. Warning: This is slow to use with large tables- use JSON instead as it is quicker, surprisingly. 62 | 63 | ### SaveMergeStatementFromTable 64 | 65 | This creates a merge statement, creating a table source from a multi-row 66 | VALUES statement, and merging it with the table whose name you provide. 67 | This MERGE statement can then be executed. Beware 68 | that this is only really practicable for small tables, because the VALUES statement degrades with scale. 69 | 70 | The source is specified either by the database.schema.table 'tablespec, 71 | or by doing tablename, schema and database individually. You can also use queries 72 | 73 | ## JSON Data Discovery 74 | 75 | ### UnwrapJSON.sql 76 | 77 | This multi-statement table-valued function talkes a JSON string and 78 | unwraps it into a relational hierarchy table that also retains 79 | the path to each element in the JSON document, and calculates the 80 | best-fit sql datatype for every simple value 81 | 82 | ### OpenJSONExpressions.sql 83 | 84 | This inline table-valued function talkes a JSON string and 85 | locates every table structure. Then it creates an OpenJSON 86 | Statement that can then be executed to create that table 87 | from the original JSON. 88 | 89 | ### TablesFromJSON 90 | 91 | This procedure returns a table for every one found in a JSON 92 | string 93 | 94 | 95 | ## PowerShell routines 96 | 97 | ### ValidateViaJSONSchema.ps1 98 | 99 | Shows how to validate a directory, with a subdirectory with the schema and a parallel directory with the data 100 | 101 | ### GenerateSQLMergeScripts.ps1 102 | 103 | This is a PowerShell script uses SaveMergeStatementFromTable.sql to generate a gigantic merge script for all the tables of a (small) database. 104 | -------------------------------------------------------------------------------- /SaveAllTables as ArrayinArrayJSON.sql: -------------------------------------------------------------------------------- 1 | EXEC sp_msforeachtable ' 2 | print ''Creating JSON for ?'' 3 | DECLARE @TheData NVARCHAR(MAX)=( 4 | SELECT ''[''+ String_Agg(f.EachLine,'','')+'']'' 5 | FROM 6 | (SELECT ''[''+String_Agg ( 7 | CASE WHEN shredded.type=1 8 | THEN ''"''+String_Escape(Coalesce(shredded.value,''null''),''json'')+''"'' 9 | ELSE Coalesce(shredded.value,''null'') 10 | END, '','') +'']'' 11 | AS TheValue 12 | FROM OpenJson((SELECT * 13 | FROM ? 14 | FOR JSON AUTO, INCLUDE_NULL_VALUES )) f 15 | CROSS apply OpenJson(f.value) shredded 16 | GROUP BY f.[Key])f(EachLine) 17 | ) 18 | CREATE TABLE ##myTemp (Bulkcol nvarchar(MAX)) 19 | INSERT INTO ##myTemp (Bulkcol) SELECT @TheData 20 | print ''Writing out ?'' 21 | EXECUTE xp_cmdshell ''bcp ##myTemp out C:\data\RawData\JsonData\adventureworks\?.JSON -c -C 65001 -T'' 22 | DROP TABLE ##myTemp' 23 | -------------------------------------------------------------------------------- /SaveExtendedJsonDataFromTable.sql: -------------------------------------------------------------------------------- 1 | CREATE OR alter PROCEDURE #SaveExtendedJsonDataFromTable 2 | /** 3 | Summary: > 4 | This gets the Extended JSON data from a table. You can specify 5 | it either by the database.schema.table 'tablespec, or do it 6 | individually. 7 | Author: phil factor 8 | Date: 04/02/2019 9 | 10 | Examples: > 11 | - USE pubs 12 | DECLARE @Json NVARCHAR(MAX) 13 | EXECUTE #SaveExtendedJsonDataFromTable 14 | @database='pubs', 15 | @Schema ='dbo', 16 | @table= 'jobs', 17 | @JSONData=@json OUTPUT 18 | PRINT @Json 19 | - use Adventureworks2016 20 | DECLARE @Json NVARCHAR(MAX) 21 | EXECUTE #SaveExtendedJsonDataFromTable 22 | @query = 'Select * from person.addresstype;', 23 | @JSONData=@json OUTPUT 24 | PRINT @Json 25 | - use Adventureworks2016 26 | DECLARE @Json NVARCHAR(MAX) 27 | EXECUTE #SaveExtendedJsonDataFromTable 28 | @query = ' 29 | SELECT AccountNumber, PersonType, Title, FirstName, MiddleName, LastName, 30 | Suffix, AddressLine1, AddressLine2, City, PostalCode, Name 31 | FROM Sales.Customer 32 | INNER JOIN Person.Person 33 | ON Customer.PersonID = Person.BusinessEntityID 34 | INNER JOIN Person.BusinessEntityAddress 35 | ON Person.BusinessEntityID = BusinessEntityAddress.BusinessEntityID 36 | INNER JOIN Person.Address 37 | ON BusinessEntityAddress.AddressID = Address.AddressID 38 | INNER JOIN Person.AddressType 39 | ON BusinessEntityAddress.AddressTypeID = AddressType.AddressTypeID ;', 40 | @JSONData=@json OUTPUT 41 | PRINT @Json 42 | Returns: > 43 | The JSON data 44 | **/ 45 | (@database sysname = NULL, @Schema sysname = NULL, @table sysname = NULL, 46 | @tableSpec sysname = NULL , @Query NVARCHAR(4000) = null, 47 | @jsonData NVARCHAR(MAX) OUTPUT 48 | ) 49 | AS 50 | BEGIN 51 | DECLARE @SourceCode NVARCHAR(4000); 52 | IF @database IS NULL 53 | SELECT @database = Coalesce(ParseName(@Tablespec, 3), Db_Name()); 54 | IF @Query IS NULL 55 | BEGIN 56 | IF Coalesce(@table, @Tablespec) IS NULL 57 | OR Coalesce(@Schema, @Tablespec) IS NULL 58 | RAISERROR('{"error":"must have the table details"}', 16, 1); 59 | 60 | IF @table IS NULL SELECT @table = ParseName(@Tablespec, 1); 61 | IF @Schema IS NULL SELECT @Schema = ParseName(@Tablespec, 2); 62 | IF @table IS NULL OR @Schema IS NULL OR @database IS NULL 63 | RAISERROR('{"error":"must have the table details"}', 16, 1); 64 | SELECT @SourceCode = 65 | N'USE ' + @database + N'; SELECT * FROM ' + QuoteName(@database) 66 | + N'.' + QuoteName(@Schema) + N'.' + QuoteName(@table); 67 | END; 68 | ELSE 69 | BEGIN 70 | SELECT @SourceCode = N'USE ' + @database + N';' + @Query; 71 | END; 72 | DECLARE @a_unique_key bit 73 | DECLARE @HowManyUniqueKeys INT 74 | SELECT @HowManyUniqueKeys= Sum(Convert(INT,is_part_of_unique_key)) 75 | FROM sys.dm_exec_describe_first_result_set(@SourceCode, NULL, 1) 76 | SELECT @a_unique_key= CASE WHEN @HowManyUniqueKeys = 1 THEN 1 ELSE 0 END 77 | --PRINT @sourcecode 78 | DECLARE @params NVARCHAR(MAX); 79 | DECLARE @list NVARCHAR(4000); 80 | DECLARE @AllErrors NVARCHAR(4000); 81 | 82 | SELECT @params = 83 | String_Agg( 84 | CASE WHEN system_type_id IN 85 | ( 35, -- text 86 | 99, -- ntext 87 | 98, -- sql_variant 88 | 167, -- varchar 89 | 231, -- nvarchar 90 | 239, -- nchar 91 | 175, -- char 92 | 36, -- uniqueidentifier 93 | 59, -- real 94 | 62, -- float 95 | 104, -- bit 96 | 241 97 | ) -- xml 98 | THEN 99 | CASE WHEN @a_unique_key=1 AND is_part_of_unique_key =1 THEN name+ ' as "_id", ' 100 | ELSE '' END +QuoteName(name) 101 | WHEN user_type_id IN (128, 129, 130) THEN 102 | 'convert(nvarchar(100),' + name + ') as "' + name + '"' 103 | --hierarchyid (128) geometry (130) and geography types (129) can be coerced. 104 | --------binary 105 | WHEN system_type_id IN 106 | ( 165, -- varbinary 107 | 173-- binary 108 | ) 109 | --THEN name + ' as "' + name + '.$binary.hex", ''80'' as "' + name + '.$binary.subType"' 110 | THEN name --I gave up. Extended json binary form is just awful 111 | WHEN system_type_id = 34 THEN --image 112 | 'convert(varbinary(max),' + name + ') as "' + name + '"' 113 | WHEN system_type_id IN (35) THEN --35 is text 114 | 'convert(varchar(max),' + name + ') as "' + name + '"' 115 | WHEN system_type_id IN (99) THEN --ntext 116 | 'convert(nvarchar(max),' + name + ') as "' + name + '"' 117 | --------numberInt 118 | WHEN system_type_id IN 119 | ( 48, -- tinyint 120 | 56, -- int 121 | 52 -- smallint 122 | ) 123 | THEN 124 | CASE WHEN @a_unique_key=1 AND is_part_of_unique_key =1 THEN name+ ' as "_id", ' 125 | ELSE '' END + 126 | 'convert(varchar(50),' + name + ') as "' + name + '.$numberInt"' 127 | --------numberLong 128 | WHEN system_type_id = 127 -- bigint 129 | THEN 130 | CASE WHEN @a_unique_key=1 AND is_part_of_unique_key =1 THEN name+ ' as "_id", ' 131 | ELSE '' END + 132 | 'convert(varchar(50),' + name + ') as "' + name + '.$numberLong"' 133 | --------date 134 | WHEN system_type_id IN 135 | ( 40, -- date 136 | 41, -- time 137 | 42, -- datetime2 138 | 43, -- datetimeoffset 139 | 58, -- smalldatetime 140 | 61, -- datetime 141 | 189 142 | ) -- timestamp 143 | THEN 144 | 'convert(datetimeoffset,convert(datetime2(0),' + name + ')) as "' + name + '.$date"' 145 | -------numberDecimal 146 | WHEN system_type_id IN 147 | ( 106, -- decimal 148 | 108 -- numeric 149 | ) 150 | THEN 151 | 'convert(varchar(50),' + name + ') as "' + name + '.$numberDecimal"' 152 | WHEN system_type_id IN 153 | ( 154 | 122, -- smallmoney 155 | 60 -- money 156 | ) 157 | THEN 158 | 'convert(varchar(50),' + name + ', 2) as "' + name + '.$numberDecimal"' ELSE QuoteName(name) 159 | END, 160 | ', ' 161 | ), 162 | @list=String_Agg(QuoteName(name),', '), 163 | @allErrors=String_Agg(Coalesce([error_message]+',',''),'') 164 | FROM sys.dm_exec_describe_first_result_set(@SourceCode, NULL, 1) WHERE Coalesce(is_hidden,0)=0 ; 165 | DECLARE @expression NVARCHAR(max) 166 | IF @query IS NULL 167 | begin 168 | SELECT @expression = 'USE ' + @database + ' 169 | SELECT @TheData=(SELECT ' + @params + ' FROM ' + QuoteName(@database) + '.' 170 | + QuoteName(@Schema) + '.' + QuoteName(@table) 171 | + ' FOR JSON PATH)'; 172 | END 173 | ELSE 174 | begin 175 | SELECT @query = left(@Query,patindex('%; ',rtrim(@Query)+' ' COLLATE SQL_Latin1_General_CP1_CI_AI)-1) 176 | SELECT @expression = N'USE ' + @database + N'; 177 | Select @TheData= (SELECT '+ @params + N' 178 | FROM (' + @Query + N')f(' + @list + N') for json path)'; 179 | end 180 | --PRINT @sourcecode 181 | --PRINT @expression 182 | IF RTrim(@Allerrors)<>'' RAISERROR ('Query could not be executed. %s )',16,1,@AllErrors ) 183 | EXECUTE sp_executesql @expression, N'@TheData nvarchar(max) output', 184 | @TheData = @jsonData OUTPUT; 185 | END; 186 | GO 187 | 188 | -------------------------------------------------------------------------------- /SaveJSONDataToTable.sql: -------------------------------------------------------------------------------- 1 | USE philfactor 2 | go 3 | CREATE OR ALTER PROCEDURE #SaveJsonDataToTable (@database sysname=null, @Schema sysname=NULL, @table sysname=null, @Tablespec sysname=NULL, @Path sysname) 4 | AS 5 | Declare @parameters nvarchar(max) 6 | DECLARE @hasIdentityColumn INT 7 | DECLARE @columnlist NVARCHAR(4000) 8 | 9 | IF Coalesce(@table,@Tablespec) IS NULL 10 | OR Coalesce(@schema,@Tablespec) IS NULL 11 | RAISERROR ('{"error":"must have the table details"}',16,1) 12 | 13 | IF @table is NULL SELECT @table=ParseName(@Tablespec,1) 14 | IF @Schema is NULL SELECT @schema=ParseName(@Tablespec,2) 15 | IF @Database is NULL SELECT @Database=coalesce(ParseName(@Tablespec,3),Db_Name()) 16 | IF @table IS NULL OR @schema IS NULL OR @database IS NULL 17 | RAISERROR ('{"error":"must have the table details"}',16,1) 18 | DECLARE @source NVARCHAR(MAX) = 19 | (Select @path+Replace(Replace(Replace(@schema+'-'+@Table,'.','-'),']',''),'[','')+'.json') 20 | SELECT @TableSpec=QuoteName(@database)+ '.'+ QuoteName(@Schema)+'.'+QuoteName(@table) 21 | DECLARE @SelectStatement NVARCHAR(200)=(SELECT 'Select * from '+@TableSpec) 22 | 23 | SELECT @parameters=String_Agg(QuoteName(name)+' '+ 24 | CASE f.system_type_name 25 | WHEN 'hierarchyid' THEN 'nvarchar(30)' 26 | WHEN 'geometry'THEN 'nvarchar(100)' 27 | WHEN 'geography' THEN 'nvarchar(100)' 28 | WHEN 'image' THEN 'Varbinary(max)' 29 | WHEN 'text' THEN 'Varchar(max)' 30 | WHEN 'ntext' THEN 'Nvarchar(max)' 31 | ELSE f.system_type_name end+ ' ''$."'+name+'"''',', '), 32 | @hasIdentityColumn =MAX(Convert(INT,is_identity_column)), 33 | @columnlist=String_Agg(name,', ') 34 | from 35 | sys.dm_exec_describe_first_result_set 36 | (@SelectStatement, NULL, 1) f 37 | 38 | IF @parameters IS NULL RAISERROR('cannot execute %s',16,1,@selectStatement) 39 | Declare @command nvarchar(max)=(SELECT ' 40 | use '+@database+' 41 | DECLARE @jsonData NVARCHAR(max)= 42 | (SELECT BulkColumn 43 | FROM OPENROWSET (BULK '''+@source +''', SINGLE_CLOB, CODEPAGE=''65001'' ) AS json ) 44 | 45 | Delete from '+@TableSpec+ CASE WHEN @hasIdentityColumn>0 THEN ' 46 | SET IDENTITY_INSERT '+@TableSpec+' ON ' ELSE '' END+' 47 | INSERT INTO '+@TableSpec+' ('+@columnList+') 48 | SELECT '+@columnList+' FROM OpenJson(@jsonData) 49 | WITH 50 | ( 51 | '+@parameters+' ); 52 | '+ CASE WHEN @hasIdentityColumn>0 THEN ' 53 | SET IDENTITY_INSERT '+@TableSpec+' OFF ' ELSE '' END) 54 | IF @command IS NULL RAISERROR('cannot execute null command',16,1) 55 | EXECUTE sp_executeSQL @command 56 | GO 57 | 58 | 59 | 60 | 61 | -------------------------------------------------------------------------------- /SaveJSONToFile.sql: -------------------------------------------------------------------------------- 1 | CREATE OR ALTER PROCEDURE #SaveJSONToFile 2 | /** 3 | Summary: > 4 | This is a utility stored procedure for 5 | saving text to a file It is designed to save 6 | as utf-8 for JSON files but will do any file 7 | 8 | Author: phil factor 9 | Date: 01/11/2018 10 | Examples: 11 | Execute #SaveJSONToFile @theString=@TheJSON, @filename=@destination' 12 | Returns: > 13 | nothing 14 | **/ 15 | @TheString NVARCHAR(MAX), @Filename NVARCHAR(255), 16 | @Unicode INT=8 --0 for not unicode, 8 for utf8 and 16 for utf16 17 | AS 18 | SET NOCOUNT ON 19 | DECLARE @MySpecialTempTable sysname, @Command NVARCHAR(4000) , @RESULT INT; 20 | --firstly we create a global temp table with a unique name 21 | SELECT @MySpecialTempTable = 22 | '##temp' + Convert(VARCHAR(12), Convert(INT, Rand() * 1000000)); 23 | --then we create it using dynamic SQL, & insert a single row 24 | --in it with the MAX Varchar stocked with the string we want 25 | SELECT @Command = 'create table [' 26 | + @MySpecialTempTable 27 | + '] (MyID int identity(1,1), Bulkcol nvarchar(MAX)) 28 | insert into [' 29 | + @MySpecialTempTable 30 | + '](BulkCol) select @TheString' 31 | EXECUTE sp_ExecuteSQL @command, N'@TheString nvarchar(MAX)', 32 | @TheString 33 | SELECT @command 34 | --then we execute the BCP to save the file 35 | SELECT @Command = 'bcp "select BulkCol from [' 36 | + @MySpecialTempTable + ']' 37 | + '" queryout "' 38 | + @Filename + '" ' 39 | + CASE @Unicode 40 | WHEN 0 THEN '-c' 41 | WHEN 8 THEN '-c -C 65001' 42 | ELSE '-w' END 43 | + ' -T -S' + @@ServerName 44 | SELECT @command 45 | 46 | EXECUTE @RESULT= MASTER..xp_cmdshell @command 47 | EXECUTE ( 'Drop table ' + @MySpecialTempTable ) 48 | RETURN @result 49 | go 50 | -------------------------------------------------------------------------------- /SaveJsonDataFromTable.sql: -------------------------------------------------------------------------------- 1 | CREATE OR ALTER PROCEDURE #SaveJsonDataFromTable 2 | /** 3 | Summary: > 4 | This gets the JSON data from a table 5 | Author: phil factor 6 | Date: 26/10/2018 7 | 8 | Examples: > 9 | USE bigpubs 10 | DECLARE @Json NVARCHAR(MAX) 11 | EXECUTE #SaveJsonDataFromTable 12 | @database='pubs', 13 | @Schema ='dbo', 14 | @table= 'authors', 15 | @JSONData=@json OUTPUT 16 | PRINT @Json 17 | Returns: > 18 | The JSON data 19 | **/ 20 | (@database sysname = NULL, @Schema sysname = NULL, @table sysname = NULL, 21 | @Tablespec sysname = NULL, @jsonData NVARCHAR(MAX) OUTPUT 22 | ) 23 | AS 24 | BEGIN 25 | DECLARE @Data NVARCHAR(MAX); 26 | IF Coalesce(@table, @Tablespec) IS NULL 27 | OR Coalesce(@Schema, @Tablespec) IS NULL 28 | RAISERROR('{"error":"must have the table details"}', 16, 1); 29 | 30 | IF @table IS NULL SELECT @table = ParseName(@Tablespec, 1); 31 | IF @Schema IS NULL SELECT @Schema = ParseName(@Tablespec, 2); 32 | IF @database IS NULL SELECT @database = Coalesce(ParseName(@Tablespec, 3),Db_Name()); 33 | IF @table IS NULL OR @Schema IS NULL OR @database IS NULL 34 | RAISERROR('{"error":"must have the table details"}', 16, 1); 35 | 36 | DECLARE @SourceCode NVARCHAR(255) = 37 | ( 38 | SELECT 'SELECT * FROM ' + QuoteName(@database) + '.' 39 | + QuoteName(@Schema) + '.' + QuoteName(@table) 40 | ); 41 | 42 | 43 | DECLARE @params NVARCHAR(MAX) = 44 | ( 45 | SELECT 46 | String_Agg( 47 | CASE WHEN user_type_id IN (128, 129, 130) THEN 48 | 'convert(nvarchar(100),' + name 49 | + ') as "' + name + '"' 50 | --hierarchyid (128) geometry (130) and geography types (129) can be coerced. 51 | WHEN user_type_id IN (35) THEN 52 | 'convert(varchar(max),' + name + ') as "' 53 | + name + '"' 54 | WHEN user_type_id IN (99) THEN 55 | 'convert(nvarchar(max),' + name + ') as "' 56 | + name + '"' 57 | WHEN user_type_id IN (34) THEN 58 | 'convert(varbinary(max),' + name 59 | + ') as "' + name + '"' ELSE 60 | QuoteName(name) END, ', ' ) 61 | FROM sys.dm_exec_describe_first_result_set(@SourceCode, NULL, 1) 62 | ); 63 | DECLARE @expression NVARCHAR(800) = 64 | ' 65 | USE ' + @database + ' 66 | SELECT @TheData=(SELECT ' + @params + ' FROM ' + QuoteName(@database) + '.' 67 | + QuoteName(@Schema) + '.' + QuoteName(@table) 68 | + ' FOR JSON auto, INCLUDE_NULL_VALUES)'; 69 | EXECUTE sp_executesql @expression, N'@TheData nvarchar(max) output', 70 | @TheData = @jsonData OUTPUT; 71 | END; 72 | GO 73 | 74 | 75 | -------------------------------------------------------------------------------- /SaveMergeStatementFromTable.sql: -------------------------------------------------------------------------------- 1 | 2 | DROP PROCEDURE IF exists #SaveMergeStatementFromTable 3 | GO 4 | CREATE PROCEDURE #SaveMergeStatementFromTable 5 | /** 6 | Summary: > 7 | This creates a merge statement, creating a table source from a multi-row 8 | VALUES statement, and merging it with the table whose name you provide. 9 | This MERGE statement can then be executed. Beware 10 | that this is only really practicable for small tables, because the 11 | VALUES statement degrades with scale. 12 | The source is specified either by the database.schema.table 'tablespec, 13 | or by doing tablename, schema and database individually. 14 | 15 | Author: phil factor 16 | Date: 11/11/2019 17 | 18 | Examples: > 19 | - DECLARE @TheStatement NVARCHAR(MAX) 20 | EXECUTE #SaveMergeStatementFromTable 21 | @database='pubs', 22 | @Schema ='dbo', 23 | @table= 'jobs', 24 | @Statement=@TheStatement OUTPUT, 25 | @DontSpecifyTheDatabase=1 26 | PRINT @TheStatement 27 | - DECLARE @TheStatement NVARCHAR(MAX) 28 | EXECUTE #SaveMergeStatementFromTable 29 | @tablespec='Adventureworks2016.[HumanResources].[Department]', 30 | @Statement=@TheStatement OUTPUT; 31 | PRINT @TheStatement 32 | - DECLARE @TheStatement NVARCHAR(MAX) 33 | EXECUTE #SaveMergeStatementFromTable 34 | @tablespec='Adventureworks2016.[Person].[vAdditionalContactInfo]', 35 | @Statement=@TheStatement OUTPUT; 36 | PRINT @TheStatement 37 | - use Adventureworks2016 38 | DECLARE @TheStatement NVARCHAR(MAX) 39 | EXECUTE #SaveMergeStatementFromTable 40 | @query = ' 41 | 42 | SELECT into #temp identity(), AccountNumber, PersonType, Title, FirstName, MiddleName, LastName, 43 | Suffix, AddressLine1, AddressLine2, City, PostalCode, Name 44 | FROM Sales.Customer 45 | INNER JOIN Person.Person 46 | ON Customer.PersonID = Person.BusinessEntityID 47 | INNER JOIN Person.BusinessEntityAddress 48 | ON Person.BusinessEntityID = BusinessEntityAddress.BusinessEntityID 49 | INNER JOIN Person.Address 50 | ON BusinessEntityAddress.AddressID = Address.AddressID 51 | INNER JOIN Person.AddressType 52 | ON BusinessEntityAddress.AddressTypeID = AddressType.AddressTypeID ;', 53 | @Statement =@TheStatement OUTPUT 54 | PRINT @TheStatement 55 | Returns: > 56 | The Select statement using the multirow Values clause as a derived table. 57 | **/ 58 | (@database sysname = NULL, --if not providing a table spec, then use this for the database 59 | @Schema sysname = NULL,--if not providing a table spec, then use this for the schema 60 | @table sysname = NULL,--if not providing a table spec, then use this for the table 61 | @tableSpec sysname = NULL , --the full three-part table spec database.schema.table 62 | @Query NVARCHAR(4000) = null, --if you are doing this for a query rather than a table 63 | @Statement NVARCHAR(MAX) OUTPUT,--the resulting sql statement 64 | @DestinationTable sysname=NULL,--the name of the destination table if you specify a query etc 65 | @DestinationDatabase sysname=NULL, --the destination database if different name from the source 66 | @PrimaryKeys NVARCHAR(100)=NULL, --a list of the primary keys if you use a query as a source 67 | @DontSpecifyTheDatabase bit=NULL --set this if you wish to avoid the destination database name 68 | ) 69 | AS 70 | BEGIN 71 | DECLARE @Source Sysname, @TheFinalQuery NVARCHAR(4000), 72 | @SelectStarFrom NVARCHAR(4000), @ItHasAnIdentityColumn int; 73 | DECLARE @compatibility_level INT = (SELECT compatibility_level FROM sys.databases WHERE name = Db_Name()) 74 | IF (@compatibility_level <130) 75 | RAISERROR ('compatibility LEVEL IS ONLY %d AND should be AT least 130',16,1, @compatibility_level) 76 | IF @database IS NULL 77 | SELECT @database = Coalesce(ParseName(@Tablespec, 3), Db_Name()); 78 | IF @Query IS NULL --we always use a query. If you don't provide it we construct it 79 | BEGIN 80 | IF Coalesce(@table, @Tablespec) IS NULL 81 | OR Coalesce(@Schema, @Tablespec) IS NULL 82 | RAISERROR('{"error":"must have the table details"}', 16, 1); 83 | 84 | IF @table IS NULL SELECT @table = ParseName(@Tablespec, 1); 85 | IF @Schema IS NULL SELECT @Schema = ParseName(@Tablespec, 2); 86 | IF @table IS NULL OR @Schema IS NULL OR @database IS NULL 87 | RAISERROR('{"error":"must have the table details"}', 16, 1); 88 | SELECT @source=QuoteName(@database) 89 | + N'.' + QuoteName(@Schema) + N'.' + QuoteName(@table); 90 | DECLARE @AllErrors NVARCHAR(4000); 91 | DECLARE @ColumnExpressions NVARCHAR(4000) 92 | SELECT 93 | @ColumnExpressions= 94 | -- SQL Prompt formatting off 95 | String_Agg( 96 | CASE 97 | --hierarchyid, geometry,and geography types can be coerced. 98 | WHEN system_type_id IN (240) 99 | THEN 'convert(nvarchar(max),' + QuoteName(name) + ') AS "'+name+'"' 100 | --text and ntext 101 | WHEN system_type_id IN (35,99) 102 | THEN 'convert(nvarchar(max),' + QuoteName(name) + ')AS "'+name+'"' 103 | --image varbinary snd uniqueIdentifier 104 | WHEN system_type_id IN (36,165) 105 | THEN 'convert(nvarchar(max),' + QuoteName(name) + ')AS "'+name+'"' 106 | WHEN system_type_id = 34 --image type 107 | THEN 'cast(' + QuoteName(name) + ' as varbinary(max)) AS "'+name+'"' 108 | --xml 109 | --WHEN system_type_id = 241 110 | ELSE QuoteName(name) END,', ') WITHIN GROUP ( ORDER BY column_ordinal ASC ), 111 | -- SQL Prompt formatting on 112 | --@list=String_Agg(QuoteName(name),', '), 113 | @allErrors=String_Agg([error_message],', ') 114 | --SELECT String_Agg(name,',') WITHIN GROUP ( ORDER BY column_ordinal ASC ) 115 | FROM sys.dm_exec_describe_first_result_set((SELECT 'Select * from '+@source), NULL, 1)r 116 | WHERE Coalesce(is_hidden,0)=0 AND Coalesce(is_computed_column,0)=0 117 | 118 | IF @ColumnExpressions IS NULL 119 | RAISERROR( 'Source Code %s couldn''t be executed because %s',16,1, '' , @AllErrors); 120 | SELECT @TheFinalQuery ='SELECT '+ @ColumnExpressions+' FROM ' +@source, 121 | @SelectStarFrom = 'SELECT * FROM '+@source 122 | IF @DestinationDatabase IS NULL 123 | SELECT @DestinationTable=COALESCE(@DestinationTable,@source) 124 | ELSE 125 | SELECT @DestinationTable= 126 | Replace(COALESCE(@DestinationTable,@source),@database,@DestinationDatabase) 127 | END; 128 | ELSE 129 | BEGIN--you are supplying a query 130 | --IF you ARE suplying a query then it must not have the final ';' 131 | SELECT @TheFinalQuery = --so strip the semicolon 132 | CASE WhereFinalSemicolonWas WHEN 0 THEN @Query 133 | ELSE Left(@Query,WhereFinalSemicolonWas-1) END 134 | FROM (VALUES (PatIndex('%; ',rtrim(@Query) 135 | + ' ' COLLATE DATABASE_DEFAULT)) 136 | )f(WhereFinalSemicolonWas) 137 | IF Coalesce(@DestinationTable,'') = '' COLLATE DATABASE_DEFAULT --if null or blank 138 | RAISERROR ( 139 | 'if you provide a query, you must also provide a "@destinationTable" table name', 140 | 16,1) 141 | SELECT @SelectStarFrom = @TheFinalQuery 142 | END; 143 | IF Coalesce(@DontSpecifyTheDatabase,0)<>0 144 | SELECT @DestinationTable=QuoteName(ParseName(@DestinationTable,2))+'.'+QuoteName(ParseName(@DestinationTable,1)) 145 | DECLARE @ColumnList nvarchar(4000) 146 | select @ColumnList= string_agg(name,', ') 147 | FROM sys.dm_exec_describe_first_result_set(@SelectStarFrom , NULL, 1) 148 | WHERE Coalesce(is_hidden,0)=0 AND Coalesce(is_computed_column,0)=0 149 | if (@ColumnList is null) 150 | RAISERROR ('The expression %s was not correct',16,1,@TheFinalQuery) 151 | --is there a PK in the specified table or is the a specified PK?? 152 | DECLARE @PK NVARCHAR(400)--the list of unique indexes in the table 153 | IF @PrimaryKeys IS NOT NULL --then a primary key spec has been provided 154 | SELECT @PK=String_Agg( 155 | 'source.'+LTrim(value) COLLATE DATABASE_DEFAULT 156 | +' = target.'+LTrim(value) COLLATE DATABASE_DEFAULT,' AND ' 157 | ) 158 | FROM string_split(@PrimaryKeys COLLATE DATABASE_DEFAULT ,',') 159 | ELSE 160 | SELECT @PK=String_Agg( 161 | 'source.'+name COLLATE DATABASE_DEFAULT+' = '+'target.' 162 | +name COLLATE DATABASE_DEFAULT,' AND ' 163 | ) 164 | FROM sys.dm_exec_describe_first_result_set(@SelectStarFrom, NULL, 1) 165 | WHERE is_part_of_unique_key=1 166 | AND Coalesce(is_hidden,0)=0 AND Coalesce(is_computed_column,0)=0 167 | IF (@PK is null) 168 | RAISERROR ( 169 | 'There seems to be no primary key produced from "%s"',16,1,@SelectStarFrom) 170 | -- now we have the ON conditions prepared for the merge statement 171 | --is there an identity column in the query? 172 | SELECT @ItHasAnIdentityColumn = 173 | CASE when EXISTS( 174 | SELECT 1 FROM sys.dm_exec_describe_first_result_set(@SelectStarFrom, NULL, 1 175 | ) 176 | WHERE Coalesce(is_identity_column,0)=1) THEN 1 ELSE 0 end 177 | --now we can create the SQL that will, it turn create the merge statement 178 | DECLARE @expression NVARCHAR(MAX) 179 | SELECT @expression= 180 | 'Select @TheData=(Select ''' 181 | +CASE when @table IS not NULL THEN 'PRINT ''''Ensuring that the "'+ @table+'" data is there''''' ELSE''''END 182 | +' 183 | ' 184 | +CASE WHEN @ItHasAnIdentityColumn=1 THEN ' 185 | SET IDENTITY_INSERT '+@DestinationTable+' ON;' 186 | ELSE '' END+' 187 | MERGE INTO '+@DestinationTable+' AS target 188 | USING (VALUES ('' + String_Agg(ROW, ''), 189 | ('') + '') 190 | )source('+@ColumnList+') 191 | ON '+@Pk+' 192 | WHEN NOT MATCHED BY TARGET THEN 193 | INSERT ( '+@ColumnList+' ) 194 | VALUES ( '+@ColumnList+' ) 195 | WHEN NOT MATCHED BY SOURCE THEN 196 | DELETE; 197 | ' 198 | +CASE WHEN @ItHasAnIdentityColumn=1 THEN 'SET IDENTITY_INSERT '+@DestinationTable+' OFF;' ELSE '' END + ' 199 | IF @@ERROR <> 0 SET NOEXEC ON 200 | 201 | '' 202 | FROM 203 | ( 204 | SELECT 205 | ( 206 | SELECT 207 | String_Agg 208 | (CASE type 209 | WHEN 1 THEN '''''''' + replace(rtrim(value),'''''''','''''''''''') + '''''''' 210 | WHEN 2 THEN value 211 | WHEN 3 THEN 212 | CASE WHEN value = ''true'' THEN ''1'' ELSE ''0'' END 213 | ELSE ''null'' END, 214 | '', '' 215 | ) 216 | FROM OpenJson(value) 217 | ) AS row 218 | FROM OpenJson( 219 | ('+@TheFinalQuery+' FOR JSON PATH, INCLUDE_NULL_VALUES) 220 | ) 221 | ) AS f(row));' 222 | IF @expression IS NULL 223 | RAISERROR ('The expression could not be created', 16,1) 224 | ELSE 225 | begin 226 | --now we create the SQL for the merge statement 227 | DECLARE @RowsInResult int 228 | EXECUTE sp_executesql @expression, N'@TheData nvarchar(max) output', 229 | @TheData = @Statement OUTPUT; 230 | --it could be some sort of error or maybe an empty table 231 | IF @Statement IS NULL 232 | BEGIN 233 | DECLARE @CountOfResultExpression NVARCHAR(4000),@RowsInData INT 234 | SELECT @Statement='', 235 | @CountOfResultExpression='SELECT @count= Count(*) FROM ('+@TheFinalQuery+')f', 236 | @RowsInData=0 237 | EXECUTE sp_ExecuteSQL @CountOfResultExpression,N'@count int output', 238 | @count = @RowsInData OUTPUT; 239 | IF @RowsInData<>0 240 | RAISERROR ('No merge statement could be produced from "%s"', 16,1,@expression) 241 | end 242 | END 243 | END 244 | GO 245 | 246 | -------------------------------------------------------------------------------- /SaveMultiRowSelectStatementFromTable.sql: -------------------------------------------------------------------------------- 1 | CREATE OR ALTER PROCEDURE #SaveMultiRowSelectStatementFromTable 2 | /** 3 | Summary: > 4 | This gets a multirow derived table SELECT * from (VALUES) statement from a table 5 | it either by the database.schema.table 'tablespec, or do it individually. 6 | Author: phil factor 7 | Date: 04/05/2019 8 | 9 | Examples: > 10 | - USE pubs 11 | DECLARE @TheStatement NVARCHAR(MAX) 12 | EXECUTE #SaveMultiRowSelectStatementFromTable 13 | @database='pubs', 14 | @Schema ='dbo', 15 | @table= 'jobs', 16 | @Statement=@TheStatement OUTPUT, 17 | @Destination='pubs.dbo.jobs' 18 | PRINT @TheStatement 19 | - use Adventureworks2016 20 | DECLARE @TheStatement NVARCHAR(MAX) 21 | EXECUTE #SaveMultiRowSelectStatementFromTable 22 | @query = 'Select * from person.addresstype;', 23 | @Statement =@TheStatement OUTPUT 24 | PRINT @TheStatement 25 | - use Adventureworks2016 26 | DECLARE @TheStatement NVARCHAR(MAX) 27 | EXECUTE #SaveMultiRowSelectStatementFromTable 28 | @query = ' 29 | SELECT AccountNumber, PersonType, Title, FirstName, MiddleName, LastName, 30 | Suffix, AddressLine1, AddressLine2, City, PostalCode, Name 31 | FROM Sales.Customer 32 | INNER JOIN Person.Person 33 | ON Customer.PersonID = Person.BusinessEntityID 34 | INNER JOIN Person.BusinessEntityAddress 35 | ON Person.BusinessEntityID = BusinessEntityAddress.BusinessEntityID 36 | INNER JOIN Person.Address 37 | ON BusinessEntityAddress.AddressID = Address.AddressID 38 | INNER JOIN Person.AddressType 39 | ON BusinessEntityAddress.AddressTypeID = AddressType.AddressTypeID ;', 40 | @Statement =@TheStatement OUTPUT 41 | PRINT @TheStatement 42 | Returns: > 43 | The Select statement using the multirow Values clause as a derived table. 44 | **/ 45 | (@database sysname = NULL, @Schema sysname = NULL, @table sysname = NULL, 46 | @tableSpec sysname = NULL , @Query NVARCHAR(4000) = null, 47 | @Statement NVARCHAR(MAX) OUTPUT, 48 | @Destination sysname=NULL 49 | ) 50 | AS 51 | BEGIN 52 | DECLARE @Finalquery NVARCHAR(4000); 53 | IF @database IS NULL 54 | SELECT @database = Coalesce(ParseName(@Tablespec, 3), Db_Name()); 55 | IF @Query IS NULL 56 | BEGIN 57 | IF Coalesce(@table, @Tablespec) IS NULL 58 | OR Coalesce(@Schema, @Tablespec) IS NULL 59 | RAISERROR('{"error":"must have the table details"}', 16, 1); 60 | 61 | IF @table IS NULL SELECT @table = ParseName(@Tablespec, 1); 62 | IF @Schema IS NULL SELECT @Schema = ParseName(@Tablespec, 2); 63 | IF @table IS NULL OR @Schema IS NULL OR @database IS NULL 64 | RAISERROR('{"error":"must have the table details"}', 16, 1); 65 | SELECT @Finalquery ='SELECT * FROM ' + QuoteName(@database) 66 | + N'.' + QuoteName(@Schema) + N'.' + QuoteName(@table); 67 | END; 68 | ELSE 69 | BEGIN 70 | select @Finalquery = left(@Query,patindex('%; ',rtrim(@Query)+' ' COLLATE SQL_Latin1_General_CP1_CI_AI)-1) 71 | END; 72 | 73 | Declare @Params nvarchar(4000) 74 | 75 | select @Params= string_agg(name,', ') 76 | from sys.dm_exec_describe_first_result_set(@finalquery, NULL, 1) 77 | WHERE Coalesce(is_hidden,0)=0 78 | if (@Params is null) Raiserror ('The expression %s was not correct',16,1,@Finalquery) 79 | 80 | Declare @expression NVARCHAR(MAX) 81 | Select @expression='Select @TheData=(SELECT '''+ 82 | case when @Destination is not null then 'Insert into '+@Destination+' ('+@Params+') 83 | ' else '' end+'Select * from (VALUES ('' + String_Agg(ROW, ''), 84 | ('') + ''))f(d'+@Params+')'' 85 | FROM 86 | ( 87 | SELECT 88 | ( 89 | SELECT 90 | String_Agg 91 | (CASE type 92 | WHEN 1 THEN '''''''' + replace(value,'''''''','''''''''''') + '''''''' 93 | WHEN 2 THEN value 94 | WHEN 3 THEN 95 | CASE WHEN value = ''true'' THEN ''1'' ELSE ''0'' END 96 | ELSE ''null'' END, 97 | '', '' 98 | ) 99 | FROM OpenJson(value) 100 | ) AS row 101 | FROM OpenJson( 102 | ('+@Finalquery+' FOR JSON PATH, INCLUDE_NULL_VALUES) 103 | ) 104 | ) AS f(row));' 105 | --print @expression 106 | EXECUTE sp_executesql @expression, N'@TheData nvarchar(max) output', 107 | @TheData = @Statement OUTPUT; 108 | END 109 | GO 110 | 111 | 112 | -------------------------------------------------------------------------------- /SelectJSONIntoTable.sql: -------------------------------------------------------------------------------- 1 | CREATE OR ALTER PROCEDURE #SelectJsonIntoTable 2 | (@database sysname, @JSONSchemaAndData NVARCHAR(MAX) 3 | ) 4 | AS 5 | /** 6 | Summary: > 7 | This is a way of taking a JSON string that contains both the schema 8 | and the data, and inserting it into a table in the database you wish 9 | Author: philfactor 10 | Date: 01/11/2018 11 | Database: business 12 | Examples: 13 | - Declare @jsonSchema NVARCHAR(max)= ' 14 | {"schema":{ 15 | "$id": "https://mml.uk/jsonSchema/Person-PhoneNumberType.json", 16 | "$schema": "http://json-schema.org/draft-07/schema#", 17 | "title": "PhoneNumberType", 18 | "SQLtablename":"[Person].[PhoneNumberType]", 19 | "SQLschema":"Person", 20 | "type": "array", 21 | "items": { 22 | "type": "object", 23 | "required": ["PhoneNumberTypeID","Name","ModifiedDate"], 24 | "maxProperties": 4, 25 | "minProperties": 3, 26 | "properties":{ 27 | "PhoneNumberTypeID": {"type":["number"],"sqltype":"int", "columnNo":1, "nullable":0, "Description":""}, 28 | "Name": {"type":["string"],"sqltype":"nvarchar(50)", "columnNo":2, "nullable":0, "Description":""}, 29 | "ModifiedDate": {"type":["string"],"sqltype":"datetime", "columnNo":3, "nullable":0, "Description":""}} 30 | } 31 | },"data":[ 32 | {"PhoneNumberTypeID":1,"Name":"Cell","ModifiedDate":"2017-12-13T13:19:22.273"}, 33 | {"PhoneNumberTypeID":2,"Name":"Home","ModifiedDate":"2017-12-13T13:19:22.273"}, 34 | {"PhoneNumberTypeID":3,"Name":"Work","ModifiedDate":"2017-12-13T13:19:22.273"}]} 35 | ' 36 | EXECUTE #SelectJsonIntoTable @Database='MyDatabase', @JSONSchemaAndData=@jsonSchema 37 | Returns: > 38 | nothing 39 | **/ 40 | DECLARE @ExplicitSchema NVARCHAR(MAX); 41 | DECLARE @columnlist NVARCHAR(4000); 42 | DECLARE @tableSpec sysname; 43 | 44 | IF @JSONSchemaAndData IS NULL 45 | OR @Database IS NULL 46 | RAISERROR('{"error":"must have the database and JSON details"}', 16, 1); 47 | 48 | SELECT @ExplicitSchema = 49 | String_Agg(quotename(property.[key])+' '+ 50 | CASE sqltype 51 | WHEN 'hierarchyid' THEN 'nvarchar(30)' 52 | WHEN 'geometry'THEN 'nvarchar(100)' 53 | WHEN 'geography' THEN 'nvarchar(100)' 54 | WHEN 'image' THEN 'Varbinary(max)' 55 | WHEN 'text' THEN 'Varchar(max)' 56 | WHEN 'ntext' THEN 'Nvarchar(max)' 57 | ELSE sqltype end+ ' ''$."'+property.[key]+'"''',',') 58 | FROM OpenJson(@JSONSchemaAndData,'strict $.schema.items.properties') property 59 | OUTER APPLY OpenJson(property.value) 60 | WITH (sqltype VARCHAR(20) 'strict $.sqltype'); 61 | 62 | SELECT @columnlist = String_Agg( 63 | CASE WHEN sqltype IN ( 'hierarchyid', 'geometry', 'geography') 64 | THEN 'Convert('+sqlType+','+QuoteName(property.[key])+') AS "'+property.[key]+'"' 65 | ELSE property.[key] end,', ') 66 | FROM OpenJson(@JSONSchemaAndData,'strict $.schema.items.properties') property 67 | OUTER APPLY OpenJson(property.value) 68 | WITH (sqltype VARCHAR(20) 'strict $.sqltype'); 69 | 70 | IF @ExplicitSchema IS NULL RAISERROR('Cannot locate the explicit schema for WITH clause ', 16, 1); 71 | SELECT @Tablespec=Json_Value(@JSONSchemaAndData,'strict $.schema.SQLtablename') 72 | DECLARE @command NVARCHAR(MAX) = 73 | (SELECT ' 74 | use ' + @database + ' 75 | DROP TABLE IF EXISTS '+@TableSpec+' 76 | SELECT '+@columnlist+' into '+@TableSpec+' FROM OpenJson(@jsonData,''strict $.data'') 77 | WITH 78 | ( 79 | '+@explicitSchema+' 80 | ); 81 | ') 82 | 83 | EXECUTE sp_executesql @command, N'@jsonData nvarchar(max)', @jsonData = @JSONSchemaAndData; 84 | 85 | GO 86 | 87 | 88 | 89 | 90 | 91 | 92 | 93 | 94 | 95 | -------------------------------------------------------------------------------- /TablesFromJSON.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE TablesFromJSON @TheJSON NVARCHAR(MAX) 2 | /** 3 | summary: > 4 | This procedure returns a table for every one found in a JSON 5 | string 6 | Author: Phil Factor 7 | Revision: 1.0 8 | date: 1 Nov 2020 9 | example: 10 | - EXECUTE TablesFromJSON @TheJSON= N'[ 11 | {"name":"Phil", "email":"PhilipFactor@geeMail.com"}, 12 | {"name":"Geoff", "email":"Geoff2435@geeMail.com"}, 13 | {"name":"Mo", "email":"MoHussain34@geeMail.com"}, 14 | {"name":"Karen", "email":"KarenAlott34@geeMail.com"}, 15 | {"name":"Bob", "email":"bob32@geeMail.com"} 16 | ]' 17 | returns: > 18 | expression 19 | 20 | **/ 21 | AS 22 | DECLARE @expressions TABLE (id INT IDENTITY, TheExpression NVARCHAR(MAX)); 23 | INSERT INTO @expressions (TheExpression) 24 | SELECT expression FROM OpenJSONExpressions(@TheJSON); 25 | DECLARE @RowCount INT = -1, @ii INT = 1, @expressionToExcecute NVARCHAR(MAX); 26 | WHILE @RowCount <> 0 27 | BEGIN 28 | SELECT @expressionToExcecute = TheExpression FROM @expressions WHERE id = @ii; 29 | SELECT @RowCount = @@RowCount; 30 | SELECT @ii = @ii + 1; 31 | IF @RowCount > 0 32 | EXECUTE sp_executesql @expressionToExcecute, N'@JSON NVARCHAR(MAX)', 33 | @JSON = @TheJSON; 34 | END; 35 | GO -------------------------------------------------------------------------------- /UnwrapJSON.sql: -------------------------------------------------------------------------------- 1 | CREATE OR alter FUNCTION [dbo].[UnwrapJson] 2 | /** 3 | summary: > 4 | This multi-statement table-valued function talkes a JSON string and 5 | unwraps it into a relational hierarchy table that also retains 6 | the path to each element in the JSON document, and calculates the 7 | best-fit sql datatype for every simple value 8 | Author: Phil Factor 9 | Revision: 1.0 10 | date: 1 Nov 2020 11 | example: 12 | - SELECT * FROM UnwrapJson (N'[ 13 | {"name":"Phil", "email":"PhilipFactor@gmail.com"}, 14 | {"name":"Bob", "email":"bob32@gmail.com"} 15 | ]') 16 | returns: > 17 | id, level, [key], Value, type, SQLDatatype, parent, path 18 | 19 | **/ 20 | ( 21 | @JSON NVARCHAR(MAX) 22 | ) 23 | RETURNS @Unwrapped TABLE 24 | ( 25 | [id] INT IDENTITY, --just used to get a unique reference to each json item 26 | [level] INT, --the hierarchy level 27 | [key] NVARCHAR(100), --the key or name of the item 28 | [Value] NVARCHAR(MAX),--the value, if it is a null, int,binary,numeric or string 29 | type INT, --0 TO 5, the JSON type, null, numeric, string, binary, array or object 30 | SQLDatatype sysname, --whatever the datatype can be parsed to 31 | parent INT, --the ID of the parent 32 | [path] NVARCHAR(4000) --the path as used by OpenJSON 33 | ) 34 | AS begin 35 | INSERT INTO @Unwrapped ([level], [key], Value, type, SQLDatatype, parent, 36 | [path]) 37 | VALUES 38 | (0, --the level 39 | NULL, --the key, 40 | @json, --the value, 41 | CASE WHEN Left(ltrim(@json),1)='[' THEN 4 ELSE 5 END, --the type 42 | 'json', --SQLDataType, 43 | 0 , --no parent 44 | '$' --base path 45 | ); 46 | DECLARE @ii INT = 0,--the level 47 | @Rowcount INT = -1; --the number of rows from the previous iteration 48 | WHILE @Rowcount <> 0 --while we are still finding levels 49 | BEGIN 50 | INSERT INTO @Unwrapped ([level], [key], Value, type, SQLDatatype, parent, 51 | [path]) 52 | SELECT [level] + 1 AS [level], new.[Key] AS [key], 53 | new.[Value] AS [value], new.[Type] AS [type], 54 | -- SQL Prompt formatting off 55 | /* in order to determine the datatype of a json value, the best approach is to a determine 56 | the datatype that can be parsed. It JSON, an array of objects can contain attributes that arent 57 | consistent either in their name or value. */ 58 | CASE 59 | WHEN new.Type = 0 THEN 'bit null' 60 | WHEN new.[type] IN (1,2) then COALESCE( 61 | CASE WHEN TRY_CONVERT(INT,new.[value]) IS NOT NULL THEN 'int' END, 62 | CASE WHEN TRY_CONVERT(NUMERIC(14,4),new.[value]) IS NOT NULL THEN 'numeric' END, 63 | CASE WHEN TRY_CONVERT(FLOAT,new.[value]) IS NOT NULL THEN 'float' END, 64 | CASE WHEN TRY_CONVERT(MONEY,new.[value]) IS NOT NULL THEN 'money' END, 65 | CASE WHEN TRY_CONVERT(DateTime,new.[value],126) IS NOT NULL THEN 'Datetime2' END, 66 | CASE WHEN TRY_CONVERT(Datetime,new.[value],127) IS NOT NULL THEN 'Datetime2' END, 67 | 'nvarchar') 68 | WHEN new.Type = 3 THEN 'bit' 69 | WHEN new.Type = 5 THEN 'object' ELSE 'array' END AS SQLDatatype, 70 | old.[id], 71 | old.[path] + CASE WHEN old.type = 5 THEN '.' + new.[Key] 72 | ELSE '[' + new.[Key] COLLATE DATABASE_DEFAULT + ']' END AS path 73 | -- SQL Prompt formatting on 74 | FROM @Unwrapped old 75 | CROSS APPLY OpenJson(old.[Value]) new 76 | WHERE old.[level] = @ii AND old.type IN (4, 5); 77 | SELECT @Rowcount = @@RowCount; 78 | SELECT @ii = @ii + 1; 79 | END; 80 | return 81 | END 82 | go -------------------------------------------------------------------------------- /ValidateViaJSONSchema.ps1: -------------------------------------------------------------------------------- 1 | $ErrorActionPreference = "Stop" 2 | # enter the base directory 3 | $Path = 'ThePathToTheData' 4 | # ...and the names of the subdirectories 5 | $SchemaDirectory = 'JSONSchema\' 6 | $DataDirectory = 'JSONData\' 7 | # all this following section thanks to James Newton-King 8 | $NewtonsoftJsonPath = Resolve-Path -Path "lib\Newtonsoft.Json.dll" 9 | $NewtonsoftJsonSchemaPath = Resolve-Path -Path "lib\Newtonsoft.Json.Schema.dll" 10 | 11 | Add-Type -Path $NewtonsoftJsonPath 12 | Add-Type -Path $NewtonsoftJsonSchemaPath 13 | 14 | 15 | # define the validator type 16 | $source = @' 17 | public class Validator 18 | { 19 | public static System.Collections.Generic.IList Validate(Newtonsoft.Json.Linq.JToken token, Newtonsoft.Json.Schema.JSchema schema) 20 | { 21 | System.Collections.Generic.IList messages; 22 | Newtonsoft.Json.Schema.SchemaExtensions.IsValid(token, schema, out messages); 23 | return messages; 24 | } 25 | } 26 | '@ 27 | Add-Type -TypeDefinition $source -ReferencedAssemblies $NewtonsoftJsonPath, $NewtonsoftJsonSchemaPath 28 | # end of James Newton-King's code. Thanks, James. 29 | 30 | Get-ChildItem "$($Path)\$($DataDirectory)" -Filter *.json | select Name | Foreach{ 31 | # do every file in the directory 32 | $JSON = [IO.File]::ReadAllText("$($Path)\$($DataDirectory)$($_.Name)") 33 | $Schema = [IO.File]::ReadAllText("$($Path)\$($SchemaDirectory)$($_.Name)") 34 | # parse the JSON files documents into a tokenised form 35 | $Token = [Newtonsoft.Json.Linq.JToken]::Parse($JSON) 36 | $Schema = [Newtonsoft.Json.Schema.JSchema]::Parse($Schema) 37 | # do the validation, using the parsed documents 38 | $ErrorMessages = [Validator]::Validate($Token, $Schema) 39 | if ($ErrorMessages.Count -eq 0) 40 | { write-host "Schema is valid" } #just for the test. I don't approve of write-host! 41 | else #I've selected just the first five because usually a whole column is wrong! 42 | { $ErrorMessages | Select-Object -First 5 | foreach{ write-warning $_ } } 43 | 44 | } --------------------------------------------------------------------------------