|
| 1 | +-- This SQL script is for old version of this API Consumer. |
| 2 | +-- It is used to re-install the assembly and stored procedures and functions. |
| 3 | +-- It is used to update the assembly to the new version. |
| 4 | +-- Cause of change by New version using IL-repack, so we need to re-install the assembly. |
| 5 | +-- also you can use this for install first time |
| 6 | + |
| 7 | + |
| 8 | +sp_configure 'show advanced options', 1; |
| 9 | +GO |
| 10 | +RECONFIGURE; |
| 11 | +GO |
| 12 | +sp_configure 'clr enabled', 1; |
| 13 | +GO |
| 14 | +RECONFIGURE; |
| 15 | +GO |
| 16 | +USE [master]; |
| 17 | +GO |
| 18 | +-- ============================================= |
| 19 | +-- Create a log table (temporary) |
| 20 | +-- ============================================= |
| 21 | +IF OBJECT_ID('tempdb..#ErrorLog') IS NOT NULL DROP TABLE #ErrorLog; |
| 22 | + |
| 23 | +CREATE TABLE #ErrorLog ( |
| 24 | + dbname NVARCHAR(128), |
| 25 | + error_message NVARCHAR(MAX), |
| 26 | + error_time DATETIME DEFAULT GETDATE() |
| 27 | +); |
| 28 | +-- ============================================= |
| 29 | +-- Define DLL Path |
| 30 | +-- ============================================= |
| 31 | +DECLARE @dll_path NVARCHAR(260) = N'C:\CLR\API_Consumer.dll'; -- <<<< SET YOUR PATH HERE |
| 32 | + |
| 33 | +-- ============================================= |
| 34 | +-- Trust the assembly file (at the instance level) |
| 35 | +-- ============================================= |
| 36 | +DECLARE @dynamic_sql NVARCHAR(MAX); |
| 37 | + |
| 38 | +SET @dynamic_sql = ' |
| 39 | + DECLARE @hash VARBINARY(64); |
| 40 | + SELECT @hash = HASHBYTES(''SHA2_512'', BulkColumn) |
| 41 | + FROM OPENROWSET(BULK ''' + @dll_path + ''', SINGLE_BLOB) AS x; |
| 42 | +
|
| 43 | + EXEC sys.sp_add_trusted_assembly @hash = @hash, @description = N''SecureLibrary-SQL Assembly''; |
| 44 | +'; |
| 45 | +EXEC(@dynamic_sql); |
| 46 | + |
| 47 | +-- ============================================= |
| 48 | +-- Loop through the target databases |
| 49 | +-- ============================================= |
| 50 | + |
| 51 | +DECLARE @databases TABLE (dbname NVARCHAR(128)); |
| 52 | +INSERT INTO @databases (dbname) |
| 53 | +VALUES ('db1'), ('db2'), ('db3'); -- <<<< PUT YOUR DATABASE NAMES HERE |
| 54 | + |
| 55 | +DECLARE @db NVARCHAR(128); |
| 56 | + |
| 57 | +DECLARE db_cursor CURSOR FOR |
| 58 | +SELECT dbname FROM @databases; |
| 59 | + |
| 60 | +OPEN db_cursor; |
| 61 | +FETCH NEXT FROM db_cursor INTO @db; |
| 62 | + |
| 63 | +WHILE @@FETCH_STATUS = 0 |
| 64 | +BEGIN |
| 65 | + BEGIN TRY |
| 66 | + -- Build dynamic SQL for each DB |
| 67 | + SET @dynamic_sql = ' |
| 68 | + USE [' + @db + ']; |
| 69 | +
|
| 70 | + -- ============================================= |
| 71 | + -- Drop dependent stored procedures and functions |
| 72 | + -- ============================================= |
| 73 | + IF OBJECT_ID(''[dbo].[APICaller_WebMethod]'') IS NOT NULL DROP PROCEDURE [dbo].[APICaller_WebMethod]; |
| 74 | + IF OBJECT_ID(''[dbo].[APICaller_Web_Extended]'') IS NOT NULL DROP PROCEDURE [dbo].[APICaller_Web_Extended]; |
| 75 | + IF OBJECT_ID(''[dbo].[APICaller_GET]'') IS NOT NULL DROP PROCEDURE [dbo].[APICaller_GET]; |
| 76 | + IF OBJECT_ID(''[dbo].[APICaller_POST]'') IS NOT NULL DROP PROCEDURE [dbo].[APICaller_POST]; |
| 77 | + IF OBJECT_ID(''[dbo].[APICaller_POSTAuth]'') IS NOT NULL DROP PROCEDURE [dbo].[APICaller_POSTAuth]; |
| 78 | + IF OBJECT_ID(''[dbo].[APICaller_GETAuth]'') IS NOT NULL DROP PROCEDURE [dbo].[APICaller_GETAuth]; |
| 79 | + IF OBJECT_ID(''[dbo].[APICaller_GET_Headers]'') IS NOT NULL DROP PROCEDURE [dbo].[APICaller_GET_Headers]; |
| 80 | + IF OBJECT_ID(''[dbo].[APICaller_GET_Headers_BODY]'') IS NOT NULL DROP PROCEDURE [dbo].[APICaller_GET_Headers_BODY]; |
| 81 | + IF OBJECT_ID(''[dbo].[APICaller_POST_Headers]'') IS NOT NULL DROP PROCEDURE [dbo].[APICaller_POST_Headers]; |
| 82 | + IF OBJECT_ID(''[dbo].[APICaller_POST_JsonBody_Header]'') IS NOT NULL DROP PROCEDURE [dbo].[APICaller_POST_JsonBody_Header]; |
| 83 | + IF OBJECT_ID(''[dbo].[APICaller_GET_Extended]'') IS NOT NULL DROP PROCEDURE [dbo].[APICaller_GET_Extended]; |
| 84 | + IF OBJECT_ID(''[dbo].[APICaller_POST_Extended]'') IS NOT NULL DROP PROCEDURE [dbo].[APICaller_POST_Extended]; |
| 85 | + IF OBJECT_ID(''[dbo].[APICaller_POST_Encoded]'') IS NOT NULL DROP PROCEDURE [dbo].[APICaller_POST_Encoded]; |
| 86 | +
|
| 87 | + IF OBJECT_ID(''[dbo].[Create_HMACSHA256]'') IS NOT NULL DROP FUNCTION [dbo].[Create_HMACSHA256]; |
| 88 | + IF OBJECT_ID(''[dbo].[GetTimestamp]'') IS NOT NULL DROP FUNCTION [dbo].[GetTimestamp]; |
| 89 | + IF OBJECT_ID(''[dbo].[fn_GetBytes]'') IS NOT NULL DROP FUNCTION [dbo].[fn_GetBytes]; |
| 90 | +
|
| 91 | + -- ============================================= |
| 92 | + -- Drop assemblies |
| 93 | + -- ============================================= |
| 94 | + IF EXISTS (SELECT * FROM sys.assemblies WHERE name = ''API_Consumer'') DROP ASSEMBLY [API_Consumer]; |
| 95 | + IF EXISTS (SELECT * FROM sys.assemblies WHERE name = ''Newtonsoft.Json'') DROP ASSEMBLY [Newtonsoft.Json]; |
| 96 | + IF EXISTS (SELECT * FROM sys.assemblies WHERE name = ''System.Runtime.Serialization'') DROP ASSEMBLY [System.Runtime.Serialization]; |
| 97 | + IF EXISTS (SELECT * FROM sys.assemblies WHERE name = ''SMDiagnostics'') DROP ASSEMBLY [SMDiagnostics]; |
| 98 | +
|
| 99 | + -- ============================================= |
| 100 | + -- Create the updated assembly |
| 101 | + -- ============================================= |
| 102 | + CREATE ASSEMBLY [API_Consumer] |
| 103 | + AUTHORIZATION dbo |
| 104 | + FROM ''' + @dll_path + ''' |
| 105 | + WITH PERMISSION_SET = UNSAFE; |
| 106 | +
|
| 107 | + -- ============================================= |
| 108 | + -- Recreate Procedures and Functions |
| 109 | + -- ============================================= |
| 110 | +
|
| 111 | + CREATE PROCEDURE [dbo].[APICaller_WebMethod] |
| 112 | + @httpMethod NVARCHAR(MAX) NULL, @URL NVARCHAR(MAX) NULL, @JsonBody NVARCHAR(MAX) NULL |
| 113 | + AS EXTERNAL NAME [API_Consumer].[StoredProcedures].[APICaller_WebMethod]; |
| 114 | +
|
| 115 | + CREATE PROCEDURE [dbo].[APICaller_Web_Extended] |
| 116 | + @httpMethod NVARCHAR(MAX) NULL, @URL NVARCHAR(MAX) NULL, @Headers NVARCHAR(MAX) NULL, @JsonBody NVARCHAR(MAX) NULL |
| 117 | + AS EXTERNAL NAME [API_Consumer].[StoredProcedures].[APICaller_Web_Extended]; |
| 118 | +
|
| 119 | + CREATE FUNCTION [dbo].[Create_HMACSHA256] |
| 120 | + (@message NVARCHAR(MAX) NULL, @SecretKey NVARCHAR(MAX) NULL) |
| 121 | + RETURNS NVARCHAR(MAX) |
| 122 | + AS EXTERNAL NAME [API_Consumer].[UserDefinedFunctions].[Create_HMACSHA256]; |
| 123 | +
|
| 124 | + CREATE FUNCTION [dbo].[GetTimestamp]() |
| 125 | + RETURNS NVARCHAR(MAX) |
| 126 | + AS EXTERNAL NAME [API_Consumer].[UserDefinedFunctions].[GetTimestamp]; |
| 127 | +
|
| 128 | + CREATE FUNCTION [dbo].[fn_GetBytes] |
| 129 | + (@value NVARCHAR(MAX) NULL) |
| 130 | + RETURNS NVARCHAR(MAX) |
| 131 | + AS EXTERNAL NAME [API_Consumer].[UserDefinedFunctions].[fn_GetBytes]; |
| 132 | +
|
| 133 | + CREATE PROCEDURE [dbo].[APICaller_GET] |
| 134 | + @URL NVARCHAR(MAX) NULL |
| 135 | + AS EXTERNAL NAME [API_Consumer].[StoredProcedures].[APICaller_GET]; |
| 136 | +
|
| 137 | + CREATE PROCEDURE [dbo].[APICaller_POST] |
| 138 | + @URL NVARCHAR(MAX) NULL, @JsonBody NVARCHAR(MAX) NULL |
| 139 | + AS EXTERNAL NAME [API_Consumer].[StoredProcedures].[APICaller_POST]; |
| 140 | +
|
| 141 | + CREATE PROCEDURE [dbo].[APICaller_POSTAuth] |
| 142 | + @URL NVARCHAR(MAX) NULL, @Token NVARCHAR(MAX) NULL, @JsonBody NVARCHAR(MAX) NULL |
| 143 | + AS EXTERNAL NAME [API_Consumer].[StoredProcedures].[APICaller_POST_Auth]; |
| 144 | +
|
| 145 | + CREATE PROCEDURE [dbo].[APICaller_GETAuth] |
| 146 | + @URL NVARCHAR(MAX) NULL, @Token NVARCHAR(MAX) NULL |
| 147 | + AS EXTERNAL NAME [API_Consumer].[StoredProcedures].[APICaller_GET_Auth]; |
| 148 | +
|
| 149 | + CREATE PROCEDURE [dbo].[APICaller_GET_Headers] |
| 150 | + @URL NVARCHAR(MAX) NULL, @Headers NVARCHAR(MAX) NULL |
| 151 | + AS EXTERNAL NAME [API_Consumer].[StoredProcedures].[APICaller_GET_Headers]; |
| 152 | +
|
| 153 | + CREATE PROCEDURE [dbo].[APICaller_GET_Headers_BODY] |
| 154 | + @URL NVARCHAR(MAX) NULL, @JsonBody NVARCHAR(MAX) NULL, @Headers NVARCHAR(MAX) NULL |
| 155 | + AS EXTERNAL NAME [API_Consumer].[StoredProcedures].APICaller_GET_JsonBody_Header; |
| 156 | +
|
| 157 | + CREATE PROCEDURE [dbo].[APICaller_POST_Headers] |
| 158 | + @URL NVARCHAR(MAX) NULL, @Headers NVARCHAR(MAX) NULL |
| 159 | + AS EXTERNAL NAME [API_Consumer].[StoredProcedures].APICaller_POST_Headers; |
| 160 | +
|
| 161 | + CREATE PROCEDURE [dbo].[APICaller_POST_JsonBody_Header] |
| 162 | + @URL NVARCHAR(MAX), @Headers NVARCHAR(MAX), @jSON NVARCHAR(MAX) |
| 163 | + AS EXTERNAL NAME [API_Consumer].[StoredProcedures].APICaller_POST_JsonBody_Headers; |
| 164 | +
|
| 165 | + CREATE PROCEDURE [dbo].[APICaller_GET_Extended] |
| 166 | + @URL NVARCHAR(MAX) NULL, @JsonBody NVARCHAR(MAX) NULL, @Headers NVARCHAR(MAX) NULL |
| 167 | + AS EXTERNAL NAME [API_Consumer].[StoredProcedures].[APICaller_GET_Extended]; |
| 168 | +
|
| 169 | + CREATE PROCEDURE [dbo].[APICaller_POST_Extended] |
| 170 | + @URL NVARCHAR(MAX) NULL, @Headers NVARCHAR(MAX) NULL, @JsonBody NVARCHAR(MAX) NULL |
| 171 | + AS EXTERNAL NAME [API_Consumer].[StoredProcedures].[APICaller_POST_Extended]; |
| 172 | +
|
| 173 | + CREATE PROCEDURE [dbo].[APICaller_POST_Encoded] |
| 174 | + @URL NVARCHAR(MAX) NULL, @Headers NVARCHAR(MAX) NULL, @JsonBody NVARCHAR(MAX) NULL |
| 175 | + AS EXTERNAL NAME [API_Consumer].[StoredProcedures].APICaller_POST_Encoded; |
| 176 | + '; |
| 177 | + |
| 178 | + EXEC sp_executesql @dynamic_sql; |
| 179 | + END TRY |
| 180 | + BEGIN CATCH |
| 181 | + -- Log the error |
| 182 | + INSERT INTO #ErrorLog (dbname, error_message) |
| 183 | + VALUES (@db, ERROR_MESSAGE()); |
| 184 | + END CATCH; |
| 185 | + |
| 186 | + FETCH NEXT FROM db_cursor INTO @db; |
| 187 | +END |
| 188 | + |
| 189 | +CLOSE db_cursor; |
| 190 | +DEALLOCATE db_cursor; |
| 191 | + |
| 192 | +-- ============================================= |
| 193 | +-- See Errors if any |
| 194 | +-- ============================================= |
| 195 | +SELECT * FROM #ErrorLog; |
0 commit comments