├── .github └── FUNDING.yml ├── .gitmodules ├── README.md ├── audit └── DatabaseSchemaAudit.sql ├── docs ├── DatabaseSnapshotBriefUsage.txt └── HideDatabaseListFromAUser.txt ├── external-script └── python │ ├── MoneyToWord.sql │ └── PipInstall.sql ├── ftp ├── FtpDownload-CMD.sql ├── FtpDownload-Python.sql └── FtpDownload-WinSCP.sql ├── maintenance ├── ChangeDbObjectCollation.sql ├── CreateReaderDBU.sql ├── DbExec.sql ├── KillAllDatabaseProcesses.sql ├── MaintenanceDBBackup.sql ├── MaintenanceDBRestoreFromSnapshot.sql ├── MaintenanceDBSnapshot.sql ├── MaintenanceRebuildIndexes.sql ├── PurgeDbData.sql ├── Script-CheckIndexes.sql ├── batch │ └── run-MaintenanceDBBackup.bat ├── sp_whoisactive.sql └── who_is_active_v11_32.zip ├── operator └── Div.sql ├── query-store └── DoQueryStore.sql ├── script-generation ├── GetCRUD.sql ├── GetCreateIndex.sql ├── GetDropIndex.sql ├── GetGRANT.sql ├── GetInsert-Less2016.sql ├── GetInsert.sql └── GetInsert_MongoShell.sql ├── security └── GetSqlLoginDetails.sql ├── string ├── Base642String.sql ├── CharIndexWithQuotes.sql ├── GetNthWord.sql ├── GetRandomSentence.sql ├── GetRandomString.sql ├── RegexRemove.sql ├── ReplaceManyToSingle.sql ├── SplitString-less2016.sql ├── SplitString.sql ├── String2Base64.sql └── Trim.sql ├── utility ├── CompareTableSchema.sql ├── DateAddBusinessDays.sql ├── FileExists.sql ├── FindStringData.sql ├── GetAllDatesInMonth.sql ├── GetCalendar.sql ├── GetDFColumns.sql ├── GetFakeJSON.sql ├── GetFilesInFolder.sql ├── GetFirstResultSchema.sql ├── GetHierachicalTables.sql ├── GetObjectDependencies.sql ├── GetPKColumns.sql ├── GetRandomDate.sql ├── GetRandomNumber.sql ├── GetTableSize.sql ├── IsIdentityColumn.sql └── Script-FakeDataGeneration.sql └── web-call ├── API.sql ├── ApiCovid19.sql ├── GetHttpRequest.sql └── async ├── APIAsync.sql ├── GetResponseAsync.sql └── SendAsync.sql /.github/FUNDING.yml: -------------------------------------------------------------------------------- 1 | # These are supported funding model platforms 2 | custom: ['paypal.me/datnguyenit09'] 3 | -------------------------------------------------------------------------------- /.gitmodules: -------------------------------------------------------------------------------- 1 | [submodule "mssql-num2words"] 2 | path = mssql-num2words 3 | url = https://github.com/datnguye/mssql-num2words 4 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # SQL-Server 2 | 3 | 4 | Placing all SQL stored procedures, functions or script to make life easier for SQL Server Developer 5 | 6 | In case that you'd have requests for me to do something, feel free to send it via my personal email: datnguyen.it09@gmail.com 7 | -------------------------------------------------------------------------------- /audit/DatabaseSchemaAudit.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: Trigger database schema changes 3 | -- Notes: Recommend to create agent job to regurlarly clean up Audit table 4 | -- History: 5 | -- Date Author Description 6 | -- 2019-05-29 DN Intial 7 | --====================================================== 8 | /* 9 | --Pre-condition 10 | DROP TABLE IF EXISTS dbo.SystemDDLAudit 11 | GO 12 | CREATE TABLE dbo.SystemDDLAudit 13 | ( 14 | EventType nvarchar(256), 15 | SchemaName nvarchar(256), 16 | ObjectName nvarchar(256), 17 | SqlCommand nvarchar(MAX), 18 | EventXml XML, 19 | IpAddress nvarchar(256), 20 | HostName nvarchar(256), 21 | AppName nvarchar(256), 22 | NetTransport nvarchar(256), 23 | ProtocolType nvarchar(256), 24 | AuthScheme nvarchar(256), 25 | LocalNetAddress nvarchar(256), 26 | LocalTcpPort nvarchar(256), 27 | PhysicalNetTransport nvarchar(256), 28 | Principal nvarchar(256), 29 | LoginToken XML, 30 | [User] nvarchar(256), 31 | CurrentUser nvarchar(256), 32 | SessionUser nvarchar(256), 33 | SystemUser nvarchar(256), 34 | UserName nvarchar(256), 35 | SuserName nvarchar(256), 36 | SuserSname nvarchar(256), 37 | OriginalLogin nvarchar(256), 38 | IsSysadmin bit, 39 | IsDbOwner bit, 40 | IsDdlAdmin bit, 41 | IsDbDatareader bit, 42 | MachineName nvarchar(256), 43 | InstanceName nvarchar(256), 44 | ServerName nvarchar(256), 45 | NetbiosName nvarchar(256), 46 | DatabaseName nvarchar(256), 47 | EventTimestamp DateTime CONSTRAINT DFSystemDDLAuditEventTimestamp DEFAULT(GETDATE()) 48 | ) 49 | GO 50 | */ 51 | DROP TRIGGER IF EXISTS DatabaseSchemaAudit ON DATABASE 52 | GO 53 | CREATE TRIGGER DatabaseSchemaAudit ON DATABASE 54 | FOR 55 | CREATE_USER, ALTER_USER, DROP_USER, 56 | CREATE_SCHEMA, ALTER_SCHEMA, DROP_SCHEMA, 57 | CREATE_TABLE, ALTER_TABLE, DROP_TABLE, 58 | CREATE_VIEW, ALTER_VIEW, DROP_VIEW, 59 | CREATE_PROCEDURE, ALTER_PROCEDURE, DROP_PROCEDURE, 60 | CREATE_FUNCTION, ALTER_FUNCTION, DROP_FUNCTION, 61 | CREATE_TRIGGER, ALTER_TRIGGER, DROP_TRIGGER, 62 | CREATE_TYPE, DROP_TYPE, 63 | CREATE_INDEX, ALTER_INDEX, DROP_INDEX, 64 | CREATE_QUEUE, ALTER_QUEUE, DROP_QUEUE, 65 | RENAME 66 | AS 67 | BEGIN 68 | SET NOCOUNT ON; 69 | 70 | IF NOT EXISTS(SELECT TOP 1 1 FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_SCHEMA = 'dbo' AND TABLE_NAME = 'SystemDDLAudit') 71 | RETURN; 72 | 73 | DECLARE @EventData XML = EVENTDATA(); 74 | DECLARE @LoginToken XML; 75 | DECLARE @OperationPrincipal nvarchar(256); 76 | 77 | SET @LoginToken = 78 | ( 79 | SELECT lt.* 80 | FROM sys.login_token AS lt 81 | JOIN sys.server_principals AS sp 82 | ON lt.principal_id = sp.principal_id 83 | WHERE lt.name NOT IN (SELECT name FROM sys.database_principals WHERE type = 'R' AND name IS NOT NULL) 84 | AND lt.name IS NOT NULL 85 | AND sp.type <> 'R' 86 | ORDER BY lt.name 87 | FOR XML PATH(''), ROOT ('token') 88 | ) 89 | SET @OperationPrincipal = 90 | ( 91 | SELECT TOP 1 p.NameNode.value('.', 'nvarchar(256)') 92 | FROM @LoginToken.nodes('//name') AS p(NameNode) 93 | ORDER BY 1 94 | ); 95 | 96 | INSERT 97 | INTO dbo.SystemDDLAudit 98 | SELECT -- Did what ? 99 | @EventData.value('(/EVENT_INSTANCE/EventType)[1]', 'nvarchar(256)') AS EventType, 100 | @EventData.value('(/EVENT_INSTANCE/SchemaName)[1]', 'nvarchar(256)') AS SchemaName, 101 | @EventData.value('(/EVENT_INSTANCE/ObjectName)[1]', 'nvarchar(256)') AS ObjectName, 102 | @EventData.value('(/EVENT_INSTANCE/TSQLCommand)[1]', 'nvarchar(MAX)') AS SqlCommand, 103 | @EventData AS EventXml, 104 | 105 | -- Where from ? 106 | CONVERT(nvarchar(256),CONNECTIONPROPERTY('client_net_address')) AS IpAddress, 107 | HOST_NAME() AS HostName, 108 | APP_NAME() AS AppName, 109 | CONVERT(nvarchar(256),CONNECTIONPROPERTY('net_transport')) AS NetTransport, 110 | CONVERT(nvarchar(256),CONNECTIONPROPERTY('protocol_type')) AS ProtocolType, 111 | CONVERT(nvarchar(256),CONNECTIONPROPERTY('auth_scheme')) AS AuthScheme, 112 | CONVERT(nvarchar(256),CONNECTIONPROPERTY('local_net_address')) AS LocalNetAddress, 113 | CONVERT(nvarchar(256),CONNECTIONPROPERTY('local_tcp_port')) AS LocalTcpPort, 114 | CONVERT(nvarchar(256),CONNECTIONPROPERTY('physical_net_transport')) AS PhysicalNetTransport, 115 | 116 | -- Who did it ? 117 | @OperationPrincipal AS Principal, 118 | @LoginToken AS LoginToken, 119 | USER, 120 | CURRENT_USER AS CurrentUser, 121 | SESSION_USER AS SessionUser, 122 | SYSTEM_USER AS SystemUser, 123 | USER_NAME() AS UserName, 124 | SUSER_NAME() AS SuserName, 125 | SUSER_SNAME() AS SuserSname, 126 | ORIGINAL_LOGIN() AS OriginalLogin, 127 | 128 | -- What rights did said person have ? 129 | CONVERT(nvarchar(256),IS_SRVROLEMEMBER('sysadmin')) AS IsSysadmin, 130 | CONVERT(nvarchar(256),IS_MEMBER('db_owner')) AS IsDbOwner, 131 | CONVERT(nvarchar(256),IS_MEMBER('db_ddladmin')) AS IsDdlAdmin, 132 | CONVERT(nvarchar(256),IS_MEMBER('db_datareader')) AS IsDbDatareader, 133 | 134 | -- On which server was this done ? 135 | CONVERT(nvarchar(256),SERVERPROPERTY(N'MachineName')) AS MachineName, 136 | CONVERT(nvarchar(256),SERVERPROPERTY(N'InstanceName')) AS InstanceName, 137 | CONVERT(nvarchar(256),SERVERPROPERTY(N'ServerName')) AS ServerName, 138 | CONVERT(nvarchar(256),SERVERPROPERTY(N'ComputerNamePhysicalNetBIOS')) AS NetbiosName, 139 | DB_NAME() AS DatabaseName, 140 | 141 | --When 142 | GETDATE() 143 | 144 | WHERE @EventData.value('(/EVENT_INSTANCE/EventType)[1]', 'nvarchar(256)') IS NOT NULL 145 | AND @EventData.value('(/EVENT_INSTANCE/TSQLCommand)[1]', 'nvarchar(MAX)') IS NOT NULL 146 | AND 147 | ( 148 | 1 = 1 --// PUT YOUR EXTRA EXLUSION HERE // 149 | ) 150 | END 151 | GO 152 | 153 | /* 154 | TRUNCATE TABLE SystemDDLAudit 155 | GO 156 | DROP TABLE IF EXISTS test1 157 | GO 158 | CREATE TABLE test1 (id int) 159 | GO 160 | SELECT * 161 | FROM SystemDDLAudit 162 | GO 163 | */ -------------------------------------------------------------------------------- /docs/DatabaseSnapshotBriefUsage.txt: -------------------------------------------------------------------------------- 1 | Basic view of Database Snapshots (SQL Server) 2 | Available from SQL 2016 SP1 or later 3 | Docs: https://docs.microsoft.com/en-us/sql/relational-databases/databases/database-snapshots-sql-server 4 | 5 | Where should to use: 6 | + Locally develop a feature: Easily revert database state from a snapshot 7 | + Testing environment: Useful when repeatedly running each round of testing. Restore from a snapshot that is much quick than restoring from a backup) 8 | + Reporting purposes: Snapshot working as a copy of source database but read-only 9 | 10 | Limitations as some: 11 | + Double up database size so disk space issue may occur 12 | + Snapshot must be remaining on the same server instance as the source database 13 | + Snapshot is dependent on source database. If source database is not available, all its snapshot will be not available too 14 | + Database cannot be dropped if any snapshots existing 15 | 16 | Usage: 17 | + Generate new database snapshot: 18 | USE your_db 19 | GO 20 | EXEC MaintenanceDBSnapshot @LiveRun = 1 21 | ref: https://github.com/datnguye/SQL-Server/blob/master/maintenance/MaintenanceDBSnapshot.sql 22 | 23 | + Restore snapshot to revert the source database to the time of snapshot creation: 24 | USE master 25 | GO 26 | EXEC MaintenanceDBRestoreFromSnapshot @DbName = 'your_db', @FromSnapshot = 'your_db-SNAPSHOT-date-time', @LiveRun = 1 27 | ref: https://github.com/datnguye/SQL-Server/blob/master/maintenance/MaintenanceDBRestoreFromSnapshot.sql -------------------------------------------------------------------------------- /docs/HideDatabaseListFromAUser.txt: -------------------------------------------------------------------------------- 1 | --1. Deny db view to public 2 | USE MASTER 3 | GO 4 | DENY VIEW ANY DATABASE TO PUBLIC 5 | GO 6 | --2. Create your login need stuffing (skip if existed already) 7 | CREATE LOGIN 'example_login' WITH PASSWORD = 'Y0ursT0on9p@@sworD' 8 | GO 9 | --3. Assign db owner to the login 10 | USE YOUR_DB 11 | GO 12 | EXEC sp_changedbowner 'example_login' 13 | GO 14 | --Done. 15 | 16 | --To revert what you did: 17 | --GRANT VIEW ANY DATABASE TO PUBLIC; 18 | --GO 19 | --USE YOUR_DB 20 | --GO 21 | --EXEC sp_changedbowner 'sa'--or whatever login you would like to 22 | --GO 23 | --USE master 24 | --GO 25 | --DROP LOGIN 'example_login' -------------------------------------------------------------------------------- /external-script/python/MoneyToWord.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: To have ability to convert money to text 3 | -- with utilizing python in SQL 4 | -- Notes: 5 | -- Parameters: 6 | -- History: 7 | -- Date Author Description 8 | -- 2020-08-21 DN Intial 9 | --====================================================== 10 | DROP PROCEDURE IF EXISTS MoneyToWord 11 | GO 12 | CREATE PROCEDURE [dbo].MoneyToWord @Money float = 0,--It does not support decimal type unfortunately 13 | @Lang varchar(3) = 'en' 14 | AS 15 | BEGIN 16 | SET NOCOUNT ON; 17 | DECLARE @vTemp TABLE (MoneyInText nvarchar(MAX)) 18 | 19 | INSERT INTO @vTemp(MoneyInText) 20 | EXECUTE sp_execute_external_script 21 | @language = N'Python', 22 | @script = N' 23 | from num2words import num2words 24 | import pandas 25 | 26 | in_dists = pandas.DataFrame(input) 27 | dists = [str(num2words(number=in_dists.iloc[0].MoneyValue, lang=in_dists.iloc[0].Lang))] 28 | results = pandas.DataFrame(dists) 29 | ' 30 | , @input_data_1 = N'SELECT @vMoneyValue as MoneyValue, @vLang as Lang' 31 | , @input_data_1_name = N'input' 32 | , @output_data_1_name = N'results' 33 | , @params = N'@vMoneyValue float, @vLang varchar(10)' 34 | , @vMoneyValue = @Money 35 | , @vLang = @Lang 36 | 37 | SELECT * 38 | FROM @vTemp 39 | ORDER BY 1 40 | END 41 | GO 42 | /* 43 | 1. Install module num2words 44 | EXEC PipInstall @Module = 'num2words'--run once to install num2words pip package 45 | 46 | Sample output as below 47 | 2020-08-21 10:10:46.947- Starting installing python module: num2words 48 | STDOUT message(s) from external script: 49 | 3.7.1 (default, Dec 10 2018, 22:54:23) [MSC v.1915 64 bit (AMD64)] 50 | 2020-08-21 10:10:53.977- PYTHON_SERVICES path: C:\Program Files\Microsoft SQL Server\MSSQL15.DAT19\PYTHON_SERVICES 51 | 2020-08-21 10:10:53.980- pip command: C: & cd "C:\Program Files\Microsoft SQL Server\MSSQL15.DAT19\PYTHON_SERVICES" & "Scripts\pip.exe" install num2words 52 | 2020-08-21 10:11:03.633- To remove this module, please try with: C: & cd "C:\Program Files\Microsoft SQL Server\MSSQL15.DAT19\PYTHON_SERVICES" & "Scripts\pip.exe" uninstall num2words 53 | 2020-08-21 10:11:04.137- SUCCESSFULLY installed: num2words 0.5.10 54 | 2020-08-21 10:11:04.137- Finished 55 | 56 | Completion time: 2020-08-21T10:11:04.1711011+07:00 57 | 58 | 59 | 2. ENJOY! 60 | EXEC MoneyToWord @Money = 550001.27 61 | EXEC MoneyToWord @Money = 550001.27, @Lang = 'vi' 62 | EXEC MoneyToWord @Money = 550001.27, @Lang = 'th' 63 | */ 64 | -------------------------------------------------------------------------------- /external-script/python/PipInstall.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: To perform pip install command 3 | -- Notes: 4 | -- Parameters: 5 | -- History: 6 | -- Date Author Description 7 | -- 2020-05-29 DN Intial 8 | --====================================================== 9 | DROP PROCEDURE IF EXISTS PipInstall 10 | GO 11 | CREATE PROCEDURE [dbo].PipInstall @Module nvarchar(255) 12 | AS 13 | BEGIN 14 | SET NOCOUNT ON 15 | 16 | DECLARE @vCommand nvarchar(4000) 17 | DECLARE @vMessage nvarchar(MAX) 18 | 19 | DECLARE @vSystemPath TABLE (SystemPath nvarchar(255)) 20 | DECLARE @vPackageInstalled TABLE (PackageName nvarchar(255)) 21 | DECLARE @vPythonServicePath nvarchar(255) 22 | DECLARE @vPackageName nvarchar(255) 23 | 24 | --Required options enabled 25 | DECLARE @vXpCmdShellInfo TABLE (name sysname, minimum int, maximum int, config_value int, run_value int) 26 | INSERT INTO @vXpCmdShellInfo EXEC sp_configure 'xp_cmdshell' 27 | IF (SELECT run_value FROM @vXpCmdShellInfo) = 0 28 | BEGIN 29 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- ERROR: xp_cmdshell is being disabled. Please help to run EXEC sp_configure ''xp_cmdshell'', 1'' to fix it.' 30 | RAISERROR(@vMessage,0,1) 31 | 32 | RETURN -1; 33 | END 34 | 35 | DECLARE @vExternalScriptEnabledInfo TABLE (name sysname, minimum int, maximum int, config_value int, run_value int) 36 | INSERT INTO @vExternalScriptEnabledInfo EXEC sp_configure 'external scripts enabled' 37 | IF (SELECT run_value FROM @vExternalScriptEnabledInfo) = 0 38 | BEGIN 39 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- ERROR: sp_execute_external_script is being disabled. Please help to run EXEC sp_configure ''external scripts enabled'', 1'' to fix it.' 40 | RAISERROR(@vMessage,0,1) 41 | 42 | RETURN -1; 43 | END 44 | 45 | --Printing python version 46 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- Starting installing python module: ' + @Module 47 | RAISERROR(@vMessage,0,1) 48 | EXECUTE sp_execute_external_script @language = N'Python' 49 | , @script = N' 50 | import sys 51 | print(sys.version)' 52 | 53 | --Getting SQL Server's PYTHON_SERVICES path 54 | INSERT 55 | INTO @vSystemPath 56 | EXECUTE sp_execute_external_script 57 | @language =N'Python', 58 | @script=N' 59 | import sys 60 | import pandas 61 | Results = pandas.DataFrame(sys.path)', 62 | @output_data_1_name = N'Results' 63 | 64 | SET @vPythonServicePath = 65 | ( 66 | SELECT TOP 1 SystemPath 67 | FROM @vSystemPath 68 | WHERE SystemPath LIKE '%\PYTHON_SERVICES%' 69 | ORDER BY 1 70 | ) 71 | IF @vPythonServicePath IS NOT NULL 72 | BEGIN 73 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- PYTHON_SERVICES path: ' + @vPythonServicePath 74 | RAISERROR(@vMessage,0,1) 75 | END 76 | ELSE 77 | BEGIN 78 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- ERROR: PYTHON_SERVICES path could not be found!' 79 | RAISERROR(@vMessage,0,1) 80 | 81 | RETURN -1; 82 | END 83 | 84 | --Build pip command and run it 85 | SET @vCommand = LEFT(@vPythonServicePath,2) + ' & cd "' + @vPythonServicePath + '" & "Scripts\pip.exe" install ' + @Module 86 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- pip command: ' + @vCommand 87 | RAISERROR(@vMessage,0,1) 88 | 89 | EXEC xp_cmdshell @vCommand, no_output 90 | 91 | SET @vCommand = LEFT(@vPythonServicePath,2) + ' & cd "' + @vPythonServicePath + '" & "Scripts\pip.exe" uninstall ' + @Module 92 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- To remove this module, please try with: ' + @vCommand 93 | RAISERROR(@vMessage,0,1) 94 | 95 | 96 | --Verify packages installed 97 | INSERT 98 | INTO @vPackageInstalled (PackageName) 99 | EXECUTE sp_execute_external_script @language = N'Python' 100 | , @script = N' 101 | import pkg_resources 102 | import pandas 103 | dists = [str(d) for d in pkg_resources.working_set] 104 | Results = pandas.DataFrame(dists)', 105 | @output_data_1_name = N'Results' 106 | 107 | SELECT @vPackageName = PackageName 108 | FROM @vPackageInstalled 109 | WHERE PackageName LIKE @Module + '%' 110 | IF @vPackageName IS NOT NULL 111 | BEGIN 112 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- SUCCESSFULLY installed: ' + @vPackageName 113 | RAISERROR(@vMessage,0,1) 114 | END 115 | ELSE 116 | BEGIN 117 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- ERROR: Module has not been installed yet. Please help to try with command in cmd to verify!' 118 | RAISERROR(@vMessage,0,1) 119 | 120 | RETURN -1; 121 | END 122 | 123 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- Finished' 124 | RAISERROR(@vMessage,0,1) 125 | 126 | RETURN 127 | END 128 | GO 129 | /* 130 | EXEC PipInstall @Module = 'BeautifulSoup4' 131 | */ 132 | 133 | /* 134 | EXEC sp_configure 'external scripts enabled', 1 135 | RECONFIGURE 136 | GO 137 | EXECUTE sp_execute_external_script 138 | @language =N'Python', 139 | @script=N' 140 | import sys 141 | import pandas 142 | OutputDataSet = pandas.DataFrame(sys.path)', 143 | @input_data_1 = N'' 144 | WITH RESULT SETS(([RecordText] nvarchar(4000))); 145 | 146 | EXECUTE sp_execute_external_script @language = N'Python' 147 | , @script = N' 148 | import pkg_resources 149 | import pandas 150 | dists = [str(d) for d in pkg_resources.working_set] 151 | OutputDataSet = pandas.DataFrame(dists)' 152 | WITH RESULT SETS(([Package] NVARCHAR(max))) 153 | GO 154 | 155 | */ 156 | -------------------------------------------------------------------------------- /ftp/FtpDownload-CMD.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: FtpDownload using native cmd shell 3 | -- Notes: xp_cmdshell needs enabling 4 | -- EXEC sp_configure 'xp_cmdshell', 1 5 | -- RECONFIGURE; 6 | -- Parameters: 7 | -- History: 8 | -- Date Author Description 9 | -- 2020-06-14 DN Intial 10 | --====================================================== 11 | DROP PROCEDURE IF EXISTS FtpDownload 12 | GO 13 | CREATE PROCEDURE [dbo].[FtpDownload] @FtpFolder nvarchar(255) = '/', 14 | @FtpFileName nvarchar(255), 15 | @FtpHost nvarchar(255), 16 | @FtpUser nvarchar(255), 17 | @FtpPassword nvarchar(255), 18 | @LocalFolder nvarchar(255) = 'C:\Temp\' 19 | AS 20 | BEGIN 21 | SET NOCOUNT ON 22 | DECLARE @vMessage nvarchar(MAX) 23 | DECLARE @vCommand nvarchar(4000) 24 | DECLARE @RunFileName nvarchar(255) = 'FtpDownload_RUN.txt' 25 | DECLARE @vReturnCode INT = 0 26 | 27 | IF RIGHT(@FtpFolder,1) <> '/' SET @FtpFolder += '/' 28 | IF RIGHT(@LocalFolder,1) <> '\' AND RIGHT(@LocalFolder,1) <> '/' SET @LocalFolder += '\' 29 | SET @RunFileName = @LocalFolder + @RunFileName 30 | 31 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Starting FTP download files from: ' + @FtpHost + ' - with user: ' + @FtpUser 32 | RAISERROR(@vMessage,0,1) 33 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Remote folder: ' + @FtpFolder 34 | RAISERROR(@vMessage,0,1) 35 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Local folder: ' + @LocalFolder 36 | RAISERROR(@vMessage,0,1) 37 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' File: ' + @FtpFileName 38 | RAISERROR(@vMessage,0,1) 39 | 40 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Creating run file under: ' + @RunFileName 41 | RAISERROR(@vMessage,0,1) 42 | SET @vCommand = 'echo open ' + @FtpHost + ' > ' + @RunFileName 43 | EXEC @vReturnCode = master..xp_cmdshell @vCommand, no_output 44 | IF @vReturnCode <> 0 GOTO EXCEPTION 45 | 46 | SET @vCommand = 'echo ' + @FtpUser + '>> "' + @RunFileName + '"' 47 | EXEC @vReturnCode = master..xp_cmdshell @vCommand, no_output 48 | IF @vReturnCode <> 0 GOTO EXCEPTION 49 | 50 | SET @vCommand = 'echo ' + @FtpPassword + '>> "' + @RunFileName + '"' 51 | EXEC @vReturnCode = master..xp_cmdshell @vCommand, no_output 52 | IF @vReturnCode <> 0 GOTO EXCEPTION 53 | 54 | SET @vCommand = 'echo get "' + @FtpFolder + @FtpFileName + '" "' + @LocalFolder + @FtpFileName + '" >> "' + @RunFileName + '"' 55 | EXEC @vReturnCode = master..xp_cmdshell @vCommand, no_output 56 | IF @vReturnCode <> 0 GOTO EXCEPTION 57 | 58 | SET @vCommand = 'echo quit >> "' + @RunFileName + '"' 59 | EXEC @vReturnCode = master..xp_cmdshell @vCommand, no_output 60 | IF @vReturnCode <> 0 GOTO EXCEPTION 61 | 62 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Start running' 63 | RAISERROR(@vMessage,0,1) 64 | SET @vCommand = 'ftp -s:"' + @RunFileName + '"' 65 | RAISERROR(@vCommand,0,1) 66 | EXEC @vReturnCode = master..xp_cmdshell @vCommand 67 | IF @vReturnCode <> 0 GOTO EXCEPTION 68 | 69 | IF @vReturnCode = 0 GOTO DONE 70 | EXCEPTION: 71 | BEGIN 72 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Something wrong happened' 73 | RAISERROR(@vMessage,16,1) 74 | 75 | RETURN -1 76 | END 77 | 78 | DONE: 79 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Finished' 80 | RAISERROR(@vMessage,0,1) 81 | 82 | RETURN 83 | END 84 | GO 85 | /* 86 | EXEC dbo.FtpDownload @FtpHost='localhost', @FtpUser='ftpuser', @FtpPassword='ftpuser', 87 | @FtpFolder = '/', @LocalFolder = 'C:\Temp', 88 | @FtpFileName = 'Countries-20200614-090721.sql' 89 | */ 90 | 91 | 92 | -------------------------------------------------------------------------------- /ftp/FtpDownload-Python.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: FtpDownload using Python code 3 | -- Notes: 4 | -- Parameters: 5 | -- History: 6 | -- Date Author Description 7 | -- 2020-06-14 DN Intial 8 | --====================================================== 9 | DROP PROCEDURE IF EXISTS FtpDownload 10 | GO 11 | CREATE PROCEDURE [dbo].[FtpDownload] @FtpFolder nvarchar(255) = '/', 12 | @FtpFileMask nvarchar(255) = '*', 13 | @FtpHost nvarchar(255), 14 | @FtpUser nvarchar(255), 15 | @FtpPassword nvarchar(255), 16 | @LocalFolder nvarchar(255) = 'C:\Temp\' 17 | AS 18 | BEGIN 19 | SET NOCOUNT ON 20 | DECLARE @vMessage nvarchar(MAX) 21 | DECLARE @vCommand nvarchar(4000) 22 | DECLARE @vReturnCode INT = 0 23 | 24 | IF RIGHT(@FtpFolder,1) <> '/' SET @FtpFolder += '/' 25 | IF RIGHT(@LocalFolder,1) <> '\' AND RIGHT(@LocalFolder,1) <> '/' SET @LocalFolder += '\' 26 | 27 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Starting FTP download files from: ' + @FtpHost + ' - with user: ' + @FtpUser 28 | RAISERROR(@vMessage,0,1) 29 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Remote folder: ' + @FtpFolder 30 | RAISERROR(@vMessage,0,1) 31 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Local folder: ' + @LocalFolder 32 | RAISERROR(@vMessage,0,1) 33 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' File(s): ' + @FtpFileMask 34 | RAISERROR(@vMessage,0,1) 35 | 36 | SET @vCommand = N' 37 | from ftplib import FTP 38 | import fnmatch as fm 39 | 40 | ftp = FTP() 41 | 42 | ftp.connect(host="' + @FtpHost + N'") 43 | ftp.login(user="' + @FtpUser + N'", passwd="' + @FtpPassword + N'") 44 | 45 | ftp.cwd("' + @FtpFolder + N'") 46 | 47 | files = ftp.nlst() 48 | files = (file for file in files if fm.fnmatch(file, "' + @FtpFileMask + N'")) 49 | 50 | for file in files: 51 | print(f"Downloading {file}") 52 | with open("' + REPLACE(@LocalFolder,'\','\\') + N'" + file, "wb") as fp: 53 | ftp.retrbinary("RETR " + file, fp.write) 54 | 55 | ftp.quit() 56 | print("Done")' 57 | 58 | --PRINT @vCommand 59 | EXEC @vReturnCode = sp_execute_external_script 60 | @language =N'Python', 61 | @script= @vCommand 62 | 63 | IF @vReturnCode <> 0 64 | BEGIN 65 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Something wrong happened. Please help to review message log' 66 | RAISERROR(@vMessage,16,1) 67 | 68 | RETURN -1 69 | END 70 | 71 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Finished' 72 | RAISERROR(@vMessage,0,1) 73 | 74 | RETURN 75 | END 76 | GO 77 | /* 78 | EXEC dbo.FtpDownload @FtpHost='localhost', @FtpUser='ftpuser', @FtpPassword='ftpuser', @FtpFolder = '/', 79 | @LocalFolder = 'C:\Temp' 80 | */ 81 | 82 | 83 | -------------------------------------------------------------------------------- /ftp/FtpDownload-WinSCP.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: FtpDownload using WinSCP 3 | -- Notes: xp_cmdshell needs enabling 4 | -- EXEC sp_configure 'xp_cmdshell', 1 5 | -- RECONFIGURE; 6 | -- Parameters: 7 | -- History: 8 | -- Date Author Description 9 | -- 2020-06-14 DN Intial 10 | --====================================================== 11 | DROP PROCEDURE IF EXISTS FtpDownload 12 | GO 13 | CREATE PROCEDURE [dbo].[FtpDownload] @FtpFolder nvarchar(255) = '/', 14 | @FtpFileMask nvarchar(255) = '*', 15 | @FtpHost nvarchar(255), 16 | @FtpUser nvarchar(255), 17 | @FtpPassword nvarchar(255), 18 | @LocalFolder nvarchar(255) = 'C:\Temp\', 19 | @WinSCPFolder nvarchar(255) = 'C:\Program Files (x86)\WinSCP\', 20 | @LogFolder nvarchar(255) = NULL 21 | AS 22 | BEGIN 23 | SET NOCOUNT ON 24 | DECLARE @vMessage nvarchar(MAX) 25 | DECLARE @vCommand nvarchar(4000) 26 | DECLARE @LogFileName nvarchar(255) = 'FtpDownload_log_' + FORMAT(GETDATE(),'_yyyyMMdd_HHmmss') + '.log' 27 | DECLARE @vReturnCode INT = 0 28 | 29 | IF RIGHT(@FtpFolder,1) <> '/' SET @FtpFolder += '/' 30 | IF RIGHT(@LocalFolder,1) <> '\' AND RIGHT(@LocalFolder,1) <> '/' SET @LocalFolder += '\' 31 | IF @LogFolder IS NULL SET @LogFolder = @LocalFolder 32 | 33 | SET @LogFileName = @LocalFolder + @LogFileName 34 | 35 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Starting FTP download files from: ' + @FtpHost + ' - with user: ' + @FtpUser 36 | RAISERROR(@vMessage,0,1) 37 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Remote folder: ' + @FtpFolder 38 | RAISERROR(@vMessage,0,1) 39 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Local folder: ' + @LocalFolder 40 | RAISERROR(@vMessage,0,1) 41 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' File(s): ' + @FtpFileMask 42 | RAISERROR(@vMessage,0,1) 43 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Log: ' + @LogFileName 44 | RAISERROR(@vMessage,0,1) 45 | 46 | SET @vCommand = LEFT(@LocalFolder,2) + 47 | ' & cd "' + @LocalFolder + '"' + 48 | ' & "' + @WinSCPFolder + 'WinSCP.com" /log="' + @LogFileName + '" /command ' + 49 | '"open ftp://' + @FtpUser + ':' + @FtpPassword + '@' + @FtpHost + '" ' + 50 | '"get ""' + @FtpFolder + '*"" -filemask=' + @FtpFileMask + '" "exit"' 51 | 52 | EXEC @vReturnCode = master..xp_cmdshell @vCommand, no_output 53 | 54 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Command used: ' 55 | RAISERROR(@vMessage,0,1) 56 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' ' + @vCommand 57 | RAISERROR(@vMessage,0,1) 58 | IF @vReturnCode <> 0 59 | BEGIN 60 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Something wrong happened. Please help to review log: ' + @LogFileName 61 | RAISERROR(@vMessage,16,1) 62 | 63 | RETURN -1 64 | END 65 | 66 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+' Finished' 67 | RAISERROR(@vMessage,0,1) 68 | 69 | RETURN 70 | END 71 | GO 72 | /* 73 | EXEC dbo.FtpDownload @FtpHost='localhost', @FtpUser='ftpuser', @FtpPassword='ftpuser', 74 | @FtpFolder = '/', @LocalFolder = 'C:\Temp' 75 | 76 | EXEC dbo.FtpDownload @FtpHost='localhost', @FtpUser='ftpuser', @FtpPassword='ftpuser', @FtpFileMask = '*-20200614-090721.sql', 77 | @FtpFolder = '/', @LocalFolder = 'C:\Temp' 78 | 79 | EXEC dbo.FtpDownload @FtpHost='localhost', @FtpUser='ftpuser', @FtpPassword='ftpuser', @FtpFileMask = 'Countries-20200614-090721.sql', 80 | @FtpFolder = '/', @LocalFolder = 'C:\Temp' 81 | */ 82 | 83 | 84 | -------------------------------------------------------------------------------- /maintenance/ChangeDbObjectCollation.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: ChangeDbObjectCollation 3 | -- Notes: Dependencies ON /script-generation/GetCreate[Drop]Index functions 4 | -- Parameters: 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-05-17 DN Intial 8 | --====================================================== 9 | DROP PROCEDURE IF EXISTS [ChangeDbObjectCollation] 10 | GO 11 | CREATE PROCEDURE [dbo].[ChangeDbObjectCollation] @CurrentCollation nvarchar(255), 12 | @NewCollation nvarchar(255), 13 | @SupressInfoMessages bit = 0 14 | AS 15 | BEGIN 16 | SET NOCOUNT ON 17 | 18 | DECLARE @vMessage nvarchar(max) 19 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Starting collation re-definition procedure.' 20 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 21 | 22 | IF @CurrentCollation IS NULL 23 | OR NOT EXISTS (SELECT 1 FROM fn_helpcollations() WHERE name = @CurrentCollation) 24 | BEGIN 25 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Collation '+Coalesce(@CurrentCollation,'(NULL)')+' does NOT exist.' 26 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 27 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Collation re-definition procedure completed WITH error.' 28 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 29 | 30 | RETURN 31 | END 32 | 33 | IF NOT EXISTS (SELECT 1 FROM sys.databases WHERE database_id = DB_ID() AND collation_name = @NewCollation) 34 | BEGIN 35 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' New collation '+Coalesce(@NewCollation,'(NULL)')+' is not database collation. The changes could not be affected!.' 36 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 37 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Try to change database collation firstly:' 38 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 39 | SET @vMessage = 'USE master' + CHAR(10) 40 | SET @vMessage += 'GO' + CHAR(10) 41 | SET @vMessage += 'ALTER DATABASE ' + QUOTENAME(DB_NAME()) + CHAR(10) 42 | SET @vMessage += 'SET SINGLE_USER WITH ROLLBACK IMMEDIATE' + CHAR(10) 43 | SET @vMessage += 'GO' + CHAR(10) 44 | SET @vMessage += 'ALTER DATABASE ' + QUOTENAME(DB_NAME()) + CHAR(10) 45 | SET @vMessage += 'COLLATE ' + @NewCollation + CHAR(10) 46 | SET @vMessage += 'GO' + CHAR(10) 47 | SET @vMessage += 'ALTER DATABASE ' + QUOTENAME(DB_NAME()) + CHAR(10) 48 | SET @vMessage += 'SET MULTI_USER WITH ROLLBACK IMMEDIATE' + CHAR(10) 49 | SET @vMessage += 'GO' + CHAR(10) 50 | 51 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 52 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Collation re-definition procedure completed WITH error.' 53 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 54 | 55 | RETURN 56 | END 57 | 58 | DECLARE @vConstraintName nvarchar(256) 59 | DECLARE @vSQLStatement nvarchar(max) 60 | DECLARE @vIsPrimaryKey bit 61 | DECLARE @vIsForeignKey bit 62 | DECLARE @vTableName nvarchar(256) 63 | DECLARE @vColumnName nvarchar(256) 64 | DECLARE @vObjectName nvarchar(512) 65 | DECLARE @vIsNullable nvarchar(10) 66 | DECLARE @vPrincipalName nvarchar(256) 67 | DECLARE @vPermissionType nvarchar(256) 68 | DECLARE @vPermissionScope nvarchar(256) 69 | IF (@NewCollation = @CurrentCollation) 70 | BEGIN 71 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Old collation IS the same as the existing database collation.' 72 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 73 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Collation re-definition procedure completed WITH error.' 74 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 75 | RETURN 76 | END 77 | 78 | DECLARE @t_IndexList Table (Index_Name nvarchar(256),Is_Primary_Key bit,Is_Foreign_Key bit,Drop_Statement nvarchar(1024),Create_Statement nvarchar(max)) 79 | DECLARE @t_ColumnList Table (Table_Schema nvarchar(256),Table_Name nvarchar(256),Column_Name nvarchar(256), Is_Nullable nvarchar(10)) 80 | DECLARE @t_ObjectList Table (Object_Schema nvarchar(256),Object_Name nvarchar(256), Object_Drop_Statement nvarchar(1024), Object_Definition nvarchar(max),Original_Object_ID bigint) 81 | DECLARE @t_ViewList Table (View_Schema nvarchar(256),View_Name nvarchar(256), View_Drop_Statement nvarchar(1024), View_Definition nvarchar(max),Original_Object_ID bigint) 82 | DECLARE @t_PermissionList Table (Original_Object_ID bigint, Permission_Grant_Statement nvarchar(1024), Object_Name nvarchar(256),Database_Principal nvarchar(256), Permission_Type nvarchar(256), Permission_Scope nvarchar(256)) 83 | 84 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Database objects will be changed FROM collation ['+@CurrentCollation+'] to ['+@NewCollation+'].' 85 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 86 | 87 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Getting list of constraints referencing columns of the requested collation' 88 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 89 | INSERT 90 | INTO @t_IndexList 91 | SELECT DISTINCT 92 | SI.Name, 93 | SI.Is_Primary_Key, 94 | 0, 95 | dbo.GetDropIndex(SI.Object_ID, SI.Name), 96 | dbo.GetCreateIndex(SI.Object_ID, SI.Name) 97 | FROM sys.Indexes SI 98 | JOIN sys.Objects SO 99 | ON SO.Object_ID = SI.Object_ID 100 | AND SO.Is_MS_Shipped = 0 101 | JOIN sys.Index_Columns SIC 102 | ON SIC.Index_ID = SI.Index_ID 103 | AND SIC.Object_ID = SI.Object_ID 104 | JOIN sys.Columns SC 105 | ON SC.Column_ID = SIC.Column_ID 106 | AND SC.Object_ID = SIC.Object_ID 107 | AND SC.Collation_Name = @CurrentCollation 108 | UNION 109 | SELECT DISTINCT 110 | SI.Name, 111 | SI.Is_Primary_Key, 112 | 0, 113 | dbo.GetDropIndex(SI.Object_ID, SI.Name), 114 | dbo.GetCreateIndex(SI.Object_ID, SI.Name) 115 | FROM sys.Indexes SI 116 | JOIN sys.Objects SO 117 | ON SO.Object_ID = SI.Object_ID 118 | AND SO.Is_MS_Shipped = 0 119 | WHERE SI.Has_Filter = 1 120 | UNION 121 | SELECT DISTINCT 122 | FK.Name, 123 | 0, 124 | 1, 125 | dbo.GetDropIndex(FK.Object_ID,FK.Name), 126 | dbo.GetCreateIndex(FK.Object_ID,FK.Name) 127 | FROM sys.Foreign_Keys FK 128 | JOIN sys.Objects SO 129 | ON SO.Object_ID = FK.Object_ID 130 | AND SO.Is_MS_Shipped = 0 131 | JOIN sys.Foreign_Key_Columns FKC 132 | ON FKC.Constraint_Object_ID = FK.Object_ID 133 | JOIN sys.Columns SC 134 | ON SC.Object_ID = FKC.Referenced_Object_ID 135 | AND SC.Column_ID = FKC.Referenced_Column_ID 136 | AND SC.Collation_Name = @CurrentCollation 137 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' '+Cast(@@RowCount as nvarchar)+' constraints found.' 138 | IF (@SupressInfoMessages = 0) RAISERROR(@vMessage, 0, 1) WITH NOWAIT 139 | 140 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Getting list of columns of the requested collation.' 141 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 142 | INSERT 143 | INTO @t_ColumnList 144 | SELECT ISC.Table_Schema, 145 | ISC.Table_Name, 146 | ISC.Column_Name, 147 | ISC.Is_Nullable 148 | FROM Information_Schema.Columns ISC 149 | JOIN Information_Schema.Tables IST 150 | ON IST.Table_Name = ISC.Table_Name 151 | AND IST.Table_Schema = ISC.Table_Schema 152 | AND IST.Table_Type <> 'VIEW' 153 | WHERE ISC.Collation_Name = @CurrentCollation 154 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' '+Cast(@@RowCount as nvarchar)+' columns found.' 155 | IF (@SupressInfoMessages = 0) RAISERROR(@vMessage, 0, 1) WITH NOWAIT 156 | 157 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Getting a list of routines.' 158 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 159 | INSERT 160 | INTO @t_ObjectList 161 | SELECT Object_Schema_Name(SO.Object_ID), 162 | Object_Name(SO.Object_ID), 163 | Case 164 | When SO.Type = 'P' Then 'DROP PROCEDURE ['+Object_Schema_Name(SO.Object_ID)+'].['+Object_Name(SO.Object_ID)+']' 165 | When SO.Type In ('FN','IF','TF') Then 'DROP FUNCTION ['+Object_Schema_Name(SO.Object_ID)+'].['+Object_Name(SO.Object_ID)+']' 166 | When SO.Type In ('TR') Then 'DROP TRIGGER ['+Object_Schema_Name(SO.Object_ID)+'].['+Object_Name(SO.Object_ID)+']' 167 | END, 168 | SM.Definition, 169 | SO.Object_ID 170 | FROM sys.SQL_Modules SM 171 | JOIN sys.Objects SO 172 | ON SO.Object_ID = SM.Object_ID 173 | AND SO.Is_MS_Shipped = 0 174 | WHERE Object_Name(SO.Object_ID) <> 'ChangeDbObjectCollation' 175 | AND Object_Name(SO.Object_ID) <> 'Change_User_Defined_Type_Definition' 176 | AND Object_Name(SO.Object_ID) <> 'PadString' 177 | AND Object_Name(SO.Object_ID) <> 'GetDropIndex' 178 | AND Object_Name(SO.Object_ID) <> 'GetCreateIndex' 179 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' '+Cast(@@Rowcount as nvarchar)+' routines found.' 180 | IF (@SupressInfoMessages = 0) RAISERROR(@vMessage, 0, 1) WITH NOWAIT 181 | 182 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Getting a list of views.' 183 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 184 | INSERT 185 | INTO @t_ViewList 186 | SELECT DISTINCT 187 | VCU.View_Schema, 188 | VCU.View_Name, 189 | 'DROP VIEW ['+VCU.View_Schema+'].['+VCU.View_Name+']', 190 | SM.Definition, 191 | SO.Object_ID 192 | FROM Information_Schema.View_Column_Usage VCU 193 | JOIN @t_ColumnList CL 194 | ON CL.Table_Name = VCU.Table_Name 195 | AND CL.Column_Name = VCU.Column_Name 196 | JOIN sys.Objects SO 197 | ON SO.Name = VCU.View_Name 198 | AND Object_Schema_Name(SO.Object_ID) = VCU.View_Schema 199 | JOIN sys.SQL_Modules SM 200 | ON SM.Object_ID = SO.Object_ID 201 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' '+Cast(@@Rowcount as nvarchar)+' views found.' 202 | IF (@SupressInfoMessages = 0) RAISERROR(@vMessage, 0, 1) WITH NOWAIT 203 | 204 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Getting a list of permission assignments ON objects that will be removed.' 205 | IF (@SupressInfoMessages = 0) RAISERROR(@vMessage, 0, 1) WITH NOWAIT 206 | INSERT 207 | INTO @t_PermissionList 208 | SELECT Original_Object_ID, 209 | State_Desc Collate Latin1_General_CI_AS+' '+Permission_Name Collate Latin1_General_CI_AS+' ON ['+Object_Schema_Name(SO.Object_ID)+'].['+Object_Name(SO.Object_ID)+'] TO '+ DP.Name Collate Latin1_General_CI_AS, 210 | '['+Object_Schema_Name(SO.Object_ID)+'].['+Object_Name(SO.Object_ID)+']', 211 | DP.Name, 212 | Upper(Substring(State_Desc,1,1))+Lower(Substring(State_Desc,2,256)), 213 | Permission_Name 214 | FROM @t_ObjectList OL 215 | JOIN sys.Database_Permissions DPE 216 | ON DPE.Major_ID = OL.Original_Object_ID 217 | JOIN sys.Objects SO 218 | ON SO.Object_ID = OL.Original_Object_ID 219 | JOIN sys.Database_Principals DP 220 | ON DP.Principal_ID = DPE.Grantee_Principal_ID 221 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' '+Cast(@@Rowcount as nvarchar)+' permissions located.' 222 | IF (@SupressInfoMessages = 0) RAISERROR(@vMessage, 0, 1) WITH NOWAIT 223 | 224 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Removing existing constraints.' 225 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 226 | DECLARE c_DropConstraints CURSOR FOR 227 | SELECT Index_Name, 228 | Drop_Statement, 229 | Is_Primary_Key, 230 | Is_Foreign_Key 231 | FROM @t_IndexList 232 | ORDER BY Is_Foreign_Key Desc, 233 | Is_Primary_Key Asc, 234 | Index_Name Asc 235 | OPEN c_DropConstraints 236 | FETCH NEXT FROM c_DropConstraints INTO @vConstraintName, @vSQLStatement, @vIsPrimaryKey, @vIsForeignKey 237 | While @@Fetch_Status = 0 238 | BEGIN 239 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Removing constraint '+@vConstraintName+'.' 240 | IF (@SupressInfoMessages = 0) RAISERROR(@vMessage, 0, 1) WITH NOWAIT 241 | BEGIN TRY 242 | Exec sp_ExecuteSQL @vSQLStatement 243 | END TRY 244 | BEGIN CATCH 245 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Removal of constraint '+@vConstraintName+' failed due to "'+Error_Message()+'".' 246 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 247 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' '+@vSQLStatement 248 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 249 | END CATCH 250 | FETCH NEXT FROM c_DropConstraints INTO @vConstraintName, @vSQLStatement, @vIsPrimaryKey, @vIsForeignKey 251 | END 252 | CLOSE c_DropConstraints 253 | DEALLOCATE c_DropConstraints 254 | 255 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Removing routines.' 256 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 257 | DECLARE c_Routines CURSOR FOR 258 | SELECT '['+Object_Schema+'].['+Object_Name+']', 259 | Object_Drop_Statement 260 | FROM @t_ObjectList 261 | WHERE Object_Drop_Statement IS NOT NULL 262 | ORDER BY Object_Name 263 | OPEN c_Routines 264 | FETCH NEXT FROM c_Routines INTO @vObjectName, @vSQLStatement 265 | While @@Fetch_Status = 0 266 | BEGIN 267 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Removing routine '+@vObjectName+'. '+@vSQLStatement 268 | IF (@SupressInfoMessages = 0) RAISERROR(@vMessage, 0, 1) WITH NOWAIT 269 | BEGIN TRY 270 | Exec sp_ExecuteSQL @vSQLStatement 271 | END TRY 272 | BEGIN CATCH 273 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Removal of routine '+@vObjectName+' failed due to "'+Error_Message()+'".' 274 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 275 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' '+@vSQLStatement 276 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 277 | END CATCH 278 | FETCH NEXT FROM c_Routines INTO @vObjectName, @vSQLStatement 279 | END 280 | CLOSE c_Routines 281 | DEALLOCATE c_Routines 282 | 283 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Removing views.' 284 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 285 | DECLARE c_Views CURSOR FOR 286 | SELECT '['+View_Schema+'].['+View_Name+']', 287 | View_Drop_Statement 288 | FROM @t_ViewList 289 | OPEN c_Views 290 | FETCH NEXT FROM c_Views INTO @vObjectName, @vSQLStatement 291 | While @@Fetch_Status = 0 292 | BEGIN 293 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Removing view '+@vObjectName+'.' 294 | IF (@SupressInfoMessages = 0) RAISERROR(@vMessage, 0, 1) WITH NOWAIT 295 | BEGIN TRY 296 | Exec sp_ExecuteSQL @vSQLStatement 297 | END TRY 298 | BEGIN CATCH 299 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Removal of view '+@vObjectName+' failed due to "'+Error_Message()+'".' 300 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 301 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' '+@vSQLStatement 302 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 303 | END CATCH 304 | FETCH NEXT FROM c_Views INTO @vObjectName, @vSQLStatement 305 | END 306 | CLOSE c_Views 307 | DEALLOCATE c_Views 308 | 309 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Resetting columns.' 310 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 311 | DECLARE c_Columns CURSOR FOR 312 | SELECT '['+ISC.Table_Schema+'].['+ISC.Table_Name+']', 313 | ISC.Column_Name, 314 | 'ALTER TABLE '+'['+ISC.Table_Schema+'].['+ISC.Table_Name+'] ALTER COLUMN ['+ISC.Column_Name+'] '+ 315 | Coalesce(ISC.Domain_Name,ISC.Data_Type+Coalesce(Case when ISC.Data_Type = 'text' Then '' else NULL END,'('+Case When ISC.Character_Maximum_Length < 0 Then 'Max' Else Cast(ISC.Character_Maximum_Length As nvarchar) END+')'))+ 316 | Case When ISC.Is_Nullable = 'NO' Then ' NOT NULL' Else ' NULL' END 317 | FROM @t_ColumnList CL 318 | JOIN Information_Schema.Columns ISC 319 | ON ISC.Table_Name = CL.Table_Name 320 | AND ISC.Column_Name = CL.Column_Name 321 | ORDER BY ISC.Table_Name Asc, 322 | ISC.Column_Name Asc 323 | OPEN c_Columns 324 | FETCH NEXT FROM c_Columns INTO @vTableName, @vColumnName, @vSQLStatement 325 | While @@Fetch_Status = 0 326 | BEGIN 327 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Changing column '+@vColumnName+' ON table '+@vTableName+'.' 328 | IF (@SupressInfoMessages = 0) RAISERROR(@vMessage, 0, 1) WITH NOWAIT 329 | BEGIN TRY 330 | Exec sp_ExecuteSQL @vSQLStatement 331 | END TRY 332 | BEGIN CATCH 333 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Column change of '+@vColumnName+' ON table '+@vTableName+' failed due to "'+Error_Message()+'".' 334 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 335 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' '+@vSQLStatement 336 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 337 | END CATCH 338 | FETCH NEXT FROM c_Columns INTO @vTableName, @vColumnName, @vSQLStatement 339 | END 340 | CLOSE c_Columns 341 | DEALLOCATE c_Columns 342 | 343 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Re-creating constraints.' 344 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 345 | DECLARE c_CreateConstraints CURSOR FOR 346 | SELECT Index_Name, 347 | Create_Statement, 348 | Is_Primary_Key, 349 | Is_Foreign_Key 350 | FROM @t_IndexList 351 | ORDER BY Is_Primary_Key Desc, 352 | Is_Foreign_Key Asc, 353 | Index_Name Desc 354 | OPEN c_CreateConstraints 355 | FETCH NEXT FROM c_CreateConstraints INTO @vConstraintName, @vSQLStatement, @vIsPrimaryKey, @vIsForeignKey 356 | While @@Fetch_Status = 0 357 | BEGIN 358 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Creating constraint '+@vConstraintName+'.' 359 | IF (@SupressInfoMessages = 0) RAISERROR(@vMessage, 0, 1) WITH NOWAIT 360 | BEGIN TRY 361 | Exec sp_ExecuteSQL @vSQLStatement 362 | END TRY 363 | BEGIN CATCH 364 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Contraint recreation of '+@vConstraintName+' failed due to "'+Error_Message()+'". ['+@vSQLStatement+']' 365 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 366 | END CATCH 367 | FETCH NEXT FROM c_CreateConstraints INTO @vConstraintName, @vSQLStatement, @vIsPrimaryKey, @vIsForeignKey 368 | END 369 | CLOSE c_CreateConstraints 370 | DEALLOCATE c_CreateConstraints 371 | 372 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Recreating routines.' 373 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 374 | DECLARE c_Routines CURSOR FOR 375 | SELECT '['+Object_Schema+'].['+Object_Name+']', 376 | Object_Definition 377 | FROM @t_ObjectList 378 | WHERE Object_Drop_Statement IS NOT NULL 379 | ORDER BY Object_Name 380 | OPEN c_Routines 381 | FETCH NEXT FROM c_Routines INTO @vObjectName, @vSQLStatement 382 | While @@Fetch_Status = 0 383 | BEGIN 384 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Creating routine '+@vObjectName+'.' 385 | IF (@SupressInfoMessages = 0) RAISERROR(@vMessage, 0, 1) WITH NOWAIT 386 | BEGIN TRY 387 | Exec sp_ExecuteSQL @vSQLStatement 388 | END TRY 389 | BEGIN CATCH 390 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Routine recreation of '+@vObjectName+' failed due to "'+Error_Message()+'".' 391 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 392 | END CATCH 393 | FETCH NEXT FROM c_Routines INTO @vObjectName, @vSQLStatement 394 | END 395 | CLOSE c_Routines 396 | DEALLOCATE c_Routines 397 | 398 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Recreating views.' 399 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 400 | DECLARE c_Views CURSOR FOR 401 | SELECT '['+View_Schema+'].['+View_Name+']', 402 | View_Definition 403 | FROM @t_ViewList 404 | OPEN c_Views 405 | FETCH NEXT FROM c_Views INTO @vObjectName, @vSQLStatement 406 | While @@Fetch_Status = 0 407 | BEGIN 408 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Creating view '+@vObjectName+'.' 409 | IF (@SupressInfoMessages = 0) RAISERROR(@vMessage, 0, 1) WITH NOWAIT 410 | BEGIN TRY 411 | Exec sp_ExecuteSQL @vSQLStatement 412 | END TRY 413 | BEGIN CATCH 414 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' View recreation of '+@vObjectName+' failed due to "'+Error_Message()+'".' 415 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 416 | END CATCH 417 | FETCH NEXT FROM c_Views INTO @vObjectName, @vSQLStatement 418 | END 419 | CLOSE c_Views 420 | DEALLOCATE c_Views 421 | 422 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Re-applying permissions ON re-created objects.' 423 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 424 | DECLARE c_Permissions CURSOR FOR 425 | SELECT Object_Name, 426 | Permission_Grant_Statement, 427 | Database_Principal, 428 | Permission_Type, 429 | Permission_Scope 430 | FROM @t_PermissionList 431 | ORDER BY Object_Name, 432 | Database_Principal 433 | OPEN c_Permissions 434 | FETCH NEXT FROM c_Permissions INTO @vObjectName, @vSQLStatement, @vPrincipalName, @vPermissionType, @vPermissionScope 435 | While @@Fetch_Status = 0 436 | BEGIN 437 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' '+@vPermissionType+'ing '+Lower(@vPermissionScope)+' permission for '+@vPrincipalName+' ON object '+@vObjectName+'.' 438 | IF (@SupressInfoMessages = 0) RAISERROR(@vMessage, 0, 1) WITH NOWAIT 439 | BEGIN TRY 440 | Exec sp_ExecuteSQL @vSQLStatement 441 | END TRY 442 | BEGIN CATCH 443 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Permission setting ON '+@vObjectName+' failed for principal '+@vPrincipalName+' due to "'+Error_Message()+'". ['+@vSQLStatement+']' 444 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 445 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' '+@vSQLStatement 446 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 447 | END CATCH 448 | FETCH NEXT FROM c_Permissions INTO @vObjectName, @vSQLStatement, @vPrincipalName, @vPermissionType, @vPermissionScope 449 | END 450 | CLOSE c_Permissions 451 | DEALLOCATE c_Permissions 452 | 453 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+' Collation re-definition procedure complete.' 454 | RAISERROR(@vMessage, 0, 1) WITH NOWAIT 455 | 456 | SET NOCOUNT Off 457 | RETURN 458 | END 459 | /* 460 | EXEC [dbo].[ChangeDbObjectCollation] @CurrentCollation = 'SQL_Latin1_General_CP1_CI_AS', 461 | @NewCollation = 'Latin1_General_CI_AS', 462 | @SupressInfoMessages = 0 463 | */ -------------------------------------------------------------------------------- /maintenance/CreateReaderDBU.sql: -------------------------------------------------------------------------------- 1 | --========================================================================================================= 2 | -- Usage: This is to create a SQL login with reader right and can view only assigned database in a instance 3 | -- Notes: USE WITH CAUTION: it drops server login by default 4 | -- Must have grantor login to run this sproc 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-05-21 DN Intial 8 | --========================================================================================================== 9 | --use master; 10 | DROP PROCEDURE IF EXISTS CreateReaderDBU 11 | GO 12 | 13 | CREATE PROCEDURE CreateReaderDBU @LoginName sysname, 14 | @LoginPassword sysname, 15 | @AssignedToDatabase sysname, 16 | @DropLoginIfExists bit = 1, 17 | @Debug bit = 0 --1 to return script content only 18 | AS 19 | BEGIN 20 | SET NOCOUNT ON; 21 | 22 | DECLARE @vSQL nvarchar(4000) = '' 23 | DECLARE @EndLiner varchar(2) = char(10) 24 | 25 | --Drop database user if exists 26 | SET @vSQL += 'use [{dbname}];'+@EndLiner 27 | SET @vSQL += 'IF EXISTS ( SELECT TOP 1 1 FROM sys.sysusers WHERE name = ''{loginname}'' AND islogin = 1)'+@EndLiner 28 | SET @vSQL += 'BEGIN'+@EndLiner 29 | SET @vSQL += ' DROP USER {loginname}'+@EndLiner 30 | SET @vSQL += 'END;'+@EndLiner 31 | 32 | 33 | --Drop server login if exists 34 | IF @DropLoginIfExists = 1 35 | BEGIN 36 | SET @vSQL += 'use master;'+@EndLiner 37 | SET @vSQL += 'IF EXISTS ( SELECT TOP 1 1 FROM sys.syslogins WHERE name = ''{loginname}'' AND dbname = ''{dbname}'')'+@EndLiner 38 | SET @vSQL += 'BEGIN'+@EndLiner 39 | SET @vSQL += ' DROP LOGIN {loginname}'+@EndLiner 40 | SET @vSQL += 'END;'+@EndLiner 41 | END 42 | 43 | --Create server login (set default database and deny view any database) 44 | IF @DropLoginIfExists = 1 45 | BEGIN 46 | SET @vSQL += 'use master;'+@EndLiner 47 | SET @vSQL += 'CREATE LOGIN {loginname} WITH PASSWORD = ''{loginpassword}'', DEFAULT_DATABASE=[{dbname}], CHECK_POLICY = OFF;'+@EndLiner 48 | SET @vSQL += 'DENY VIEW ANY DATABASE TO {loginname};'+@EndLiner 49 | END 50 | 51 | --Create database user and database role 52 | SET @vSQL += 'use [{dbname}];'+@EndLiner 53 | SET @vSQL += 'CREATE USER {loginname} FOR LOGIN {loginname};'+@EndLiner 54 | SET @vSQL += 'ALTER ROLE db_datareader ADD MEMBER {loginname};'+@EndLiner 55 | 56 | 57 | --INPUT 58 | SET @vSQL = REPLACE(REPLACE(REPLACE( 59 | @vSQL, 60 | '{loginname}',@LoginName), 61 | '{loginpassword}',@LoginPassword), 62 | '{dbname}',@AssignedToDatabase) 63 | 64 | --OUTPUT / RESULT 65 | IF @Debug = 0 66 | BEGIN 67 | BEGIN TRY 68 | EXEC(@vSQL) 69 | SELECT @LoginName AS CreatedUser, @LoginPassword AS [Password], @AssignedToDatabase AS [Database] 70 | END TRY 71 | BEGIN CATCH 72 | SELECT ERROR_NUMBER() AS ErrorNumber, 73 | ERROR_SEVERITY() AS ErrorSeverity, 74 | ERROR_STATE() AS ErrorState, 75 | ERROR_PROCEDURE() AS ErrorProcedure, 76 | ERROR_LINE() AS ErrorLine, 77 | ERROR_MESSAGE() AS ErrorMessage 78 | END CATCH 79 | END 80 | ELSE 81 | BEGIN 82 | PRINT @vSQL 83 | END 84 | 85 | RETURN; 86 | END 87 | GO 88 | /* 89 | EXEC CreateReaderDBU @LoginName = 'test02', @LoginPassword = 'test02pwd', @AssignedToDatabase = 'Test', @Debug = 1 90 | EXEC CreateReaderDBU @LoginName = 'test02', @LoginPassword = 'test02pwd', @AssignedToDatabase = 'Test', @Debug = 0 91 | */ -------------------------------------------------------------------------------- /maintenance/DbExec.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: Execute SQL script (in file) accross databases 3 | -- Notes: Recommend to release to master database 4 | -- Recommend to have dbowner database role for all databases to be accessing to 5 | -- xp_cmdshell option enabled for usage of SQL File Path 6 | -- Parameters: 7 | -- @SQL: SQL Text or file path containing SQL text to get run (Mandatory) 8 | -- IF it is file path, log file to be ouput 9 | -- @DBNamePattern: To filter list of database by database name. Set % to run all 10 | -- @Where: To filter list of databases to be running. 11 | -- Applicable for database scope ONLY. 12 | -- Must be valid as Boolean_Expression of IF statement. 13 | -- @FailedAtOne: If Failed at one database then stop whole process 14 | -- @LiveRun: Turn to 1 to have REAL execution, otherwise log output only 15 | -- 16 | -- History: 17 | -- Date Author Description 18 | -- 2019-05-21 DN Intial 19 | --====================================================== 20 | --use master; 21 | DROP PROCEDURE IF EXISTS DbExec 22 | GO 23 | 24 | CREATE PROCEDURE DbExec @SQL nvarchar(max), 25 | @DbNamePattern sysname = '%', 26 | @Where nvarchar(4000) = NULL, 27 | @FailedAtOne Bit = 1, 28 | @SQLInstanceName sysname = NULL, 29 | @SQLLoginName sysname = NULL, 30 | @SQLPassword sysname = NULL, 31 | @LiveRun bit = 1 32 | AS 33 | BEGIN 34 | SET NOCOUNT ON; 35 | 36 | DECLARE @vCommand nvarchar(4000) 37 | DECLARE @vExecFromFile Bit = 0 38 | Declare @vDBName nvarchar(256) 39 | 40 | DECLARE @vCmdOutput TABLE (content char(256)) 41 | 42 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- Starting executing...' 43 | --1. Validation 44 | IF PATINDEX('[A-Za-z]:\%', @SQL) = 1 OR PATINDEX('\\%', @SQL) = 1 45 | BEGIN 46 | SET @vExecFromFile = 1 47 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- SQL taken from file path: '+@SQL 48 | END 49 | 50 | IF @vExecFromFile = 1 51 | BEGIN 52 | DECLARE @vCmdShellInfo TABLE (name sysname, minimum int, maximum int, config_value int, run_value int) 53 | INSERT INTO @vCmdShellInfo EXEC sp_configure 'xp_cmdshell' 54 | IF (SELECT run_value FROM @vCmdShellInfo) = 0 55 | BEGIN 56 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- ERROR: xp_cmdshell is being disabled. Please help to run EXEC sp_configure ''xp_cmdshell'', 1'' to fix it.' 57 | RETURN -1; 58 | END 59 | 60 | SET @vCommand = 'IF EXIST "'+@SQL+'" (echo 1) ELSE (echo 0)' 61 | INSERT INTO @vCmdOutput EXEC xp_cmdshell @vCommand 62 | IF (SELECT content FROM @vCmdOutput WHERE content IS NOT NULL) = '0' 63 | BEGIN 64 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- ERROR: File does not exists - '+@SQL 65 | RETURN -1; 66 | END 67 | END 68 | 69 | --2. Get list of databases 70 | -- For each db, call execution. If failed at one database, process will stop at that point at all. 71 | DECLARE db_cursor CURSOR FOR 72 | SELECT name 73 | FROM sys.databases 74 | WHERE database_id > 4 75 | AND state = 0 76 | AND name LIKE @DbNamePattern 77 | 78 | OPEN db_cursor 79 | FETCH NEXT FROM db_cursor INTO @vDBName 80 | 81 | WHILE @@FETCH_STATUS = 0 82 | BEGIN 83 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- Processing '+QUOTENAME(@vDBName)+'...' 84 | BEGIN TRY 85 | IF @Where IS NOT NULL 86 | BEGIN 87 | DELETE FROM @vCmdOutput 88 | SET @vCommand = 'Use '+QUOTENAME(@vDBName)+';IF '+@Where+' SELECT 1 ELSE SELECT 0' 89 | INSERT INTO @vCmdOutput EXEC(@vCommand) 90 | IF (SELECT content FROM @vCmdOutput) = 0 91 | BEGIN 92 | PRINT CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+QUOTENAME(@vDBName)+' does not sastify WHERE parameter. SKIPPED!' 93 | GOTO DBSKIP 94 | END 95 | END 96 | 97 | IF @vExecFromFile = 1 98 | BEGIN 99 | Set @vCommand = 'sqlcmd' 100 | +' -S "'+Coalesce(@SQLInstanceName,@@ServerName)+'" '--Server Name 101 | + (CASE WHEN @SQLLoginName IS NULL THEN ' -E ' ELSE '' END) --Trusted Connection 102 | +' -d "'+@vDBName+'"' --Database Name 103 | +(CASE WHEN @SQLLoginName IS NOT NULL THEN ' -U '+@SQLLoginName ELSE '' END) --Login Name 104 | +(CASE WHEN @SQLLoginName IS NOT NULL THEN ' -P '+@SQLPassword ELSE '' END) --Password 105 | +' -i "'+@SQL+'"' --input file 106 | +' -o "'+Replace(@SQL,'.sql','-'+@vDBName+FORMAT(GETDATE(),'-yyyyMMdd')+'.log"') --output file 107 | IF @LiveRun = 0 PRINT @vCommand ELSE Exec xp_cmdshell @vCommand, no_output 108 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- Output under: '+Replace(@SQL,'.sql','-'+@vDBName+FORMAT(GETDATE(),'-yyyyMMdd')+'.log"') 109 | END 110 | ELSE 111 | BEGIN 112 | SET @vCommand = 'EXEC '+QUOTENAME(@vDBName)+'.dbo.sp_executesql @SQL'; 113 | IF @LiveRun = 0 PRINT @vCommand ELSE EXEC sp_executesql @vCommand, N'@SQL nvarchar(max)', @SQL 114 | END 115 | END TRY 116 | BEGIN CATCH 117 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- ERROR: Something potential happened. Please help to review the log and re-run where required.' 118 | SELECT ERROR_NUMBER() AS ErrorNumber, 119 | ERROR_SEVERITY() AS ErrorSeverity, 120 | ERROR_STATE() AS ErrorState, 121 | ERROR_PROCEDURE() AS ErrorProcedure, 122 | ERROR_LINE() AS ErrorLine, 123 | ERROR_MESSAGE() AS ErrorMessage 124 | IF @FailedAtOne = 1 125 | RETURN -1 126 | END CATCH 127 | 128 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- Finished '+QUOTENAME(@vDBName)+'...' 129 | 130 | DBSKIP: 131 | FETCH NEXT FROM db_cursor INTO @vDBName 132 | END 133 | 134 | CLOSE db_cursor 135 | DEALLOCATE db_cursor 136 | 137 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- Finished processes.' 138 | RETURN; 139 | END 140 | 141 | /* 142 | Test cases: 143 | Exec DbExec @SQL = 'SELECT DB_NAME(), 1', @LiveRun = 0 144 | Exec DbExec @SQL = 'SELECT DB_NAME(), 1', @LiveRun = 1 145 | Exec DbExec @SQL = 'SELECT DB_NAME(), 1', @LiveRun = 1, @DbNamePattern = '%[A-Za-z]-[A-Za-z]%' --database name contains hyphen 146 | Exec DbExec @SQL = 'SELECT DB_NAME(), 1', @LiveRun = 1, @Where = 'DB_NAME() LIKE ''%TEST%''' 147 | Exec DbExec @SQL = 'SELECT DB_NAME(), 1', @LiveRun = 1, @Where = 'EXISTS (SELECT TOP 1 1 FROM opp)', @FailedAtOne = 0 148 | 149 | Exec DbExec @SQL = 'C:\Temp\release-something-someday.sql', @LiveRun = 0 150 | Exec DbExec @SQL = 'C:\Temp\release-something-someday.sql', 151 | @SQLInstanceName = 'DAVE\DAVE140', 152 | @SQLLoginName='sa', 153 | @SQLPassword = '123', 154 | @LiveRun = 1 155 | 156 | */ 157 | -------------------------------------------------------------------------------- /maintenance/KillAllDatabaseProcesses.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: Kill all processes connecting to current database 3 | -- Notes: NOT RECOMMENDED TO RUN this sproc onto Production database / USAGE of DEV, TESTING and SETUP NEW DATABASE only 4 | -- Require sysadmin role 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-05-14 DN Intial 8 | --====================================================== 9 | --use master; 10 | DROP PROCEDURE IF EXISTS KillAllDatabaseProcesses 11 | GO 12 | 13 | CREATE PROCEDURE KillAllDatabaseProcesses @DatabaseName sysname = NULL, 14 | @LiveRun bit = 0 15 | AS 16 | BEGIN 17 | DECLARE @v_SQL nvarchar(4000) 18 | DECLARE @v_spid int 19 | DECLARE @v_sphost nvarchar(128) 20 | DECLARE @v_spuser nvarchar(128) 21 | DECLARE @v_spstatus nvarchar(128) 22 | 23 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- Checking for processes connected to test database.' 24 | If Exists ( 25 | SELECT spid, ltrim(rtrim(hostname)), ltrim(rtrim(loginame)), ltrim(rtrim(status)) 26 | FROM sys.sysprocesses 27 | WHERE dbid = db_id(Coalesce(@DatabaseName,db_name())) 28 | AND ltrim(rtrim(status)) In ('background','rollback') 29 | ) 30 | Begin 31 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- Error: Processes exist attached to the database which cannot be killed, aborting this restore.' 32 | End 33 | Else 34 | Begin 35 | Declare c_procCursor CURSOR FOR 36 | SELECT spid, ltrim(rtrim(hostname)), ltrim(rtrim(loginame)), ltrim(rtrim(status)) 37 | FROM sys.sysprocesses 38 | WHERE dbid = db_id(Coalesce(@DatabaseName,db_name())) 39 | AND ltrim(rtrim(status)) Not In ('background','rollback') 40 | OPEN c_procCursor 41 | FETCH NEXT FROM c_procCursor INTO @v_spid, @v_sphost, @v_spuser, @v_spstatus 42 | WHILE @@FETCH_STATUS = 0 43 | BEGIN 44 | SET @v_SQL = 'KILL ' + CAST(@v_spid AS nvarchar(5)) 45 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- Killing process '+CAST(@v_spid AS nvarchar(5))+' with status '+@v_spstatus+' for user '+@v_spuser+' from host '+@v_sphost 46 | If @LiveRun = '0' Print @v_SQL Else Exec sp_ExecuteSQL @v_SQL 47 | FETCH NEXT FROM c_procCursor INTO @v_spid, @v_sphost, @v_spuser, @v_spstatus 48 | END 49 | CLOSE c_procCursor 50 | DEALLOCATE c_procCursor 51 | End 52 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- Finished killing processes.' 53 | 54 | RETURN; 55 | END 56 | 57 | /* 58 | -- Run for Current DB 59 | Use master 60 | GO 61 | EXEC KillAllDatabaseProcesses @DatabaseName = NULL, @LiveRun = 1 62 | 63 | -- Run for your_database_name DB 64 | Use master 65 | GO 66 | EXEC KillAllDatabaseProcesses @DatabaseName = 'your_database_name', @LiveRun = 1 67 | 68 | --Set @LiveRun = 0 to just see output, no real run 69 | Use master 70 | GO 71 | EXEC KillAllDatabaseProcesses @DatabaseName = NULL, @LiveRun = 0 72 | EXEC KillAllDatabaseProcesses @DatabaseName = 'template-database', @LiveRun = 1 73 | */ -------------------------------------------------------------------------------- /maintenance/MaintenanceDBBackup.sql: -------------------------------------------------------------------------------- 1 | --============================================================================ 2 | -- Usage: This is to perform a FULL/DIFFERENTIAL/LOG backup of a database. 3 | -- Notes: 4 | -- History: 5 | -- Date By Description 6 | -- 20-Jun-2019 DN Created. 7 | -- 04-Jul-2019 DN Add @BackupMode 8 | -- =========================================================================== 9 | DROP PROCEDURE IF EXISTS [MaintenanceDBBackup] 10 | GO 11 | 12 | CREATE PROCEDURE [MaintenanceDBBackup] @DbName sysname, 13 | @BackupFolderPath nvarchar(256), 14 | @BackupMode varchar(20) = 'FULL'--DIFFERENTIAL, LOG 15 | AS 16 | BEGIN 17 | DECLARE @vBackupFileLocation nvarchar(256) 18 | DECLARE @vMessage nvarchar(MAX) 19 | 20 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- Processing FULL BACKUP database: '+@DbName+' - to location: '+@BackupFolderPath+'.' 21 | --Check DB exists 22 | IF NOT EXISTS ( SELECT TOP 1 1 FROM sys.databases WHERE name = @DbName) 23 | BEGIN 24 | SET @vMessage = 'ERROR: Database does not exist! Aborted!' 25 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+ '- '+@vMessage 26 | RAISERROR(@vMessage,16,1) WITH NOWAIT 27 | RETURN -1 28 | END 29 | --Valid backup mode 30 | IF @BackupMode NOT IN ('FULL','DIFFERENTIAL','LOG') 31 | BEGIN 32 | SET @vMessage = 'ERROR: Backup MODE invalid, it must be FULL or DIFFERENTIAL or LOG! Aborted!' 33 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+ '- '+@vMessage 34 | RAISERROR(@vMessage,16,1) WITH NOWAIT 35 | RETURN -1 36 | END 37 | 38 | --Get backup file path 39 | IF RIGHT(@BackupFolderPath,1) <> '\' SET @BackupFolderPath = @BackupFolderPath + '\' 40 | Set @vBackupFileLocation = 41 | @BackupFolderPath 42 | + @DbName 43 | + CASE 44 | WHEN @BackupMode = 'FULL' 45 | THEN '-FULL-'+FORMAT(CURRENT_TIMESTAMP,'yyyyMMdd')+'.bck' 46 | WHEN @BackupMode = 'DIFFERENTIAL' 47 | THEN '-DIFFERENTIAL-'+FORMAT(CURRENT_TIMESTAMP,'yyyyMMdd')+'.bck' 48 | ELSE '-LOG-'+FORMAT(CURRENT_TIMESTAMP,'yyyyMMdd-HHmmss')+'.bck' 49 | END 50 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- '+@BackupMode+' backup file path: '+@vBackupFileLocation+'.' 51 | 52 | --Perform BACKUP 53 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- Performing the backup...' 54 | BEGIN TRY 55 | IF @BackupMode = 'FULL' 56 | BACKUP DATABASE @DbName TO DISK = @vBackupFileLocation WITH NAME = @DbName, NOFORMAT, INIT, SKIP, NOUNLOAD, CHECKSUM 57 | ELSE IF @BackupMode = 'DIFFERENTIAL' 58 | BACKUP DATABASE @DbName TO DISK = @vBackupFileLocation WITH NAME = @DbName, NOFORMAT, INIT, SKIP, NOUNLOAD, CHECKSUM, DIFFERENTIAL, NOREWIND 59 | ELSE 60 | BACKUP LOG @DbName TO DISK = @vBackupFileLocation WITH NAME = @DbName, NOFORMAT, INIT, SKIP, NOUNLOAD, CHECKSUM, NOREWIND 61 | END TRY 62 | BEGIN CATCH 63 | SET @vMessage = 'ERROR: '+@BackupMode+' Backup of database '+@DbName+' failed with error code '+Cast(Error_Number() as nvarchar)+' - ['+Error_Message()+']' 64 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+ '- '+@vMessage 65 | RAISERROR(@vMessage,16,1) WITH NOWAIT 66 | RETURN -1 67 | END CATCH 68 | Print CONVERT(nvarchar,CURRENT_TIMESTAMP,21)+'- Finished' 69 | 70 | RETURN 71 | END 72 | GO 73 | /* 74 | EXEC [MaintenanceDBBackup] @DbName = 'Test', @BackupFolderPath = 'C:\Shared\Temp', @BackupMode = 'FULL' 75 | EXEC [MaintenanceDBBackup] @DbName = 'Test', @BackupFolderPath = 'C:\Shared\Temp', @BackupMode = 'DIFFERENTIAL' 76 | EXEC [MaintenanceDBBackup] @DbName = 'Test', @BackupFolderPath = 'C:\Shared\Temp', @BackupMode = 'LOG' 77 | 78 | --Invalid cases 79 | --DB does not exist 80 | EXEC [MaintenanceDBBackup] @DbName = 'DB NOT EXISTS', @BackupFolderPath = 'C:\Shared\Temp', @BackupMode = 'FULL' 81 | --Backup mode invalid 82 | EXEC [MaintenanceDBBackup] @DbName = 'Test', @BackupFolderPath = 'C:\Shared\Temp', @BackupMode = 'FULL INVALID' 83 | EXEC [MaintenanceDBBackup] @DbName = 'Test', @BackupFolderPath = 'C:\Shared\Temp', @BackupMode = 'DIFFERENTIAL INVALID' 84 | EXEC [MaintenanceDBBackup] @DbName = 'Test', @BackupFolderPath = 'C:\Shared\Temp', @BackupMode = 'LOG INVALID' 85 | --Backup location invalid 86 | EXEC [MaintenanceDBBackup] @DbName = 'Test', @BackupFolderPath = 'C:\Shared\Path Invalid', @BackupMode = 'FULL' 87 | EXEC [MaintenanceDBBackup] @DbName = 'Test', @BackupFolderPath = 'C:\Shared\Path Invalid', @BackupMode = 'DIFFERENTIAL' 88 | EXEC [MaintenanceDBBackup] @DbName = 'Test', @BackupFolderPath = 'C:\Shared\Path Invalid', @BackupMode = 'LOG' 89 | */ 90 | 91 | 92 | -------------------------------------------------------------------------------- /maintenance/MaintenanceDBRestoreFromSnapshot.sql: -------------------------------------------------------------------------------- 1 | --========================================================================================================= 2 | -- Usage: This is to restore database from a snapshot 3 | -- Note: Run in master database 4 | -- For more information how db snapshop working: https://docs.microsoft.com/en-us/sql/relational-databases/databases/database-snapshots-sql-server 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-12-06 DN Intial 8 | --========================================================================================================== 9 | use master 10 | GO 11 | DROP PROCEDURE IF EXISTS MaintenanceDBRestoreFromSnapshot 12 | GO 13 | 14 | CREATE PROCEDURE MaintenanceDBRestoreFromSnapshot @DbName varchar(256), 15 | @FromSnapshot varchar(256), 16 | @LiveRun BIT = 0 17 | AS 18 | BEGIN 19 | SET NOCOUNT ON; 20 | 21 | DECLARE @vSQL nvarchar(MAX) 22 | DECLARE @vMessage nvarchar(4000) 23 | 24 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21) + ' Starting restore database [' + @DbName + '] from snapshot [' + @FromSnapshot + ']' 25 | RAISERROR(@vMessage,0,1) WITH NOWAIT 26 | 27 | IF NOT EXISTS (SELECT TOP 1 1 FROM sys.databases WHERE name = @DbName) 28 | BEGIN 29 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21) + ' ERROR: Target database does not exist. Aborted!' 30 | RAISERROR(@vMessage,16,1) WITH NOWAIT 31 | RETURN -1 32 | END 33 | 34 | IF (SELECT COUNT(*) FROM sys.databases S JOIN sys.databases SS ON SS.source_database_id = S.database_id WHERE S.name = @DbName) > 1 35 | BEGIN 36 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21) + ' ERROR: Please make sure ONLY ONE snapshot exists. Aborted!' 37 | RAISERROR(@vMessage,16,1) WITH NOWAIT 38 | RETURN -1 39 | END 40 | 41 | IF NOT EXISTS (SELECT TOP 1 1 FROM sys.databases WHERE name = @FromSnapshot) 42 | BEGIN 43 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21) + ' ERROR: Database snapshot does not exist. Aborted!' 44 | RAISERROR(@vMessage,16,1) WITH NOWAIT 45 | RETURN -1 46 | END 47 | 48 | -- consider to use KillAllDatabaseProcesses to kill all active processes before restoring 49 | -- EXEC KillAllDatabaseProcesses @DatabaseName = @DbName, @LiveRun = 1 50 | 51 | SET @vSQL = 'RESTORE DATABASE [' + @DbName + '] FROM DATABASE_SNAPSHOT = ''' + @FromSnapshot + '''' 52 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21) + ' Restoring... - ' + @vSQL 53 | RAISERROR(@vMessage,0,1) WITH NOWAIT 54 | IF @LiveRun = 1 55 | BEGIN 56 | EXECUTE sp_executesql @statement=@vSQL 57 | END 58 | 59 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21) + ' Finished.' 60 | RAISERROR(@vMessage,0,1) WITH NOWAIT 61 | END 62 | GO 63 | /* 64 | use master 65 | GO 66 | EXEC MaintenanceDBRestoreFromSnapshot @DbName = 'TEST', @FromSnapshot = '', @LiveRun = 0 67 | EXEC MaintenanceDBRestoreFromSnapshot @DbName = 'TEST', @FromSnapshot = 'Test-SNAPSHOT-20191206-103640', @LiveRun = 0 68 | EXEC MaintenanceDBRestoreFromSnapshot @DbName = 'TEST', @FromSnapshot = 'Test-SNAPSHOT-20191206-103640', @LiveRun = 1 69 | */ -------------------------------------------------------------------------------- /maintenance/MaintenanceDBSnapshot.sql: -------------------------------------------------------------------------------- 1 | --========================================================================================================= 2 | -- Usage: This is to generate database snapshot 3 | -- Note: Run in source database. 4 | -- For more information how db snapshop working: https://docs.microsoft.com/en-us/sql/relational-databases/databases/database-snapshots-sql-server 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-12-06 DN Intial 8 | --========================================================================================================== 9 | DROP PROCEDURE IF EXISTS MaintenanceDBSnapshot 10 | GO 11 | 12 | CREATE PROCEDURE MaintenanceDBSnapshot @LiveRun BIT = 0, 13 | @Drop BIT = 1, 14 | @SnapshotLocation varchar(256) = NULL 15 | AS 16 | BEGIN 17 | SET NOCOUNT ON; 18 | 19 | DECLARE @vSQL nvarchar(MAX) 20 | DECLARE @vMessage nvarchar(4000) 21 | DECLARE @vDbSnapshotName varchar(256) 22 | DECLARE @vDbSnapshotPhysicalName varchar(256) 23 | 24 | DECLARE @CurrentDate DATETIME = GETDATE() 25 | DECLARE @SnapshotSuffix varchar(40) = '-SNAPSHOT' + FORMAT(@CurrentDate, '-yyyyMMdd-HHmmss') 26 | 27 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21) + ' Starting creating database snapshot from ' + DB_NAME() 28 | RAISERROR(@vMessage,0,1) WITH NOWAIT 29 | 30 | SELECT @vDbSnapshotName = [name] + @SnapshotSuffix, 31 | @vDbSnapshotPhysicalName = COALESCE(@SnapshotLocation + [name] + @SnapshotSuffix + '.ss', REPLACE([physical_name], '.mdf', + @SnapshotSuffix + '.ss')) 32 | FROM [sys].[database_files] 33 | WHERE [type] = 0 34 | 35 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21) + ' Snapshot name: ' + @vDbSnapshotName 36 | RAISERROR(@vMessage,0,1) WITH NOWAIT 37 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21) + ' Snapshot location: ' + @vDbSnapshotPhysicalName 38 | RAISERROR(@vMessage,0,1) WITH NOWAIT 39 | 40 | SET @vSQL = 'CREATE DATABASE [' + @vDbSnapshotName + '] ON (NAME = [' + DB_NAME() + '], FILENAME = ''' + @vDbSnapshotPhysicalName + ''') AS SNAPSHOT OF [' + DB_NAME() + ']' 41 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21) + ' Creating snap: ' + @vSQL 42 | RAISERROR(@vMessage,0,1) WITH NOWAIT 43 | IF @LiveRun = 1 44 | BEGIN 45 | IF NOT EXISTS (SELECT TOP 1 1 FROM sys.databases WHERE name = @vDbSnapshotName) 46 | BEGIN 47 | EXECUTE sp_executesql @statement=@vSQL 48 | END 49 | ELSE 50 | BEGIN 51 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21) + ' ERROR: Snapshot has been already existed. Aborted!' 52 | RAISERROR(@vMessage,16,1) WITH NOWAIT 53 | RETURN -1 54 | END 55 | END 56 | 57 | IF @Drop = 1 58 | BEGIN 59 | SET @vSQL = '' 60 | SELECT @vSQL += 'DROP DATABASE [' + S.name + '];' + char(10) + char(13) 61 | FROM sys.databases S 62 | WHERE S.source_database_id = (SELECT database_id FROM sys.databases WHERE name = DB_NAME()) 63 | AND S.name <> @vDbSnapshotName 64 | 65 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21) + ' Drop old snaps: ' + char(10) + char(13) + @vSQL 66 | RAISERROR(@vMessage,0,1) WITH NOWAIT 67 | EXECUTE sp_executesql @statement=@vSQL 68 | END 69 | 70 | SET @vMessage = CONVERT(nvarchar,CURRENT_TIMESTAMP,21) + ' Finished.' 71 | RAISERROR(@vMessage,0,1) WITH NOWAIT 72 | END 73 | GO 74 | /* 75 | EXEC MaintenanceDBSnapshot @LiveRun = 0, @SnapshotLocation = NULL 76 | EXEC MaintenanceDBSnapshot @LiveRun = 0, @SnapshotLocation = 'C:\' 77 | EXEC MaintenanceDBSnapshot @LiveRun = 1, @SnapshotLocation = NULL 78 | */ -------------------------------------------------------------------------------- /maintenance/MaintenanceRebuildIndexes.sql: -------------------------------------------------------------------------------- 1 | --============================================================================================================================================= 2 | -- Usage: This is to perform INDEXES REBUILD/REORGANIZE for current database 3 | -- Notes: 4 | -- History: 5 | -- Date By Description 6 | -- 2020-11-05 DN Created. 7 | --============================================================================================================================================= 8 | DROP PROCEDURE IF EXISTS dbo.MaintenanceRebuildIndexes 9 | GO 10 | CREATE PROCEDURE [dbo].[MaintenanceRebuildIndexes] @Debug BIT = 1 11 | AS 12 | BEGIN 13 | SET NOCOUNT ON 14 | DECLARE @vMessage nvarchar(4000) 15 | DECLARE @vSQL nvarchar(MAX) = '' 16 | 17 | SET @vMessage = CONVERT(nvarchar,GETDATE(),21) + ' - ' + 'Starting REBUILD\REORGANIZE indexes - @Database = ' + DB_NAME() 18 | IF @Debug = 1 RAISERROR(@vMessage,0,1) 19 | 20 | SET @vMessage = CONVERT(nvarchar,GETDATE(),21) + ' - ' + ' Processing '+QUOTENAME(DB_NAME())+' - Rowstore indexes' 21 | IF @Debug = 1 RAISERROR(@vMessage,0,1) 22 | 23 | ;WITH CTE AS 24 | ( 25 | SELECT object_name(a.object_id) AS TableName, 26 | schema_name(o.schema_id) AS SchemaName, 27 | b.name AS IndexName, 28 | a.avg_fragmentation_in_percent as FragPercent, 29 | CASE 30 | WHEN a.avg_fragmentation_in_percent > 5 AND a.avg_fragmentation_in_percent <= 30 31 | THEN FORMATMESSAGE('ALTER INDEX %s ON [%s].[%s] REORGANIZE;', b.name, SCHEMA_NAME(o.schema_id), OBJECT_NAME(a.object_id)) 32 | WHEN a.avg_fragmentation_in_percent > 30 33 | THEN FORMATMESSAGE('ALTER INDEX %s ON [%s].[%s] REBUILD;', b.name, SCHEMA_NAME(o.schema_id), OBJECT_NAME(a.object_id)) 34 | ELSE '' 35 | END as Script 36 | FROM sys.dm_db_index_physical_stats (DB_ID (DB_NAME()), NULL, NULL, NULL, NULL) AS a 37 | JOIN sys.objects o 38 | ON o.object_id = a.object_id 39 | JOIN sys.indexes AS b 40 | ON a.object_id = b.object_id 41 | AND a.index_id = b.index_id 42 | WHERE b.index_id > 0 43 | ) 44 | SELECT @vSQL += CHAR(13)+CHAR(10) + Script 45 | FROM CTE 46 | WHERE Script <> '' 47 | 48 | 49 | SET @vMessage = CONVERT(nvarchar,GETDATE(),21) + ' - ' + ' Processing '+QUOTENAME(DB_NAME())+' - Columnstore indexes' 50 | IF @Debug = 1 RAISERROR(@vMessage,0,1) 51 | ;WITH CTE AS 52 | ( 53 | SELECT object_name(i.object_id) AS TableName, 54 | schema_name(o.schema_id) AS SchemaName, 55 | i.name AS IndexName, 56 | 100*(ISNULL(SUM(CSRowGroups.deleted_rows),0))/NULLIF(SUM(CSRowGroups.total_rows),0) AS FragPercent 57 | FROM sys.indexes AS i 58 | JOIN sys.objects o 59 | ON o.object_id = i.object_id 60 | JOIN sys.dm_db_column_store_row_group_physical_stats AS CSRowGroups 61 | ON i.object_id = CSRowGroups.object_id 62 | AND i.index_id = CSRowGroups.index_id 63 | GROUP BY o.schema_id, i.object_id, i.index_id, i.name 64 | ) 65 | SELECT @vSQL += CHAR(13)+CHAR(10) + FORMATMESSAGE('ALTER INDEX %s ON [%s].[%s] REORGANIZE;', CTE.IndexName, CTE.SchemaName, CTE.TableName) 66 | FROM CTE 67 | WHERE FragPercent >= 20 68 | 69 | IF @Debug = 1 PRINT @vSQL 70 | EXEC sp_executesql @vSQL 71 | 72 | SET @vMessage = CONVERT(nvarchar,GETDATE(),21) + ' - ' + 'Finished' 73 | IF @Debug = 1 RAISERROR(@vMessage,0,1) 74 | 75 | RETURN 76 | END 77 | GO 78 | /* 79 | EXEC MaintenanceRebuildIndexes @Debug=1 80 | */ 81 | 82 | -------------------------------------------------------------------------------- /maintenance/PurgeDbData.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: Delete all tables's data and reseed identity 3 | -- Notes: !!USE WITH CAUTION!! 4 | -- Useful for usage at the development phases 5 | -- Parameters: 6 | -- @ExcludeTablePattern: To excludes tables where name like pattern. Escape character is '\' 7 | -- @ExcludeTables: To exclude tables where name exists. List of values splitted by comma 8 | -- @IncludeTables: To include tables where name exists. List of values splitted by comma 9 | -- @Force: Set to 1 to bypass restrictions 10 | -- History: 11 | -- Date Author Description 12 | -- 2019-05-22 DN Intial 13 | --====================================================== 14 | DROP PROCEDURE IF EXISTS PurgeDbData 15 | GO 16 | CREATE PROCEDURE PurgeDbData @ExcludeTablePattern nvarchar(256) = NULL, 17 | @ExcludeTables nvarchar(MAX) = NULL, 18 | @IncludeTables nvarchar(MAX) = NULL, 19 | @Force bit = 0, 20 | @Debug bit = 0 21 | AS 22 | BEGIN 23 | DECLARE @vGeneralWhere nvarchar(256) 24 | DECLARE @vIdentityWhere nvarchar(256) 25 | 26 | SET @vGeneralWhere = CASE WHEN @ExcludeTablePattern IS NOT NULL THEN 'AND o.name NOT LIKE '''+@ExcludeTablePattern+''' ESCAPE ''\''' ELSE '' END 27 | + CASE WHEN @ExcludeTables IS NOT NULL THEN ' AND o.name NOT IN (SELECT value FROM STRING_SPLIT('''+@ExcludeTables+''','',''))' ELSE '' END 28 | + CASE WHEN @IncludeTables IS NOT NULL THEN ' AND o.name IN (SELECT value FROM STRING_SPLIT('''+@IncludeTables+''','',''))' ELSE '' END 29 | + ' AND o.type=''U''' 30 | IF @Debug = 1 PRINT @vGeneralWhere 31 | SET @vIdentityWhere = @vGeneralWhere + ' AND EXISTS(SELECT TOP 1 1 FROM [sys].[columns] c WHERE c.object_id = o.id AND c.is_identity = 1)' 32 | IF @Debug = 1 PRINT @vIdentityWhere 33 | 34 | IF @Force = 0 35 | AND @ExcludeTablePattern IS NULL 36 | AND @ExcludeTables IS NULL 37 | AND @IncludeTables IS NULL 38 | BEGIN 39 | SELECT 'Do you intend to purge all data? Use @Force = 1 to do it.' AS Error 40 | RETURN -1 41 | END 42 | 43 | BEGIN TRY 44 | -- disable all the constraints on each table 45 | EXEC sys.sp_MSforeachtable @command1 = 'RAISERROR(''Disabling all contstraints on ?.'', 0, 1);', 46 | @command2 = 'ALTER TABLE ? NOCHECK CONSTRAINT ALL;', 47 | @whereand = @vGeneralWhere 48 | 49 | -- delete all data in each table 50 | EXEC sys.sp_MSforeachtable @command1 = 'RAISERROR(''Deleting all data in ?.'', 0, 1);', 51 | @command2 = 'SET QUOTED_IDENTIFIER ON; DELETE FROM ?;', 52 | @whereand = @vGeneralWhere 53 | 54 | -- reseed the identity columns of each table back to their starting values 55 | EXEC sys.sp_MSforeachtable @command1 = 'RAISERROR(''Re-Seeding identity columns in ?.'', 0, 1);', 56 | @command2 = 'SET IDENTITY_INSERT ? OFF; 57 | DECLARE @seed bigint; 58 | SELECT @seed = CASE 59 | WHEN last_value IS NULL THEN CAST(seed_value as bigint) 60 | ELSE CAST(seed_value as bigint) - CAST(increment_value as bigint) 61 | END 62 | FROM [sys].[identity_columns] 63 | WHERE [object_id] = object_id(''?''); 64 | DBCC CHECKIDENT ( ''?'', RESEED, @seed) WITH NO_INFOMSGS;', 65 | @whereand = @vIdentityWhere 66 | 67 | -- enable all the constraints on each table again 68 | EXEC sys.sp_MSforeachtable @command1 = 'RAISERROR(''Enabling all contstraints on ?.'', 0, 1);', 69 | @command2 = 'ALTER TABLE ? WITH CHECK CHECK CONSTRAINT ALL', 70 | @whereand = @vGeneralWhere 71 | 72 | END TRY 73 | BEGIN CATCH 74 | SELECT ERROR_NUMBER() AS ErrorNumber, 75 | ERROR_SEVERITY() AS ErrorSeverity, 76 | ERROR_STATE() AS ErrorState, 77 | ERROR_PROCEDURE() AS ErrorProcedure, 78 | ERROR_LINE() AS ErrorLine, 79 | ERROR_MESSAGE() AS ErrorMessage 80 | END CATCH 81 | END 82 | GO 83 | /* 84 | --Purge all data 85 | BEGIN TRAN 86 | EXEC PurgeDbData @Debug = 1, @Force = 1 87 | ROLLBACK 88 | 89 | --Purge data excluding somes 90 | BEGIN TRAN 91 | --EXEC PurgeDbData @ExcludeTablePattern = '\_%' --exclude tables where prefixed by underscore 92 | --EXEC PurgeDbData @ExcludeTables = 'User,Role' --exclude tables: Role, User 93 | EXEC PurgeDbData @IncludeTables = 'User' --delete User table data 94 | ROLLBACK 95 | 96 | */ -------------------------------------------------------------------------------- /maintenance/Script-CheckIndexes.sql: -------------------------------------------------------------------------------- 1 | IF OBJECT_ID('tempdb.dbo.#tempIndexesUsages','U') IS NOT NULL 2 | DROP TABLE #tempIndexesUsages 3 | GO 4 | IF OBJECT_ID('tempdb.dbo.#tempIndexesColumns','U') IS NOT NULL 5 | DROP TABLE #tempIndexesColumns 6 | GO 7 | 8 | SET NOCOUNT ON; 9 | 10 | DECLARE @NoOfDaySinceRestart BIGINT 11 | SELECT @NoOfDaySinceRestart = DATEDIFF(DAY, sqlserver_start_time, GETDATE()) FROM sys.dm_os_sys_info 12 | 13 | CREATE TABLE #tempIndexesUsages 14 | ( 15 | DBName sysname, 16 | TableName sysname, 17 | IndexName sysname, 18 | IndexType sysname, 19 | IndexSizeKB BIGINT, 20 | NumOfSeeks BIGINT, 21 | NumOfScans BIGINT, 22 | NumOfLookups BIGINT, 23 | NumOfUpdates BIGINT, 24 | NumOfSeeksAvgPerDay DECIMAL(38,4), 25 | NumOfScansAvgPerDay DECIMAL(38,4), 26 | NumOfLookupsAvgPerDay DECIMAL(38,4), 27 | NumOfUpdatesAvgPerDay DECIMAL(38,4), 28 | ) 29 | CREATE TABLE #tempIndexesColumns 30 | ( 31 | DBName sysname, 32 | TableName sysname, 33 | IndexName sysname, 34 | IndexType sysname, 35 | ColumnName sysname, 36 | IsInInclude sysname 37 | ) 38 | 39 | EXEC master..DbExec ' 40 | INSERT 41 | INTO #tempIndexesColumns 42 | SELECT DB_NAME(), 43 | TableName = t.name, 44 | IndexName = ind.name, 45 | IndexType = ind.type_desc, 46 | ColumnName = UPPER(col.name), 47 | IsInInclude = ic.is_included_column 48 | FROM sys.indexes ind 49 | JOIN sys.index_columns ic 50 | ON ind.object_id = ic.object_id 51 | AND ind.index_id = ic.index_id 52 | JOIN sys.columns col 53 | ON ic.object_id = col.object_id 54 | AND ic.column_id = col.column_id 55 | JOIN sys.tables t 56 | ON ind.object_id = t.object_id 57 | WHERE t.is_ms_shipped = 0 58 | ' 59 | EXEC master..DbExec ' 60 | INSERT 61 | INTO #tempIndexesUsages (DBName,TableName,IndexName,IndexType, 62 | IndexSizeKB,NumOfSeeks,NumOfScans,NumOfLookups,NumOfUpdates) 63 | SELECT DB_NAME(IXUS.database_id) as DBName, 64 | OBJECT_NAME(IX.OBJECT_ID) Table_Name, 65 | IX.name AS Index_Name, 66 | IX.type_desc Index_Type, 67 | SUM(PS.[used_page_count]) * 8 IndexSizeKB, 68 | IXUS.user_seeks AS NumOfSeeks, 69 | IXUS.user_scans AS NumOfScans, 70 | IXUS.user_lookups AS NumOfLookups, 71 | IXUS.user_updates AS NumOfUpdates 72 | FROM sys.indexes IX 73 | JOIN sys.dm_db_index_usage_stats IXUS 74 | ON IXUS.index_id = IX.index_id 75 | AND IXUS.OBJECT_ID = IX.OBJECT_ID 76 | JOIN sys.dm_db_partition_stats PS 77 | ON PS.index_id = IX.index_id 78 | AND PS.object_id=IX.object_id 79 | WHERE DB_ID(DB_NAME()) = IXUS.database_id 80 | AND OBJECTPROPERTY(IX.OBJECT_ID,''IsUserTable'') = 1 81 | AND IX.type_desc <> ''HEAP'' 82 | GROUP BY DB_NAME(IXUS.database_id), 83 | OBJECT_NAME(IX.OBJECT_ID), 84 | IX.name ,IX.type_desc, 85 | IXUS.user_seeks ,IXUS.user_scans ,IXUS.user_lookups,IXUS.user_updates 86 | ' 87 | UPDATE #tempIndexesUsages 88 | SET NumOfSeeksAvgPerDay = NumOfSeeks / @NoOfDaySinceRestart, 89 | NumOfScansAvgPerDay = NumOfScans / @NoOfDaySinceRestart, 90 | NumOfLookupsAvgPerDay = NumOfLookups / @NoOfDaySinceRestart, 91 | NumOfUpdatesAvgPerDay = NumOfUpdates / @NoOfDaySinceRestart 92 | 93 | SELECT 'All Data', * 94 | FROM #tempIndexesUsages 95 | 96 | --1 97 | SELECT 'Review to remove/or not' as Item,* 98 | FROM #tempIndexesUsages 99 | WHERE NumOfLookups = 0 100 | AND NumOfScans = 0 101 | AND NumOfSeeks = 0 102 | AND NumOfUpdates > 1000 103 | AND IndexType = 'NONCLUSTERED' 104 | 105 | --2 106 | IF OBJECT_ID('tempdb.dbo.#tempIndexesColumnsC','U') IS NOT NULL 107 | DROP TABLE #tempIndexesColumnsC 108 | GO 109 | SELECT DISTINCT 110 | DBName, 111 | TableName, 112 | IndexName, 113 | IndexType, 114 | STUFF( 115 | ( 116 | SELECT ',' + B.ColumnName 117 | FROM #tempIndexesColumns B 118 | WHERE B.DBName = A.DBName 119 | AND B.TableName = A.TableName 120 | AND B.IndexName = A.IndexName 121 | AND B.IndexType = A.IndexType 122 | AND B.IsInInclude = 0 123 | ORDER BY B.ColumnName 124 | FOR XML PATH('') 125 | ), 1, 1, '' 126 | ) as ColumnNames, 127 | STUFF( 128 | ( 129 | SELECT ',' + B.ColumnName 130 | FROM #tempIndexesColumns B 131 | WHERE B.DBName = A.DBName 132 | AND B.TableName = A.TableName 133 | AND B.IndexName = A.IndexName 134 | AND B.IndexType = A.IndexType 135 | AND B.IsInInclude = 1 136 | ORDER BY B.ColumnName 137 | FOR XML PATH('') 138 | ), 1, 1, '' 139 | ) as IncludedColumnNames 140 | INTO #tempIndexesColumnsC 141 | FROM #tempIndexesColumns A 142 | 143 | SElECT 'Review to de-dup indexes' as Item, A.*, C.* 144 | FROM #tempIndexesColumnsC A 145 | JOIN #tempIndexesColumnsC B 146 | ON B.DBName = A.DBName 147 | AND B.TableName = A.TableName 148 | AND B.ColumnNames = A.ColumnNames 149 | AND B.IncludedColumnNames = A.IncludedColumnNames 150 | AND B.IndexName <> A.IndexName 151 | JOIN #tempIndexesUsages C 152 | ON C.DBName = A.DBName 153 | AND C.TableName = A.TableName 154 | AND C.IndexName = A.IndexName 155 | AND C.IndexType = A.IndexType 156 | ORDER BY A.DBName,A.TableName,A.IndexName -------------------------------------------------------------------------------- /maintenance/batch/run-MaintenanceDBBackup.bat: -------------------------------------------------------------------------------- 1 | rem DAVE\DAVE140 is server name 2 | rem SystemMonitor: Database which is compiled with sproc MaintenanceDBBackup 3 | rem -U: user name (this user must have right to run BACKUP Database) 4 | rem -P: password 5 | rem -Q: upper case to run query then terminate connection after it 6 | 7 | Sqlcmd -S "DAVE\DAVE140" -d "SystemMonitor" -U "sa" -P "123" -Q "EXEC [MaintenanceDBBackup] @DbName = 'Test', @BackupFolderPath = 'C:\Shared\Temp'" -------------------------------------------------------------------------------- /maintenance/sp_whoisactive.sql: -------------------------------------------------------------------------------- 1 | /* 2 | 3 | Download source from herer: http://whoisactive.com/downloads/ 4 | Or Get downloaded 11.32 version via who_is_active_v11_32.zip 5 | 6 | Common usages: 7 | + Get current proceses running 8 | Exec sp_whoisactive 9 | 10 | + Get locks 11 | EXEC sp_whoisactive @get_locks = 1 12 | 13 | + Get locks with root 14 | EXEC sp_whoisactive @get_locks = 1, @find_block_leaders = 1 15 | 16 | + Some cases sp_whoisactive get hang, then run command below: 17 | USE master 18 | GO 19 | DBCC OPENTRAN 20 | 21 | 22 | */ -------------------------------------------------------------------------------- /maintenance/who_is_active_v11_32.zip: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/datnguye/SQL-Server/942fd5428cd0f921c749371b4256890a1c3ee82c/maintenance/who_is_active_v11_32.zip -------------------------------------------------------------------------------- /operator/Div.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: Divison in safe 3 | -- Notes: 4 | -- History: 5 | -- Date Author Description 6 | -- 2019-05-17 DN Intial 7 | --====================================================== 8 | DROP FUNCTION IF EXISTS dbo.Div 9 | GO 10 | CREATE FUNCTION dbo.Div 11 | ( 12 | @Dividend sql_variant, 13 | @Divisor sql_variant 14 | ) 15 | RETURNS sql_variant 16 | AS 17 | BEGIN 18 | RETURN CASE 19 | WHEN @Divisor = 0 20 | THEN 0.00 21 | ELSE Convert(float, @Dividend) / Convert(float, @Divisor ) 22 | END; 23 | END 24 | GO 25 | /* 26 | SELECT dbo.Div(4,4.4622434) 27 | */ -------------------------------------------------------------------------------- /query-store/DoQueryStore.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: DoQueryStore 3 | -- Notes: 4 | -- History: 5 | -- Date Author Description 6 | -- 2019-05-09 DN Intial 7 | --====================================================== 8 | DROP PROCEDURE IF EXISTS dbo.DoQueryStore 9 | GO 10 | CREATE PROCEDURE dbo.DoQueryStore @QueryID bigint = NULL, 11 | @RemoveQuery Bit = 0, 12 | @SearchPattern nvarchar(256) = NULL, 13 | @Count Int = 100 14 | AS 15 | BEGIN 16 | --Bring in-memory data into disk 17 | EXEC sp_query_store_flush_db; 18 | 19 | --Select into temp table with minimal log 20 | SELECT TOP (@Count) 21 | q.query_id, 22 | qt.query_text_id, 23 | qt.query_sql_text, 24 | p.plan_id, 25 | p.query_plan, 26 | q.initial_compile_start_time, 27 | q.last_compile_start_time 28 | INTO #temp 29 | FROM sys.query_store_query AS q 30 | JOIN sys.query_store_query_text AS qt 31 | ON q.query_text_id = qt.query_text_id 32 | LEFT JOIN sys.query_store_plan AS p 33 | ON p.query_id = q.query_id 34 | WHERE (@QueryID IS NULL OR q.query_id = @QueryID) 35 | AND (@SearchPattern IS NULL OR qt.query_sql_text LIKE @SearchPattern) 36 | ORDER BY q.last_compile_start_time DESC 37 | 38 | --SELECT ACTION 39 | IF @RemoveQuery = 0 40 | BEGIN 41 | SELECT * 42 | FROM #temp 43 | ORDER BY last_compile_start_time DESC 44 | END 45 | 46 | --REMOVE ACTION 47 | IF @RemoveQuery = 1 48 | BEGIN 49 | DECLARE @vSQL varchar(4000) = '' 50 | DECLARE @vQueryId bigint 51 | 52 | DECLARE c_temp CURSOR FOR 53 | SELECT DISTINCT t.query_id FROM #temp t 54 | OPEN c_temp 55 | 56 | FETCH NEXT FROM c_temp INTO @vQueryId 57 | WHILE @@FETCH_STATUS = 0 58 | BEGIN 59 | PRINT 'EXEC sp_query_store_remove_query @query_id = ' + Convert(varchar,@vQueryId) 60 | EXEC sp_query_store_remove_query @query_id = @vQueryId 61 | 62 | FETCH NEXT FROM c_temp INTO @vQueryId 63 | END 64 | 65 | CLOSE c_temp 66 | DEALLOCATE c_temp 67 | END 68 | 69 | RETURN; 70 | END 71 | GO 72 | 73 | /* 74 | --Select all 75 | EXECUTE dbo.DoQueryStore 76 | --Select specific 77 | EXECUTE dbo.DoQueryStore @QueryID = ? 78 | --Select with search patern 79 | EXECUTE dbo.DoQueryStore @SearchPattern = '?' 80 | EXECUTE dbo.DoQueryStore @SearchPattern = N'?' 81 | 82 | --Remove all 83 | EXECUTE dbo.DoQueryStore @RemoveQuery = 1 84 | --Remove specific 85 | EXECUTE dbo.DoQueryStore @QueryID = ?, @RemoveQuery = 1 86 | 87 | */ -------------------------------------------------------------------------------- /script-generation/GetCRUD.sql: -------------------------------------------------------------------------------- 1 | --====================================================================================================== 2 | -- Usage: GetCRUD - to get script for SELECT/INSERT/UPDATE/DELETE, and export to file using BCP command 3 | -- Dependencies: Table function \utiliy\GetPKColumns 4 | -- Scarlar function \utiliy\IsIdentityColumn 5 | -- Notes: Since SQL Server 2016+ 6 | -- Parameters: 7 | -- History: 8 | -- Date Author Description 9 | -- 2019-06-24 DN Intial 10 | --======================================================================================================= 11 | /* 12 | -------------------------------------------------------------------------------- 13 | Supported table designs 14 | -------------------------------------------------------------------------------- 15 | DROP TABLE IF EXISTS Base01 16 | GO 17 | DROP TABLE IF EXISTS Base02 18 | GO 19 | DROP TABLE IF EXISTS Base03 20 | GO 21 | CREATE TABLE Base01 22 | ( 23 | Id INT NOT NULL IDENTITY(1,1) CONSTRAINT PK_Base01 PRIMARY KEY, 24 | IsActive BIT NOT NULL CONSTRAINT DF_Base01_IsActive DEFAULT(1), 25 | --Some columns here-- 26 | CreateBy NVARCHAR(256) NOT NULL, 27 | CreateAt DATETIME NOT NULL CONSTRAINT DF_Base01_CreateAt DEFAULT(GETDATE()), 28 | UpdateBy NVARCHAR(256) NOT NULL, 29 | UpdateAt DATETIME NOT NULL CONSTRAINT DF_Base01_UpdateAt DEFAULT(GETDATE()) 30 | ) 31 | GO 32 | CREATE TABLE Base02 33 | ( 34 | Code INT NOT NULL CONSTRAINT PK_Base02 PRIMARY KEY, 35 | IsActive BIT NOT NULL CONSTRAINT DF_Base02_IsActive DEFAULT(1), 36 | --Some columns here-- 37 | CreateBy NVARCHAR(256) NOT NULL, 38 | CreateAt DATETIME NOT NULL CONSTRAINT DF_Base02_CreateAt DEFAULT(GETDATE()), 39 | UpdateBy NVARCHAR(256) NOT NULL, 40 | UpdateAt DATETIME NOT NULL CONSTRAINT DF_Base02_UpdateAt DEFAULT(GETDATE()) 41 | ) 42 | GO 43 | CREATE TABLE Base03 44 | ( 45 | Code1 INT NOT NULL, 46 | Code2 INT NOT NULL, 47 | IsActive BIT NOT NULL CONSTRAINT DF_Base03_IsActive DEFAULT(1), 48 | --Some columns here-- 49 | CreateBy NVARCHAR(256) NOT NULL, 50 | CreateAt DATETIME NOT NULL CONSTRAINT DF_Base03_CreateAt DEFAULT(GETDATE()), 51 | UpdateBy NVARCHAR(256) NOT NULL, 52 | UpdateAt DATETIME NOT NULL CONSTRAINT DF_Base03_UpdateAt DEFAULT(GETDATE()), 53 | CONSTRAINT PK_Base03 PRIMARY KEY (Code1, Code2) 54 | ) 55 | GO 56 | */ 57 | DROP PROCEDURE IF EXISTS GetCRUD 58 | GO 59 | CREATE PROCEDURE GetCRUD @Schema sysname = 'dbo', 60 | @Table sysname, 61 | @ExportTo nvarchar(256) = NULL,--'C:\Temp\', 62 | @IsActiveFieldName varchar(128) = 'IsActive', 63 | @CreateByFieldName varchar(128) = 'CreateBy', 64 | @UpdateByFieldName varchar(128) = 'UpdateBy', 65 | @UpdateAtFieldName varchar(128) = 'UpdateAt', 66 | @OverriddenServerName varchar(256) = NULL, 67 | @OverriddenUserName varchar(256) = NULL, 68 | @OverriddenPwd varchar(256) = NULL 69 | AS 70 | BEGIN 71 | SET NOCOUNT ON; 72 | 73 | DECLARE @vExportFullPath nvarchar(256) 74 | DECLARE @vBCPCommand nvarchar(512) 75 | -- 76 | DECLARE @tResult TABLE 77 | ( 78 | TABLE_SELECT varchar(max), 79 | TABLE_INSERT varchar(max), 80 | TABLE_UPDATE varchar(max), 81 | TABLE_DELETE varchar(max) 82 | ) 83 | -- 84 | DECLARE @SelectTemplate varchar(4000) = 'DROP PROCEDURE IF EXISTS {table}_SELECT{endline}GO{endline}CREATE PROCEDURE {table}_SELECT {param_pk_columns_with_data_type}{endline}AS{endline}BEGIN{endline}{tab}SELECT{tab}{columns}{endline}{tab}FROM{tab}{table}{endline}{tab}WHERE{tab}{pk_columns_equal_param_pk_columns}{endline}END{endline}GO{endline}' 85 | DECLARE @InsertTemplate varchar(4000) = 'DROP PROCEDURE IF EXISTS {table}_INSERT{endline}GO{endline}CREATE PROCEDURE {table}_INSERT {param_non_identity_columns_with_data_type}, @CreateBy NVARCHAR(256){endline}AS{endline}BEGIN{endline}{tab}INSERT{endline}{tab}INTO{tab}{table}{endline}{tab}({endline}{tab}{tab}{non_identity_columns},{endline}{tab}{tab}{create_by_field_name},{endline}{tab}{tab}{update_by_field_name}{endline}{tab}){endline}{tab}VALUES{endline}{tab}({endline}{tab}{tab}{param_non_identity_columns},{endline}{tab}{tab}@CreateBy,{endline}{tab}{tab}@CreateBy{endline}{tab}){endline}{tab}{endline}{tab}{scope_identity}{endline}END{endline}GO{endline}' 86 | DECLARE @UpdateTemplate varchar(4000) = 'DROP PROCEDURE IF EXISTS {table}_UPDATE{endline}GO{endline}CREATE PROCEDURE {table}_UPDATE{tab}{param_columns_with_data_type}, @UpdateBy NVARCHAR(256){endline}AS{endline}BEGIN{endline}{tab}UPDATE{tab}{table}{endline}{tab}SET {tab}{columns_equal_param_columns},{endline}{tab}{tab}{tab}{update_by_field_name} = @UpdateBy,{endline}{tab}{tab}{tab}{update_at_field_name} = GETDATE(){endline}{tab}WHERE{tab}{pk_columns_equal_param_pk_columns}{endline}END{endline}GO{endline}' 87 | DECLARE @DeleteTemplate varchar(4000) = 'DROP PROCEDURE IF EXISTS {table}_DELETE{endline}GO{endline}CREATE PROCEDURE {table}_DELETE{tab}{param_pk_columns_with_data_type}, @DeleteBy NVARCHAR(256){endline}AS{endline}BEGIN{endline}{tab}UPDATE{tab}{table}{endline}{tab}SET {tab}{is_active_field_name} = 0,{endline}{tab}{tab}{tab}{update_by_field_name} = @DeleteBy,{endline}{tab}{tab}{tab}{update_at_field_name} = GETDATE(){endline}{tab}WHERE{tab}{pk_columns_equal_param_pk_columns}{endline}END{endline}GO{endline}' 88 | 89 | SET @SelectTemplate = REPLACE(REPLACE(REPLACE(@SelectTemplate,'{table}',UPPER(@Table)),'{endline}',char(10)),'{tab}',char(9)) 90 | /* 91 | DROP PROCEDURE IF EXISTS YOUR_TABLE_SELECT 92 | GO 93 | CREATE PROCEDURE YOUR_TABLE_SELECT {param_pk_columns_with_data_type} 94 | AS 95 | BEGIN 96 | SELECT {columns} 97 | FROM YOUR_TABLE 98 | WHERE {pk_columns_equal_param_pk_columns} 99 | END 100 | GO 101 | */ 102 | SET @InsertTemplate = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@InsertTemplate,'{table}',UPPER(@Table)),'{endline}',char(10)),'{tab}',char(9)), '{create_by_field_name}', @CreateByFieldName),'{update_by_field_name}',@UpdateByFieldName) 103 | /* 104 | DROP PROCEDURE IF EXISTS YOUR_TABLE_INSERT 105 | GO 106 | CREATE PROCEDURE YOUR_TABLE_INSERT {param_non_identity_columns_with_data_type}, @CreateBy NVARCHAR(256) 107 | AS 108 | BEGIN 109 | INSERT 110 | INTO YOUR_TABLE 111 | ( 112 | {non_identity_columns}, 113 | CreateBy, 114 | UpdateBy 115 | ) 116 | VALUES 117 | ( 118 | {param_non_identity_columns}, 119 | CreateBy = @CreateBy, 120 | UpdateBy = @CreateBy 121 | ) 122 | END 123 | GO 124 | */ 125 | SET @UpdateTemplate = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@UpdateTemplate,'{table}',UPPER(@Table)),'{endline}',char(10)),'{tab}',char(9)),'{update_by_field_name}',@UpdateByFieldName),'{update_at_field_name}',@UpdateAtFieldName) 126 | /* 127 | DROP PROCEDURE IF EXISTS YOUR_TABLE_UPDATE 128 | GO 129 | CREATE PROCEDURE YOUR_TABLE_UPDATE {param_columns_with_data_type}, @UpdateBy NVARCHAR(256) 130 | AS 131 | BEGIN 132 | UPDATE YOUR_TABLE 133 | SET {columns_equal_param_columns}, 134 | UpdateBy = @UpdateBy, 135 | UpdateAt = GETDATE() 136 | WHERE {pk_columns_equal_param_pk_columns} 137 | END 138 | GO 139 | */ 140 | SET @DeleteTemplate = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@DeleteTemplate,'{table}',UPPER(@Table)),'{endline}',char(10)),'{tab}',char(9)), '{is_active_field_name}', @IsActiveFieldName),'{update_by_field_name}',@UpdateByFieldName),'{update_at_field_name}',@UpdateAtFieldName) 141 | /* 142 | DROP PROCEDURE IF EXISTS YOUR_TABLE_DELETE 143 | GO 144 | CREATE PROCEDURE YOUR_TABLE_DELETE {param_pk_columns_with_data_type}, @DeleteBy NVARCHAR(256) 145 | AS 146 | BEGIN 147 | UPDATE YOUR_TABLE 148 | SET IsActive = 0, 149 | UpdateBy = @DeleteBy 150 | UpdateAt = GETDATE() 151 | WHERE {pk_columns_equal_param_pk_columns} 152 | END 153 | GO 154 | 155 | */ 156 | 157 | 158 | /* 159 | Select column informations 160 | */ 161 | DROP TABLE IF EXISTS #tColumns; 162 | SELECT C.TABLE_SCHEMA, 163 | C.TABLE_NAME, 164 | C.COLUMN_NAME, 165 | CASE 166 | WHEN C.DATA_TYPE LIKE '%char' THEN C.DATA_TYPE+'('+COALESCE(CONVERT(varchar,NULLIF(CHARACTER_MAXIMUM_LENGTH,-1)),'MAX')+')' 167 | WHEN C.DATA_TYPE LIKE '%decimal%' OR C.DATA_TYPE LIKE '%numeric%' THEN C.DATA_TYPE+'('+CONVERT(varchar,NUMERIC_PRECISION)+','+CONVERT(varchar,NUMERIC_SCALE)+')' 168 | ELSE C.DATA_TYPE 169 | END as DATA_TYPE, 170 | C.ORDINAL_POSITION, 171 | dbo.IsIdentityColumn(@Schema,UPPER(@Table),C.COLUMN_NAME) AS IS_IDENTITY, 172 | CASE WHEN PC.ColumnName IS NULL THEN 0 ELSE 1 END IS_IN_PK, 173 | PC.ColumnOrder AS PK_ORDINAL_POSITION 174 | INTO #tColumns 175 | FROM INFORMATION_SCHEMA.COLUMNS C 176 | LEFT JOIN dbo.GetPKColumns(@Schema,UPPER(@Table)) PC 177 | ON PC.TableSchema = C.TABLE_SCHEMA 178 | AND PC.TableName = C.TABLE_NAME 179 | AND PC.ColumnName = C.COLUMN_NAME 180 | WHERE C.TABLE_SCHEMA = @Schema 181 | AND C.TABLE_NAME = UPPER(@Table) 182 | PRINT 'Insert into #tColumns with @@ROWCOUNT = '+CONVERT(varchar,@@ROWCOUNT) 183 | 184 | /* 185 | Prepare statements 186 | */ 187 | DROP TABLE IF EXISTS #tStatements; 188 | SELECT --Common usage 189 | '*' AS [columns], 190 | --SELECT,DELETE usage 191 | STRING_AGG(CASE WHEN IS_IN_PK = 1 THEN '@' + REPLACE(COLUMN_NAME,'_','') + ' ' + DATA_TYPE END,',') WITHIN GROUP (ORDER BY ORDINAL_POSITION) AS [param_pk_columns_with_data_type], 192 | --UPDATE,DELETE usage 193 | STRING_AGG(CASE WHEN IS_IN_PK = 1 THEN COLUMN_NAME + ' = @' + REPLACE(COLUMN_NAME,'_','') END,' AND ') WITHIN GROUP (ORDER BY ORDINAL_POSITION) AS [pk_columns_equal_param_pk_columns], 194 | --SELECT usage 195 | STRING_AGG(CASE WHEN IS_IN_PK = 1 THEN COLUMN_NAME + ' = COALESCE(@' + REPLACE(COLUMN_NAME,'_','')+','+COLUMN_NAME+')' END,' AND ') WITHIN GROUP (ORDER BY ORDINAL_POSITION) AS [pk_columns_equal_param_pk_columns_select], 196 | --INSERT usage 197 | STRING_AGG(CASE WHEN IS_IDENTITY = 0 THEN '@' + REPLACE(COLUMN_NAME,'_','') + ' ' + DATA_TYPE END,',') WITHIN GROUP (ORDER BY ORDINAL_POSITION) AS [param_non_identity_columns_with_data_type], 198 | STRING_AGG(CASE WHEN IS_IDENTITY = 0 THEN COLUMN_NAME END,',') WITHIN GROUP (ORDER BY ORDINAL_POSITION) AS [non_identity_columns], 199 | STRING_AGG(CASE WHEN IS_IDENTITY = 0 THEN '@' + REPLACE(COLUMN_NAME,'_','') END,',') WITHIN GROUP (ORDER BY ORDINAL_POSITION) AS [param_non_identity_columns], 200 | STRING_AGG(CASE WHEN IS_IDENTITY = 1 THEN 'SELECT SCOPE_IDENTITY()' END,';') WITHIN GROUP (ORDER BY ORDINAL_POSITION) as [scope_identity], 201 | --UPDATE usage 202 | STRING_AGG('@' + REPLACE(COLUMN_NAME,'_','') + ' ' + DATA_TYPE,',') WITHIN GROUP (ORDER BY ORDINAL_POSITION) AS [param_columns_with_data_type], 203 | STRING_AGG(CASE WHEN IS_IN_PK = 0 THEN COLUMN_NAME + ' = @' + REPLACE(COLUMN_NAME,'_','') END,',') WITHIN GROUP (ORDER BY ORDINAL_POSITION) AS [columns_equal_param_columns] 204 | INTO #tStatements 205 | FROM #tColumns 206 | WHERE COLUMN_NAME NOT IN ('CreateBy','CreateAt','UpdateBy','UpdateAt') 207 | GROUP BY TABLE_SCHEMA, TABLE_NAME 208 | PRINT 'Insert into #tStatements with @@ROWCOUNT = '+CONVERT(varchar,@@ROWCOUNT) 209 | 210 | 211 | INSERT INTO @tResult VALUES (NULL,NULL,NULL,NULL) 212 | /* 213 | SELECT 214 | */ 215 | UPDATE @tResult 216 | SET TABLE_SELECT = REPLACE(REPLACE(REPLACE(@SelectTemplate, 217 | '{param_pk_columns_with_data_type}',t.param_pk_columns_with_data_type), 218 | '{columns}',t.[columns]), 219 | '{pk_columns_equal_param_pk_columns}',t.pk_columns_equal_param_pk_columns_select) 220 | FROM #tStatements t 221 | 222 | /* 223 | INSERT 224 | */ 225 | UPDATE @tResult 226 | SET TABLE_INSERT = REPLACE(REPLACE(REPLACE(REPLACE(@InsertTemplate, 227 | '{param_non_identity_columns_with_data_type}',t.param_non_identity_columns_with_data_type), 228 | '{non_identity_columns}',t.non_identity_columns), 229 | '{param_non_identity_columns}',t.param_non_identity_columns), 230 | '{scope_identity}',Coalesce([scope_identity],'')) 231 | FROM #tStatements t 232 | 233 | /* 234 | UPDATE 235 | */ 236 | UPDATE @tResult 237 | SET TABLE_UPDATE = REPLACE(REPLACE(REPLACE(@UpdateTemplate, 238 | '{param_columns_with_data_type}',t.param_columns_with_data_type), 239 | '{columns_equal_param_columns}',t.columns_equal_param_columns), 240 | '{pk_columns_equal_param_pk_columns}',t.pk_columns_equal_param_pk_columns) 241 | FROM #tStatements t 242 | 243 | /* 244 | DELETE 245 | */ 246 | UPDATE @tResult 247 | SET TABLE_DELETE = REPLACE(REPLACE(@DeleteTemplate, 248 | '{param_pk_columns_with_data_type}',t.param_pk_columns_with_data_type), 249 | '{pk_columns_equal_param_pk_columns}',t.pk_columns_equal_param_pk_columns) 250 | FROM #tStatements t 251 | 252 | /* 253 | EXPORT TO FILE 254 | */ 255 | IF @ExportTo IS NULL 256 | BEGIN 257 | SELECT 'RESULT', * FROM @tResult 258 | SELECT '#DEBUG #tColumns', * FROM #tColumns 259 | SELECT '#DEBUG #tStatements', * FROM #tStatements 260 | END 261 | ELSE 262 | BEGIN 263 | SET @vExportFullPath = TRIM(@ExportTo) + CASE WHEN RIGHT(TRIM(@ExportTo),1) <> '\' THEN '\' ELSE '' END + UPPER(@Table) + '.sql' 264 | --Sqlcmd -S "DAVE\DAVE140" -d "SYSDB" -U "sa" -P "123" -Q "SELECT * FROM @tResult" -o "C:\TEMP\text.sql" 265 | 266 | DROP TABLE IF EXISTS ##tResult 267 | SELECT TABLE_SELECT+char(10)+TABLE_INSERT+char(10)+TABLE_UPDATE+char(10)+TABLE_DELETE AS [--CONTENT] 268 | INTO ##tResult 269 | FROM @tResult 270 | 271 | SET @vBCPCommand = 'bcp "SELECT [--CONTENT] FROM ##tResult" QUERYOUT "' + @vExportFullPath + '" -w '+COALESCE('-U "'+@OverriddenUserName+'" -P "'+@OverriddenPwd+'"','-T')+' -S "' + COALESCE(@OverriddenServerName,@@SERVERNAME) + '"' 272 | PRINT 'BCP Command: '+@vBCPCommand 273 | 274 | EXEC master..xp_cmdshell @vBCPCommand, no_output 275 | PRINT 'Exported to: '+@vExportFullPath 276 | END 277 | 278 | RETURN 279 | END 280 | 281 | /* 282 | --Test case 1 283 | DROP TABLE IF EXISTS Base01 284 | GO 285 | CREATE TABLE Base01 286 | ( 287 | Id INT NOT NULL IDENTITY(1,1) CONSTRAINT PK_Base01 PRIMARY KEY, 288 | IsActive BIT NOT NULL CONSTRAINT DF_Base01_IsActive DEFAULT(1), 289 | Col1 decimal(19,4) NOT NULL, 290 | Col2 int, 291 | Col3 xml, 292 | CreateBy NVARCHAR(256) NOT NULL, 293 | CreateAt DATETIME NOT NULL CONSTRAINT DF_Base01_CreateAt DEFAULT(GETDATE()), 294 | UpdateBy NVARCHAR(256) NOT NULL, 295 | UpdateAt DATETIME NOT NULL CONSTRAINT DF_Base01_UpdateAt DEFAULT(GETDATE()) 296 | ) 297 | GO 298 | EXEC GetCRUD @Table = 'Base01' 299 | GO 300 | 301 | --Test case 2 302 | DROP TABLE IF EXISTS Base01 303 | GO 304 | CREATE TABLE Base01 305 | ( 306 | Code INT NOT NULL CONSTRAINT PK_Base01 PRIMARY KEY, 307 | IsActive BIT NOT NULL CONSTRAINT DF_Base01_IsActive DEFAULT(1), 308 | Col1 decimal(19,4) NOT NULL, 309 | Col2 int, 310 | Col3 xml, 311 | CreateBy NVARCHAR(256) NOT NULL, 312 | CreateAt DATETIME NOT NULL CONSTRAINT DF_Base01_CreateAt DEFAULT(GETDATE()), 313 | UpdateBy NVARCHAR(256) NOT NULL, 314 | UpdateAt DATETIME NOT NULL CONSTRAINT DF_Base01_UpdateAt DEFAULT(GETDATE()) 315 | ) 316 | GO 317 | EXEC GetCRUD @Table = 'Base01' 318 | GO 319 | 320 | --Test case 3 321 | DROP TABLE IF EXISTS Base01 322 | GO 323 | CREATE TABLE Base01 324 | ( 325 | Code1 INT NOT NULL, 326 | Code2 INT NOT NULL, 327 | IsActive BIT NOT NULL CONSTRAINT DF_Base01_IsActive DEFAULT(1), 328 | Col1 decimal(19,4) NOT NULL, 329 | Col2 int, 330 | Col3 xml, 331 | CreateBy NVARCHAR(256) NOT NULL, 332 | CreateAt DATETIME NOT NULL CONSTRAINT DF_Base01_CreateAt DEFAULT(GETDATE()), 333 | UpdateBy NVARCHAR(256) NOT NULL, 334 | UpdateAt DATETIME NOT NULL CONSTRAINT DF_Base01_UpdateAt DEFAULT(GETDATE()), 335 | CONSTRAINT PK_Base01 PRIMARY KEY (Code1,Code2) 336 | ) 337 | GO 338 | EXEC GetCRUD @Table = 'Base01' 339 | GO 340 | 341 | --Test case 4 342 | EXEC GetCRUD @Table = 'Base01', 343 | @ExportTo = 'C:\Temp', 344 | @OverriddenServerName = 'DAVE\DAVE140', 345 | @OverriddenUserName = 'sa', 346 | @OverriddenPwd = '123' 347 | GO 348 | */ -------------------------------------------------------------------------------- /script-generation/GetCreateIndex.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/datnguye/SQL-Server/942fd5428cd0f921c749371b4256890a1c3ee82c/script-generation/GetCreateIndex.sql -------------------------------------------------------------------------------- /script-generation/GetDropIndex.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetDropIndex - to get CREATE indexes script 3 | -- Notes: 4 | -- Parameters: 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-05-17 DN Intial 8 | --====================================================== 9 | DROP PROCEDURE IF EXISTS GetDropIndex 10 | GO 11 | CREATE FUNCTION [GetDropIndex] (@ObjectID BIGINT, @ObjectName sysname) 12 | RETURNS nvarchar(max) 13 | AS 14 | BEGIN 15 | IF (@ObjectName Is NULL) RETURN NULL 16 | IF NOT EXISTS (SELECT 1 FROM sys.Indexes WHERE Object_ID = @ObjectID) AND NOT EXISTS (SELECT 1 FROM sys.Foreign_Keys WHERE Object_ID = @ObjectID) RETURN NULL 17 | 18 | DECLARE @vSQLString nvarchar(max) 19 | 20 | SELECT @vSQLString = 'ALTER TABLE ['+Table_Schema+'].['+Upper(Table_Name) +'] DROP CONSTRAINT ['+Upper(Constraint_Name)+']' 21 | FROM Information_Schema.Table_Constraints TC 22 | JOIN sys.Indexes SI 23 | ON SI.Name = TC.Constraint_Name 24 | AND Object_Schema_Name(SI.Object_ID) = TC.Constraint_Schema 25 | WHERE Constraint_Name = @ObjectName 26 | AND Object_ID = @ObjectID 27 | 28 | IF (@vSQLString Is NULL) 29 | BEGIN 30 | SELECT @vSQLString = 'DROP INDEX ['+SI.Name +'] ON ['+Object_Schema_Name(SI.Object_ID)+'].['+Object_Name(SI.Object_ID)+']' 31 | FROM sys.Indexes SI 32 | WHERE SI.Name = @ObjectName 33 | AND Object_ID = @ObjectID 34 | END 35 | 36 | IF (@vSQLString Is NULL) 37 | BEGIN 38 | SELECT @vSQLString = 'ALTER TABLE ['+Object_Schema_Name(FK.Parent_Object_ID)+'].['+Object_Name(FK.Parent_Object_ID)+'] DROP CONSTRAINT ['+FK.Name+']' 39 | FROM sys.Foreign_Keys FK 40 | WHERE FK.Name = @ObjectName 41 | AND Object_ID = @ObjectID 42 | END 43 | 44 | RETURN @vSQLString 45 | END 46 | 47 | /* 48 | DROP TABLE IF EXISTS Dummy20200527 49 | GO 50 | CREATE TABLE Dummy20200527 51 | ( 52 | ID INT NOT NULL PRIMARY KEY, 53 | Name VARCHAR(255) 54 | ) 55 | GO 56 | CREATE INDEX IX_Dummy20200527_Name ON Dummy20200527 (Name) WHERE Name IS NOT NULL 57 | GO 58 | 59 | SELECT SI.Object_ID, 60 | SI.Name, 61 | dbo.GetDropIndex(SI.Object_ID, SI.Name) 62 | FROM sys.Indexes SI 63 | JOIN sys.Objects SO 64 | ON SO.Object_ID = SI.Object_ID 65 | AND SO.Is_MS_Shipped = 0 66 | GO 67 | DROP TABLE IF EXISTS Dummy20200527 68 | GO 69 | */ -------------------------------------------------------------------------------- /script-generation/GetGRANT.sql: -------------------------------------------------------------------------------- 1 | DROP PROCEDURE IF EXISTS GetGRANT 2 | GO 3 | --====================================================================================================== 4 | -- Usage: GetGRANT 5 | -- Dependencies: 6 | -- Parameters: 7 | -- History: 8 | -- Date Author Description 9 | -- 2020-10-15 DN Intial 10 | --======================================================================================================= 11 | CREATE PROCEDURE GetGRANT @To sysname, 12 | @Schema sysname = 'dbo', 13 | @Grants varchar(255) = 'SELECT,INSERT,UPDATE,DELETE,EXECUTE', 14 | @ObjectPattern varchar(255) = '%' 15 | AS 16 | BEGIN 17 | SET NOCOUNT ON; 18 | 19 | --Stored Procedure 20 | SELECT sp.object_id AS [ObjectId], 21 | sp.name AS [Name], 22 | SCHEMA_NAME(sp.schema_id) AS [Schema], 23 | db_name() as [DatabaseName], 24 | 'Stored Procedure' as ObjType, 25 | FORMATMESSAGE('GRANT EXECUTE ON [%s].[%s] TO [%s]', SCHEMA_NAME(sp.schema_id), sp.name, @To) as GRANTScript 26 | FROM sys.all_objects AS sp 27 | WHERE (sp.type = 'P' OR sp.type = 'RF' OR sp.type='PC') 28 | AND SCHEMA_NAME(sp.schema_id) = @Schema 29 | AND PATINDEX('%EXECUTE%',@Grants) > 0 30 | AND PATINDEX(@ObjectPattern,sp.name) > 0 31 | --exclude itself 32 | AND FORMATMESSAGE('[%s].[%s]',OBJECT_SCHEMA_NAME(@@PROCID),OBJECT_NAME(@@PROCID)) <> FORMATMESSAGE('[%s].[%s]',SCHEMA_NAME(sp.schema_id),OBJECT_NAME(sp.object_id)) 33 | UNION ALL 34 | 35 | --Function 36 | SELECT udf.object_id AS [ID], 37 | udf.name AS [Name], 38 | SCHEMA_NAME(udf.schema_id) AS [Schema], 39 | db_name() as [DatabaseName], 40 | 'Scalar Function' as ObjType, 41 | FORMATMESSAGE('GRANT EXECUTE ON [%s].[%s] TO [%s]', SCHEMA_NAME(udf.schema_id), udf.name, @To) as GRANTScript 42 | FROM sys.all_objects AS udf 43 | WHERE udf.type in ('FN', 'IF', 'FS') 44 | AND SCHEMA_NAME(udf.schema_id) = @Schema 45 | AND PATINDEX('%EXECUTE%',@Grants) > 0 46 | AND PATINDEX(@ObjectPattern,udf.name) > 0 47 | UNION ALL 48 | --Function (Table) 49 | SELECT udf.object_id AS [ID], 50 | udf.name AS [Name], 51 | SCHEMA_NAME(udf.schema_id) AS [Schema], 52 | db_name() as [DatabaseName], 53 | 'Table Function' as ObjType, 54 | FORMATMESSAGE('GRANT SELECT ON [%s].[%s] TO [%s]', SCHEMA_NAME(udf.schema_id), udf.name, @To) as GRANTScript 55 | FROM sys.all_objects AS udf 56 | WHERE udf.type in ('TF', 'FT') 57 | AND SCHEMA_NAME(udf.schema_id) = @Schema 58 | AND PATINDEX('%SELECT%',@Grants) > 0 59 | AND PATINDEX(@ObjectPattern,udf.name) > 0 60 | UNION ALL 61 | 62 | --Table 63 | SELECT tbl.object_id AS [ID], 64 | tbl.name AS [Name], 65 | SCHEMA_NAME(tbl.schema_id) AS [Schema], 66 | db_name() as [DatabaseName], 67 | 'Table' as ObjType, 68 | FORMATMESSAGE('GRANT %s ON [%s].[%s] TO [%s]', REPLACE(REPLACE(@Grants,'EXECUTE,',''),',EXECUTE',''), SCHEMA_NAME(tbl.schema_id), tbl.name, @To) as GRANTScript 69 | FROM sys.tables AS tbl 70 | WHERE SCHEMA_NAME(tbl.schema_id) = @Schema 71 | AND ( 72 | PATINDEX('%SELECT%',@Grants) > 0 73 | OR PATINDEX('%INSERT%',@Grants) > 0 74 | OR PATINDEX('%UPDATE%',@Grants) > 0 75 | OR PATINDEX('%DELETE%',@Grants) > 0 76 | ) 77 | AND PATINDEX(@ObjectPattern,tbl.name) > 0 78 | UNION ALL 79 | 80 | --View 81 | SELECT v.object_id AS [ID], 82 | v.name AS [Name], 83 | SCHEMA_NAME(v.schema_id) AS [Schema], 84 | db_name() as [DatabaseName], 85 | 'View' as ObjType, 86 | FORMATMESSAGE('GRANT SELECT ON [%s].[%s] TO [%s]', SCHEMA_NAME(v.schema_id), v.name, @To) as GRANTScript 87 | FROM sys.all_views AS v 88 | WHERE v.type = 'V' 89 | AND SCHEMA_NAME(v.schema_id) = @Schema 90 | AND PATINDEX('%SELECT%',@Grants) > 0 91 | AND PATINDEX(@ObjectPattern,v.name) > 0 92 | 93 | RETURN 94 | END 95 | 96 | /* 97 | EXEC GetGRANT @To = 'user123', @Grants='SELECT,INSERT,UPDATE,DELETE,EXECUTE' 98 | */ 99 | -------------------------------------------------------------------------------- /script-generation/GetInsert-Less2016.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetInsert - to get (additional) INSERT scipt from a table 3 | -- Notes: Ealier to SQL 2016. This is required customized function: dbo.StringSplit & dbo.Trim 4 | -- Parameters: 5 | -- @TableName: The table/view for which the INSERT statements will be generated using the existing data 6 | -- @TableSchema: Use this if your table schema is not a default one 7 | -- @Where: Use this parameter to filter the rows based on a filter condition (using WHERE) 8 | -- @PrimaryColumns: A comma delimited list of the fields to use for primary key checking 9 | -- @IncludeColumnList: Use this parameter to include/ommit column list in the generated INSERT statement 10 | -- @Top: Use this parameter to generate INSERT statements only for the TOP n rows 11 | -- @ExcludeIdentityColumn: Use this parameter to ommit the identity column 12 | -- @ExcludeComputedColumns: When 1, computed columns will NOT be included in the INSERT statement 13 | -- @ColumnsIncluded: List of columns to be included in the INSERT statement 14 | -- @ColumnsExcluded: List of columns to be excluded from the INSERT statement 15 | -- History: 16 | -- Date Author Description 17 | -- 2019-05-17 DN Intial 18 | --====================================================== 19 | DROP PROCEDURE IF EXISTS GetInsert 20 | GO 21 | CREATE PROCEDURE [dbo].[GetInsert] @TableName NVARCHAR(256), 22 | @TableSchema VARCHAR(20) = NULL, 23 | @Where NVARCHAR(MAX) = NULL, 24 | @PrimaryColumns NVARCHAR(MAX) = NULL, 25 | @Top INT = NULL, 26 | @IncludeColumnList BIT = 1, 27 | @ExcludeIdentityColumn BIT = 0, 28 | @ExcludeComputedColumns BIT = 1, 29 | @ColumnsIncluded NVARCHAR(MAX) = NULL, 30 | @ColumnsExcluded NVARCHAR(MAX) = NULL 31 | AS 32 | BEGIN 33 | SET NOCOUNT ON 34 | 35 | --Making sure user only uses either @ColumnsIncluded or @ColumnsExcluded 36 | IF @ColumnsIncluded IS NOT NULL AND @ColumnsExcluded IS NOT NULL 37 | BEGIN 38 | RAISERROR('Use either @ColumnsIncluded or @ColumnsExcluded. Do not use both the parameters at once',16,1) 39 | RETURN -1 40 | END 41 | 42 | --Making sure the @ColumnsIncluded and @ColumnsExcluded parameters are receiving values in proper format 43 | IF (@ColumnsIncluded IS NOT NULL AND PATINDEX('[%]', @ColumnsIncluded) = 0) 44 | OR (@ColumnsExcluded IS NOT NULL AND PATINDEX('[%]', @ColumnsExcluded) = 0) 45 | OR (@PrimaryColumns IS NOT NULL AND PATINDEX('[%]', @PrimaryColumns) = 0) 46 | BEGIN 47 | RAISERROR('Invalid use of @ColumnsIncluded property',16,1) 48 | PRINT 'Specify column names surrounded by single quotes and separated by commas' 49 | PRINT 'Eg: EXEC GetInsert @TableName = ''titles'', @ColumnsIncluded = ''[title_id],[title]''' 50 | PRINT 'Eg: EXEC GetInsert @TableName = ''titles'', @ColumnsExcluded = ''[title_id],[title]''' 51 | PRINT 'Eg: EXEC GetInsert @TableName = ''titles'', @PrimaryColumns = ''[title_id],[title]''' 52 | RETURN -1 53 | END 54 | 55 | --Checking to see if the database name is specified along wih the table name 56 | IF PARSENAME(@TableName, 3) IS NOT NULL 57 | BEGIN 58 | RAISERROR('Do not specify the database name. Be in the required database and just specify the table name.',16,1) 59 | RETURN -1 60 | END 61 | 62 | --Checking for the existence of @TableName 63 | IF NOT EXISTS (SELECT TOP 1 1 64 | FROM INFORMATION_SCHEMA.TABLES 65 | WHERE TABLE_NAME = @TableName 66 | AND (@TableSchema IS NULL OR TABLE_SCHEMA = @TableSchema) 67 | AND (TABLE_TYPE = 'BASE TABLE' OR TABLE_TYPE = 'VIEW')) 68 | BEGIN 69 | RAISERROR('User table or view not found.',16,1) 70 | PRINT 'You may see this error, if you are not the owner of this table or view. In that case use @SchemaName parameter to specify the owner name.' 71 | PRINT 'Make sure you have SELECT permission on that table or view.' 72 | RETURN -1 73 | END 74 | 75 | --Variable declarations 76 | DECLARE @vColumnId INT = 0 77 | DECLARE @vColumnList NVARCHAR(MAX) = '' 78 | DECLARE @vColumnName NVARCHAR(MAX) = '' 79 | DECLARE @vStartInsert NVARCHAR(MAX) 80 | DECLARE @vDataType NVARCHAR(MAX) 81 | DECLARE @vCharacterSetName NVARCHAR(MAX) --to define if it contains unicode text 82 | DECLARE @vPrimaryKeys NVARCHAR(MAX) 83 | DECLARE @vValueList NVARCHAR(MAX) = '' --This is the string that will be finally executed to generate INSERT statements 84 | DECLARE @vValueListBlank NVARCHAR(MAX) = '' 85 | DECLARE @vValueListTemp NVARCHAR(MAX) = '' 86 | DECLARE @vIdentityNames NVARCHAR(MAX) = '' --Will contain the IDENTITY column's name in the table 87 | DECLARE @vPrimaryKeyList TABLE (Name NVARCHAR(MAX)) 88 | 89 | IF @TableSchema IS NULL 90 | BEGIN 91 | SET @vStartInsert = 'INSERT INTO ' + '[' + dbo.[Trim](@TableName) + ']' 92 | END 93 | ELSE 94 | BEGIN 95 | SET @vStartInsert = 'INSERT INTO ' + '[' + dbo.[Trim](dbo.[Trim](@TableSchema)) + '].' + '[' + dbo.[Trim](@TableName) + ']' 96 | END 97 | 98 | --To get the first column's ID 99 | SELECT @vColumnId = MIN(ORDINAL_POSITION) 100 | FROM INFORMATION_SCHEMA.COLUMNS (NOLOCK) 101 | WHERE TABLE_NAME = @TableName 102 | AND (@TableSchema IS NULL OR TABLE_SCHEMA = @TableSchema) 103 | 104 | --Loop through all the columns of the table, to get the column names and their data types 105 | WHILE @vColumnId IS NOT NULL 106 | BEGIN 107 | SELECT @vColumnName = QUOTENAME(COLUMN_NAME), 108 | @vDataType = DATA_TYPE, 109 | @vCharacterSetName = CHARACTER_SET_NAME 110 | FROM INFORMATION_SCHEMA.COLUMNS (NOLOCK) 111 | WHERE ORDINAL_POSITION = @vColumnId 112 | AND TABLE_NAME = @TableName 113 | AND (@TableSchema IS NULL OR TABLE_SCHEMA = @TableSchema) 114 | 115 | --Selecting only user specified columns 116 | IF @ColumnsIncluded IS NOT NULL 117 | AND CHARINDEX('[' + SUBSTRING(@vColumnName, 2, LEN(@vColumnName) - 2) + ']', @ColumnsIncluded) = 0 118 | BEGIN 119 | GOTO SKIP_LOOP 120 | END 121 | IF @ColumnsExcluded IS NOT NULL 122 | AND CHARINDEX('[' + SUBSTRING(@vColumnName, 2, LEN(@vColumnName) - 2) + ']', @ColumnsExcluded) <> 0 123 | BEGIN 124 | GOTO SKIP_LOOP 125 | END 126 | 127 | --Making sure to output SET IDENTITY_INSERT ON/OFF in case the table has an IDENTITY column 128 | IF (SELECT COLUMNPROPERTY(OBJECT_ID(QUOTENAME(COALESCE(@TableSchema, User_Name())) + '.' + @TableName), SUBSTRING(@vColumnName, 2, LEN(@vColumnName) - 2), 'IsIdentity')) = 1 129 | BEGIN 130 | IF @ExcludeIdentityColumn = 0 --Determing whether to include or exclude the IDENTITY column 131 | SET @vIdentityNames = @vColumnName 132 | ELSE 133 | GOTO SKIP_LOOP 134 | END 135 | 136 | --Making sure whether to output computed columns or not 137 | IF @ExcludeComputedColumns = 1 138 | AND (SELECT COLUMNPROPERTY(OBJECT_ID(QUOTENAME(COALESCE(@TableSchema, User_Name())) + '.' + @TableName), SUBSTRING(@vColumnName, 2, LEN(@vColumnName) - 2), 'IsComputed')) = 1 139 | BEGIN 140 | GOTO SKIP_LOOP 141 | END 142 | 143 | --PK column lists 144 | IF EXISTS ( SELECT TOP 1 1 145 | FROM INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE CCU 146 | JOIN INFORMATION_SCHEMA.TABLE_CONSTRAINTS C 147 | ON C.CONSTRAINT_NAME = CCU.CONSTRAINT_NAME 148 | WHERE C.CONSTRAINT_TYPE = 'PRIMARY KEY' 149 | AND C.CONSTRAINT_SCHEMA = COALESCE(@TableSchema, User_Name()) 150 | AND CCU.TABLE_NAME = @TableName 151 | AND '[' + COLUMN_NAME + ']' = @vColumnName) 152 | OR EXISTS (SELECT TOP 1 1 FROM dbo.SplitString(@PrimaryColumns, ',') WHERE value = @vColumnName) 153 | BEGIN 154 | INSERT @vPrimaryKeyList (Name) VALUES ( @vColumnName ) 155 | END 156 | 157 | --Generating the column value for the INSERT statement 158 | SET @vValueList += 159 | CASE 160 | WHEN @vCharacterSetName = 'UNICODE' 161 | THEN 'COALESCE(''N'''''' + REPLACE(dbo.[Trim](' + @vColumnName + '),'''''''','''''''''''')+'''''''',''NULL'')' 162 | WHEN @vDataType LIKE '%char' 163 | THEN 'COALESCE('''''''' + REPLACE(dbo.[Trim](' + @vColumnName + '),'''''''','''''''''''')+'''''''',''NULL'')' 164 | WHEN @vDataType LIKE '%date%' 165 | THEN 'COALESCE('''''''' + dbo.[Trim](CONVERT(varchar,' + @vColumnName + ',109))+'''''''',''NULL'')' 166 | WHEN @vDataType IN ( 'uniqueidentifier' ) 167 | THEN 'COALESCE('''''''' + REPLACE(CONVERT(nvarchar(max),dbo.[Trim](' + @vColumnName + ')),'''''''','''''''''''')+'''''''',''NULL'')' 168 | WHEN @vDataType LIKE '%text' 169 | THEN 'COALESCE('''''''' + REPLACE(CONVERT(nvarchar(max),' + @vColumnName + '),'''''''','''''''''''')+'''''''',''NULL'')' 170 | WHEN @vDataType LIKE'%binary' 171 | THEN 'CONVERT(nvarchar(max),0x0,1)' 172 | WHEN @vDataType IN ( 'image' ) 173 | THEN 'CASE WHEN ' + @vColumnName + ' IS NULL THEN ''NULL'' ELSE ''0x0'' END' 174 | WHEN @vDataType IN ( 'float', 'real', 'money', 'smallmoney' ) 175 | THEN 'COALESCE(dbo.[Trim](dbo.[Trim](' + 'CONVERT(char, ' + @vColumnName + ',2)' + ')),''NULL'')' 176 | ELSE 'COALESCE(dbo.[Trim](dbo.[Trim](' + 'CONVERT(nvarchar(max), ' + @vColumnName + ')' + ')),''NULL'')' 177 | END + '+'',''+' 178 | 179 | --Generating the column name list for the INSERT statement 180 | SET @vColumnList += @vColumnName + ',' 181 | 182 | SKIP_LOOP: --The label used in GOTO 183 | 184 | SELECT @vColumnId = MIN(ORDINAL_POSITION) 185 | FROM INFORMATION_SCHEMA.COLUMNS (NOLOCK) 186 | WHERE TABLE_NAME = @TableName 187 | AND ORDINAL_POSITION > @vColumnId 188 | AND (@TableSchema IS NULL OR TABLE_SCHEMA = @TableSchema) 189 | END 190 | 191 | --To get rid of the extra characters that got concatenated during the last run through the loop 192 | SET @vColumnList = LEFT(@vColumnList, LEN(@vColumnList) - 1) 193 | SET @vValueList = LEFT(@vValueList, LEN(@vValueList) - 5) 194 | 195 | IF dbo.[Trim](@vColumnList) = '' 196 | BEGIN 197 | RAISERROR('No columns to select. There should at least be one column to generate the output',16,1) 198 | RETURN -1 199 | END 200 | 201 | --Forming the final string that will be executed, to output the INSERT statements 202 | IF @IncludeColumnList <> 0 203 | BEGIN 204 | --Format: 205 | --IF NOT EXISTS (SELECT TOP 1 1 FROM Table WHERE ?) INSERT INTO Table (column1,column2,column3) VALUES (value1,value2,value3) 206 | IF (SELECT Count(*) FROM @vPrimaryKeyList) > 0 207 | BEGIN 208 | SET @vValueListTemp = 'IF NOT EXISTS (SELECT TOP 1 1 FROM ' + COALESCE('[' + dbo.[Trim](dbo.[Trim](@TableSchema)) + '].','') + '[' + dbo.[Trim](@TableName) + '] WHERE '; 209 | 210 | SET @vPrimaryKeys = '' 211 | ;WITH CTE AS 212 | ( 213 | SELECT Row_Number() OVER (ORDER BY Name) AS Counter, 214 | Name 215 | FROM @vPrimaryKeyList 216 | ) 217 | SELECT @vPrimaryKeys += (CASE WHEN CTE.Counter <> 1 THEN ' AND ' ELSE '' END) + CTE.Name + ' = '''''' + CAST(' + CTE.Name + ' AS NVARCHAR(MAX)) + ''''''' 218 | FROM CTE 219 | ORDER BY Counter 220 | 221 | SELECT @vValueListTemp += @vPrimaryKeys + ') ' 222 | END 223 | 224 | SET @vValueList = 'SELECT ' + (CASE WHEN @Top IS NULL OR @Top < 0 THEN '' ELSE ' TOP ' + dbo.[Trim](STR(@Top)) + ' ' END) + '''' 225 | + COALESCE(@vValueListTemp,'') 226 | + dbo.[Trim](@vStartInsert) + ' ''+' + '''(' + dbo.[Trim](@vColumnList) + '''+' + ''')''' + ' +''VALUES(''+ ' + @vValueList + '+'')''' + ' ' 227 | + ' FROM ' + COALESCE('[' + dbo.[Trim](dbo.[Trim](@TableSchema)) + '].','') + '[' + dbo.[Trim](@TableName) + ']' + '(NOLOCK)' 228 | + COALESCE(' WHERE ' + @Where, '') 229 | 230 | --SET @vValueListBlank = COALESCE(@vValueListTemp,'') + dbo.[Trim](@vStartInsert) + ' ''+' + '''(' + dbo.[Trim](@vColumnList) + '''+' + ''')''' + ' +''VALUES(''+ ' + @vValueList + '+'')''' + ' ' 231 | END 232 | ELSE IF @IncludeColumnList = 0 233 | BEGIN 234 | --Format: 235 | --INSERT INTO Table VALUES(value1,value2,value3) 236 | SET @vValueList = 'SELECT ' + (CASE WHEN @Top IS NULL OR @Top < 0 THEN '' ELSE ' TOP ' + dbo.[Trim](STR(@Top)) + ' ' END) + '''' 237 | + dbo.[Trim](@vStartInsert) + ' '' +''VALUES(''+ ' + @vValueList + '+'')''' + ' ' 238 | + ' FROM ' + COALESCE('[' + dbo.[Trim](dbo.[Trim](@TableSchema)) + '].','') + '[' + dbo.[Trim](@TableName) + ']' + '(NOLOCK)' 239 | + COALESCE(' WHERE ' + @Where, '') 240 | 241 | --SET @vValueListBlank = dbo.[Trim](@vStartInsert) + ' ''+' + ' +''VALUES(''+ ' + @vValueList + '+'')''' + ' ' 242 | END 243 | 244 | 245 | --RESULT HERE 246 | EXEC (@vValueList) 247 | IF @@ROWCOUNT = 0 248 | BEGIN 249 | SELECT '-- Nothing for ' + @TableName, @vValueListBlank 250 | END 251 | 252 | RETURN 253 | END 254 | GO 255 | 256 | /* 257 | EXEC dbo.GetInsert @TableName = 'WIDGET' 258 | */ 259 | -------------------------------------------------------------------------------- /script-generation/GetInsert.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetInsert - to get (additional) INSERT scipt from a table 3 | -- Notes: From SQL 2016 4 | -- Parameters: 5 | -- @TableName: The table/view for which the INSERT statements will be generated using the existing data 6 | -- @TableSchema: Use this if your table schema is not a default one 7 | -- @Where: Use this parameter to filter the rows based on a filter condition (using WHERE) 8 | -- @PrimaryColumns: A comma delimited list of the fields to use for primary key checking 9 | -- @IncludeColumnList: Use this parameter to include/ommit column list in the generated INSERT statement 10 | -- @Top: Use this parameter to generate INSERT statements only for the TOP n rows 11 | -- @ExcludeIdentityColumn: Use this parameter to ommit the identity column 12 | -- @ExcludeComputedColumns: When 1, computed columns will NOT be included in the INSERT statement 13 | -- @ColumnsIncluded: List of columns to be included in the INSERT statement 14 | -- @ColumnsExcluded: List of columns to be excluded from the INSERT statement 15 | -- History: 16 | -- Date Author Description 17 | -- 2019-05-17 DN Intial 18 | --====================================================== 19 | DROP PROCEDURE IF EXISTS GetInsert 20 | GO 21 | CREATE PROCEDURE [dbo].[GetInsert] @TableName NVARCHAR(256), 22 | @TableSchema VARCHAR(20) = NULL, 23 | @Where NVARCHAR(MAX) = NULL, 24 | @PrimaryColumns NVARCHAR(MAX) = NULL, 25 | @Top INT = NULL, 26 | @IncludeColumnList BIT = 1, 27 | @ExcludeIdentityColumn BIT = 0, 28 | @ExcludeComputedColumns BIT = 1, 29 | @ColumnsIncluded NVARCHAR(MAX) = NULL, 30 | @ColumnsExcluded NVARCHAR(MAX) = NULL 31 | AS 32 | BEGIN 33 | SET NOCOUNT ON 34 | 35 | --Making sure user only uses either @ColumnsIncluded or @ColumnsExcluded 36 | IF @ColumnsIncluded IS NOT NULL AND @ColumnsExcluded IS NOT NULL 37 | BEGIN 38 | RAISERROR('Use either @ColumnsIncluded or @ColumnsExcluded. Do not use both the parameters at once',16,1) 39 | RETURN -1 40 | END 41 | 42 | --Making sure the @ColumnsIncluded and @ColumnsExcluded parameters are receiving values in proper format 43 | IF (@ColumnsIncluded IS NOT NULL AND PATINDEX('[%]', @ColumnsIncluded) = 0) 44 | OR (@ColumnsExcluded IS NOT NULL AND PATINDEX('[%]', @ColumnsExcluded) = 0) 45 | OR (@PrimaryColumns IS NOT NULL AND PATINDEX('[%]', @PrimaryColumns) = 0) 46 | BEGIN 47 | RAISERROR('Invalid use of @ColumnsIncluded property',16,1) 48 | PRINT 'Specify column names surrounded by single quotes and separated by commas' 49 | PRINT 'Eg: EXEC GetInsert @TableName = ''titles'', @ColumnsIncluded = ''[title_id],[title]''' 50 | PRINT 'Eg: EXEC GetInsert @TableName = ''titles'', @ColumnsExcluded = ''[title_id],[title]''' 51 | PRINT 'Eg: EXEC GetInsert @TableName = ''titles'', @PrimaryColumns = ''[title_id],[title]''' 52 | RETURN -1 53 | END 54 | 55 | --Checking to see if the database name is specified along wih the table name 56 | IF PARSENAME(@TableName, 3) IS NOT NULL 57 | BEGIN 58 | RAISERROR('Do not specify the database name. Be in the required database and just specify the table name.',16,1) 59 | RETURN -1 60 | END 61 | 62 | --Checking for the existence of @TableName 63 | IF NOT EXISTS (SELECT TOP 1 1 64 | FROM INFORMATION_SCHEMA.TABLES 65 | WHERE TABLE_NAME = @TableName 66 | AND (@TableSchema IS NULL OR TABLE_SCHEMA = @TableSchema) 67 | AND (TABLE_TYPE = 'BASE TABLE' OR TABLE_TYPE = 'VIEW')) 68 | BEGIN 69 | RAISERROR('User table or view not found.',16,1) 70 | PRINT 'You may see this error, if you are not the owner of this table or view. In that case use @SchemaName parameter to specify the owner name.' 71 | PRINT 'Make sure you have SELECT permission on that table or view.' 72 | RETURN -1 73 | END 74 | 75 | --Variable declarations 76 | DECLARE @vColumnId INT = 0 77 | DECLARE @vColumnList NVARCHAR(MAX) = '' 78 | DECLARE @vColumnName NVARCHAR(MAX) = '' 79 | DECLARE @vStartInsert NVARCHAR(MAX) 80 | DECLARE @vDataType NVARCHAR(MAX) 81 | DECLARE @vCharacterSetName NVARCHAR(MAX) --to define if it contains unicode text 82 | DECLARE @vPrimaryKeys NVARCHAR(MAX) 83 | DECLARE @vValueList NVARCHAR(MAX) = '' --This is the string that will be finally executed to generate INSERT statements 84 | DECLARE @vValueListBlank NVARCHAR(MAX) = '' 85 | DECLARE @vValueListTemp NVARCHAR(MAX) = '' 86 | DECLARE @vIdentityNames NVARCHAR(MAX) = '' --Will contain the IDENTITY column's name in the table 87 | DECLARE @vPrimaryKeyList TABLE (Name NVARCHAR(MAX)) 88 | 89 | IF @TableSchema IS NULL 90 | BEGIN 91 | SET @vStartInsert = 'INSERT INTO ' + '[' + TRIM(@TableName) + ']' 92 | END 93 | ELSE 94 | BEGIN 95 | SET @vStartInsert = 'INSERT INTO ' + '[' + TRIM(TRIM(@TableSchema)) + '].' + '[' + TRIM(@TableName) + ']' 96 | END 97 | 98 | --To get the first column's ID 99 | SELECT @vColumnId = MIN(ORDINAL_POSITION) 100 | FROM INFORMATION_SCHEMA.COLUMNS (NOLOCK) 101 | WHERE TABLE_NAME = @TableName 102 | AND (@TableSchema IS NULL OR TABLE_SCHEMA = @TableSchema) 103 | 104 | --Loop through all the columns of the table, to get the column names and their data types 105 | WHILE @vColumnId IS NOT NULL 106 | BEGIN 107 | SELECT @vColumnName = QUOTENAME(COLUMN_NAME), 108 | @vDataType = DATA_TYPE, 109 | @vCharacterSetName = CHARACTER_SET_NAME 110 | FROM INFORMATION_SCHEMA.COLUMNS (NOLOCK) 111 | WHERE ORDINAL_POSITION = @vColumnId 112 | AND TABLE_NAME = @TableName 113 | AND (@TableSchema IS NULL OR TABLE_SCHEMA = @TableSchema) 114 | 115 | --Selecting only user specified columns 116 | IF @ColumnsIncluded IS NOT NULL 117 | AND CHARINDEX('[' + SUBSTRING(@vColumnName, 2, LEN(@vColumnName) - 2) + ']', @ColumnsIncluded) = 0 118 | BEGIN 119 | GOTO SKIP_LOOP 120 | END 121 | IF @ColumnsExcluded IS NOT NULL 122 | AND CHARINDEX('[' + SUBSTRING(@vColumnName, 2, LEN(@vColumnName) - 2) + ']', @ColumnsExcluded) <> 0 123 | BEGIN 124 | GOTO SKIP_LOOP 125 | END 126 | 127 | --Making sure to output SET IDENTITY_INSERT ON/OFF in case the table has an IDENTITY column 128 | IF (SELECT COLUMNPROPERTY(OBJECT_ID(QUOTENAME(COALESCE(@TableSchema, User_Name())) + '.' + @TableName), SUBSTRING(@vColumnName, 2, LEN(@vColumnName) - 2), 'IsIdentity')) = 1 129 | BEGIN 130 | IF @ExcludeIdentityColumn = 0 --Determing whether to include or exclude the IDENTITY column 131 | SET @vIdentityNames = @vColumnName 132 | ELSE 133 | GOTO SKIP_LOOP 134 | END 135 | 136 | --Making sure whether to output computed columns or not 137 | IF @ExcludeComputedColumns = 1 138 | AND (SELECT COLUMNPROPERTY(OBJECT_ID(QUOTENAME(COALESCE(@TableSchema, User_Name())) + '.' + @TableName), SUBSTRING(@vColumnName, 2, LEN(@vColumnName) - 2), 'IsComputed')) = 1 139 | BEGIN 140 | GOTO SKIP_LOOP 141 | END 142 | 143 | --PK column lists 144 | IF EXISTS ( SELECT TOP 1 1 145 | FROM INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE CCU 146 | JOIN INFORMATION_SCHEMA.TABLE_CONSTRAINTS C 147 | ON C.CONSTRAINT_NAME = CCU.CONSTRAINT_NAME 148 | WHERE C.CONSTRAINT_TYPE = 'PRIMARY KEY' 149 | AND C.CONSTRAINT_SCHEMA = COALESCE(@TableSchema, User_Name()) 150 | AND CCU.TABLE_NAME = @TableName 151 | AND '[' + COLUMN_NAME + ']' = @vColumnName) 152 | OR EXISTS (SELECT TOP 1 1 FROM STRING_SPLIT(@PrimaryColumns, ',') WHERE value = @vColumnName) 153 | BEGIN 154 | INSERT @vPrimaryKeyList (Name) VALUES ( @vColumnName ) 155 | END 156 | 157 | --Generating the column value for the INSERT statement 158 | SET @vValueList += 159 | CASE 160 | WHEN @vCharacterSetName = 'UNICODE' 161 | THEN 'COALESCE(''N'''''' + REPLACE(RTRIM(' + @vColumnName + '),'''''''','''''''''''')+'''''''',''NULL'')' 162 | WHEN @vDataType LIKE '%char' 163 | THEN 'COALESCE('''''''' + REPLACE(RTRIM(' + @vColumnName + '),'''''''','''''''''''')+'''''''',''NULL'')' 164 | WHEN @vDataType LIKE '%date%' 165 | THEN 'COALESCE('''''''' + RTRIM(CONVERT(varchar,' + @vColumnName + ',109))+'''''''',''NULL'')' 166 | WHEN @vDataType IN ( 'uniqueidentifier' ) 167 | THEN 'COALESCE('''''''' + REPLACE(CONVERT(nvarchar(max),RTRIM(' + @vColumnName + ')),'''''''','''''''''''')+'''''''',''NULL'')' 168 | WHEN @vDataType LIKE '%text' 169 | THEN 'COALESCE('''''''' + REPLACE(CONVERT(nvarchar(max),' + @vColumnName + '),'''''''','''''''''''')+'''''''',''NULL'')' 170 | WHEN @vDataType LIKE'%binary' 171 | THEN 'CONVERT(nvarchar(max),0x0,1)' 172 | WHEN @vDataType IN ( 'image' ) 173 | THEN 'CASE WHEN ' + @vColumnName + ' IS NULL THEN ''NULL'' ELSE ''0x0'' END' 174 | WHEN @vDataType IN ( 'float', 'real', 'money', 'smallmoney' ) 175 | THEN 'COALESCE(TRIM(RTRIM(' + 'CONVERT(char, ' + @vColumnName + ',2)' + ')),''NULL'')' 176 | ELSE 'COALESCE(TRIM(RTRIM(' + 'CONVERT(nvarchar(max), ' + @vColumnName + ')' + ')),''NULL'')' 177 | END + '+'',''+' 178 | 179 | --Generating the column name list for the INSERT statement 180 | SET @vColumnList += @vColumnName + ',' 181 | 182 | SKIP_LOOP: --The label used in GOTO 183 | 184 | SELECT @vColumnId = MIN(ORDINAL_POSITION) 185 | FROM INFORMATION_SCHEMA.COLUMNS (NOLOCK) 186 | WHERE TABLE_NAME = @TableName 187 | AND ORDINAL_POSITION > @vColumnId 188 | AND (@TableSchema IS NULL OR TABLE_SCHEMA = @TableSchema) 189 | END 190 | 191 | --To get rid of the extra characters that got concatenated during the last run through the loop 192 | SET @vColumnList = LEFT(@vColumnList, LEN(@vColumnList) - 1) 193 | SET @vValueList = LEFT(@vValueList, LEN(@vValueList) - 5) 194 | 195 | IF TRIM(@vColumnList) = '' 196 | BEGIN 197 | RAISERROR('No columns to select. There should at least be one column to generate the output',16,1) 198 | RETURN -1 199 | END 200 | 201 | --Forming the final string that will be executed, to output the INSERT statements 202 | IF @IncludeColumnList <> 0 203 | BEGIN 204 | --Format: 205 | --IF NOT EXISTS (SELECT TOP 1 1 FROM Table WHERE ?) INSERT INTO Table (column1,column2,column3) VALUES (value1,value2,value3) 206 | IF (SELECT Count(*) FROM @vPrimaryKeyList) > 0 207 | BEGIN 208 | SET @vValueListTemp = 'IF NOT EXISTS (SELECT TOP 1 1 FROM ' + COALESCE('[' + TRIM(TRIM(@TableSchema)) + '].','') + '[' + TRIM(@TableName) + '] WHERE '; 209 | 210 | SET @vPrimaryKeys = '' 211 | ;WITH CTE AS 212 | ( 213 | SELECT Row_Number() OVER (ORDER BY Name) AS Counter, 214 | Name 215 | FROM @vPrimaryKeyList 216 | ) 217 | SELECT @vPrimaryKeys += (CASE WHEN CTE.Counter <> 1 THEN ' AND ' ELSE '' END) + CTE.Name + ' = '''''' + CAST(' + CTE.Name + ' AS NVARCHAR(MAX)) + ''''''' 218 | FROM CTE 219 | ORDER BY Counter 220 | 221 | SELECT @vValueListTemp += @vPrimaryKeys + ') ' 222 | END 223 | 224 | SET @vValueList = 'SELECT ' + (CASE WHEN @Top IS NULL OR @Top < 0 THEN '' ELSE ' TOP ' + TRIM(STR(@Top)) + ' ' END) + '''' 225 | + COALESCE(@vValueListTemp,'') 226 | + TRIM(@vStartInsert) + ' ''+' + '''(' + TRIM(@vColumnList) + '''+' + ''')''' + ' +''VALUES(''+ ' + @vValueList + '+'')''' + ' ' 227 | + ' FROM ' + COALESCE('[' + TRIM(TRIM(@TableSchema)) + '].','') + '[' + TRIM(@TableName) + ']' + '(NOLOCK)' 228 | + COALESCE(' WHERE ' + @Where, '') 229 | 230 | --SET @vValueListBlank = COALESCE(@vValueListTemp,'') + TRIM(@vStartInsert) + ' ''+' + '''(' + TRIM(@vColumnList) + '''+' + ''')''' + ' +''VALUES(''+ ' + @vValueList + '+'')''' + ' ' 231 | END 232 | ELSE IF @IncludeColumnList = 0 233 | BEGIN 234 | --Format: 235 | --INSERT INTO Table VALUES(value1,value2,value3) 236 | SET @vValueList = 'SELECT ' + (CASE WHEN @Top IS NULL OR @Top < 0 THEN '' ELSE ' TOP ' + TRIM(STR(@Top)) + ' ' END) + '''' 237 | + TRIM(@vStartInsert) + ' '' +''VALUES(''+ ' + @vValueList + '+'')''' + ' ' 238 | + ' FROM ' + COALESCE('[' + TRIM(TRIM(@TableSchema)) + '].','') + '[' + TRIM(@TableName) + ']' + '(NOLOCK)' 239 | + COALESCE(' WHERE ' + @Where, '') 240 | 241 | --SET @vValueListBlank = TRIM(@vStartInsert) + ' ''+' + ' +''VALUES(''+ ' + @vValueList + '+'')''' + ' ' 242 | END 243 | 244 | 245 | --RESULT HERE 246 | EXEC (@vValueList) 247 | IF @@ROWCOUNT = 0 248 | BEGIN 249 | SELECT '-- Nothing for ' + @TableName, @vValueListBlank 250 | END 251 | 252 | RETURN 253 | END 254 | GO 255 | 256 | /* 257 | EXEC dbo.GetInsert @TableName = 'Your_Table_Name' 258 | */ -------------------------------------------------------------------------------- /script-generation/GetInsert_MongoShell.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetInsert_MongoShell 3 | -- NOTES: This routine is using SQL Windows Authentication to export js file 4 | -- History: 5 | -- Date Author Description 6 | -- 2020-06-11 DN Intial 7 | --====================================================== 8 | DROP PROCEDURE IF EXISTS [dbo].GetInsert_MongoShell 9 | GO 10 | CREATE PROCEDURE [dbo].GetInsert_MongoShell @TableName sysname, 11 | @TableSchema sysname = 'dbo', 12 | @Top INT = NULL, 13 | @Where nvarchar(4000) = '', 14 | @ExportPath nvarchar(255) = NULL, 15 | @ExportOverrideServerInstance nvarchar(255) = NULL, 16 | @OverrideDestinationCollection nvarchar(255) = NULL 17 | AS 18 | BEGIN 19 | SET NOCOUNT ON; 20 | 21 | DECLARE @vCommand nvarchar(4000) 22 | DECLARE @vCollectionName nvarchar(255) = COALESCE(@OverrideDestinationCollection, @TableName) 23 | DECLARE @vReturnCode INT 24 | 25 | SET @ExportPath += '-.js' 26 | DECLARE @vExportPath nvarchar(255) = REPLACE(REPLACE(@ExportPath, '', @TableName), '', FORMAT(GETDATE(), 'yyyyMMdd-HHmmss')) 27 | 28 | --Checking for the existence of @TableName 29 | IF NOT EXISTS (SELECT TOP 1 1 30 | FROM INFORMATION_SCHEMA.TABLES 31 | WHERE TABLE_NAME = @TableName 32 | AND (@TableSchema IS NULL OR TABLE_SCHEMA = @TableSchema) 33 | AND (TABLE_TYPE = 'BASE TABLE' OR TABLE_TYPE = 'VIEW')) 34 | BEGIN 35 | RAISERROR('User table or view not found.',16,1) 36 | RAISERROR('You may see this error, if you are not the owner of this table or view. In that case use @SchemaName parameter to specify the owner name.',0,1) WITH NOWAIT 37 | RAISERROR('Make sure you have SELECT permission on that table or view.',0,1) WITH NOWAIT 38 | RETURN -1 39 | END 40 | 41 | RAISERROR(@vExportPath,0,1) WITH NOWAIT 42 | 43 | --Store json data into a temp table 44 | DROP TABLE IF EXISTS ##tJsonData 45 | CREATE TABLE ##tJsonData (InsertScript nvarchar(max)) 46 | 47 | SET @vCommand = ' 48 | DECLARE @vJsonData nvarchar(max) 49 | SELECT @vJsonData = ( 50 | SELECT ' + CASE WHEN @Top IS NOT NULL THEN 'TOP (@Top)' ELSE '' END + ' * 51 | FROM . 52 | 53 | FOR JSON AUTO 54 | ) 55 | INSERT INTO ##tJsonData SELECT N''db.createCollection("");db..remove({});db..insert('' + @vJsonData + '')''' 56 | 57 | SET @vCommand = REPLACE(@vCommand, '', @TableSchema) 58 | SET @vCommand = REPLACE(@vCommand, '
', @TableName) 59 | SET @vCommand = REPLACE(@vCommand, '', @vCollectionName) 60 | IF COALESCE(LTRIM(RTRIM(@Where)),'') <> '' 61 | SET @Where = 'WHERE ' + @Where 62 | ELSE 63 | SET @Where = '' 64 | SET @vCommand = REPLACE(@vCommand, '', @Where) 65 | 66 | EXEC sp_executesql @vCommand, N'@Top INT', @Top 67 | 68 | --Export to js file using sqlcmd 69 | IF @ExportPath IS NOT NULL 70 | BEGIN 71 | SET @vCommand = 'bcp "SELECT InsertScript FROM ##tJsonData" QUERYOUT "' + @vExportPath + '" -T -c -C65001 -S "' + COALESCE(@ExportOverrideServerInstance, @@SERVERNAME) + '"' 72 | RAISERROR(@vCommand,0,1) WITH NOWAIT 73 | EXEC @vReturnCode = xp_cmdshell @vCommand, no_output 74 | IF @vReturnCode <> 0 75 | BEGIN 76 | RAISERROR('Exporting has been failed',16,1) WITH NOWAIT 77 | RETURN -1 78 | END 79 | 80 | -- 81 | SET @vCommand = ' mongo mongodb://127.0.0.1:27017/Covid19 -u admin -p admin --eval "load(''' + REPLACE(@vExportPath, '\','/') + ''')"' 82 | RAISERROR('Sample mongo shell:',0,1) WITH NOWAIT 83 | RAISERROR(@vCommand,0,1) WITH NOWAIT 84 | RAISERROR('OPTIONS:',0,1) WITH NOWAIT 85 | RAISERROR(' 127.0.0.1: Mongo server IP address',0,1) WITH NOWAIT 86 | RAISERROR(' 27017: Mongo server port',0,1) WITH NOWAIT 87 | RAISERROR(' Covid19: Database name',0,1) WITH NOWAIT 88 | RAISERROR(' -u admin: Specify user login',0,1) WITH NOWAIT 89 | RAISERROR(' -p admin: Specify user password',0,1) WITH NOWAIT 90 | END 91 | ELSE 92 | BEGIN 93 | SELECT InsertScript FROM ##tJsonData 94 | END 95 | 96 | RETURN 97 | END 98 | GO 99 | /* 100 | --This sample will get results of https://github.com/datnguye/SQL-Server/blob/master/web-call/ApiCovid19.sql to generate mongo shell script 101 | 102 | EXEC GetInsert_MongoShell @TableName='ApiCovid19Route' 103 | EXEC GetInsert_MongoShell @TableName='ApiCovid19CountryDayOne', @Top = 10, @Where = 'CountryCode = ''vn''' 104 | EXEC GetInsert_MongoShell @TableName='ApiCovid19Route' 105 | 106 | EXEC ApiCovid19 107 | EXEC GetInsert_MongoShell @TableName='ApiCovid19Route', @ExportPath = 'C:\Temp\' 108 | EXEC GetInsert_MongoShell @TableName='ApiCovid19Countries', @ExportPath = 'C:\Temp\' 109 | EXEC GetInsert_MongoShell @TableName='ApiCovid19CountryDayOne', @ExportPath = 'C:\Temp\' 110 | EXEC GetInsert_MongoShell @TableName='ApiCovid19Summary', @ExportPath = 'C:\Temp\' 111 | 112 | */ -------------------------------------------------------------------------------- /security/GetSqlLoginDetails.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetSqlLoginDetails 3 | -- Notes: 4 | -- Parameters: 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-05-23 DN Intial 8 | --====================================================== 9 | DROP PROCEDURE IF EXISTS GetSqlLoginDetails 10 | GO 11 | CREATE PROCEDURE [dbo].GetSqlLoginDetails @LoginName sysname = NULL, 12 | @IncludeUserMapping BIT = 0 13 | AS 14 | BEGIN 15 | SET NOCOUNT ON 16 | IF OBJECT_ID(N'tempdb.dbo.#tLogin', 'U') IS NOT NULL 17 | DROP TABLE #tLogin; 18 | 19 | SELECT l.LoginName, 20 | l.dbname as DefaultDB, 21 | l.sysadmin, 22 | l.isntname, 23 | l.isntgroup, 24 | l.isntuser, 25 | l.securityadmin, 26 | l.serveradmin, 27 | l.setupadmin, 28 | l.processadmin, 29 | l.diskadmin, 30 | l.dbcreator, 31 | l.bulkadmin 32 | INTO #tLogin 33 | FROM sys.syslogins l 34 | JOIN sys.server_principals sp 35 | ON sp.name = l.loginname 36 | WHERE l.hasaccess=1 37 | AND l.denylogin=0 38 | AND l.loginname NOT LIKE 'NT %' 39 | AND l.loginname NOT LIKE '##%' 40 | AND sp.is_disabled <> 1 41 | 42 | SELECT * 43 | FROM #tLogin 44 | ORDER BY 1 45 | 46 | IF @IncludeUserMapping = 1 47 | BEGIN 48 | IF OBJECT_ID(N'tempdb.dbo.#tUserMapping', 'U') IS NOT NULL 49 | DROP TABLE #tUserMapping; 50 | 51 | CREATE TABLE #tUserMapping ( 52 | LoginName sysname, 53 | LoginType nvarchar(60), 54 | IsMustChange bit, 55 | DatabaseName sysname NULL, 56 | DatabaseUserName sysname NULL, 57 | DatabaseRoleName sysname NULL 58 | ) 59 | 60 | EXEC sp_MSforeachdb ' 61 | USE [?]; 62 | INSERT INTO #tUserMapping 63 | SELECT sp.name AS LoginName, 64 | sp.type_desc AS LoginType, 65 | CAST(LOGINPROPERTY(sp.name, ''IsMustChange'') AS bit) AS IsMustChange, 66 | DB_NAME() AS DatabaseName, 67 | dp.name AS DatabaseUserName, 68 | r.name AS DatabaseRoleName 69 | FROM sys.server_principals sp 70 | JOIN #tLogin L 71 | ON L.LoginName = sp.name 72 | JOIN sys.database_principals dp 73 | ON dp.sid = sp.sid 74 | JOIN sys.database_role_members drm 75 | ON drm.member_principal_id = dp.principal_id 76 | JOIN sys.database_principals r 77 | ON r.principal_id = drm.role_principal_id'; 78 | 79 | SELECT * 80 | FROM #tUserMapping 81 | ORDER BY 1,2,4 82 | END 83 | 84 | 85 | RETURN 86 | END 87 | GO 88 | /* 89 | EXEC GetSqlLoginDetails @LoginName = NULL, 90 | @IncludeUserMapping = 1 91 | */ 92 | -------------------------------------------------------------------------------- /string/Base642String.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: Convert Base64 to string 3 | -- Notes: 4 | -- History: 5 | -- Date Author Description 6 | -- 2020-05-25 DN Intial 7 | --====================================================== 8 | DROP FUNCTION IF EXISTS Base642String 9 | GO 10 | CREATE FUNCTION Base642String(@Base64 nvarchar(max)) 11 | RETURNS nvarchar(max) 12 | AS 13 | BEGIN 14 | RETURN 15 | ( 16 | SELECT CONVERT(nvarchar(max), CONVERT(xml,N'').value('xs:base64Binary(sql:variable("@Base64"))', 'VARBINARY(MAX)')) as D 17 | ) 18 | END 19 | GO 20 | 21 | /* 22 | SELECT dbo.[Base642String]('dQBzAGUAcgBuAGEAbQBlADoAcABhAHMAcwB3AG8AcgBkAA==') 23 | */ -------------------------------------------------------------------------------- /string/CharIndexWithQuotes.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: CharIndexWithQuotes 3 | -- Notes: 4 | -- History: 5 | -- Date Author Description 6 | -- 2019-03-29 Dave Intial 7 | --====================================================== 8 | IF OBJECT_ID('CharIndexWithQuotes', 'FN') IS NOT NULL 9 | DROP FUNCTION CharIndexWithQuotes 10 | GO 11 | CREATE FUNCTION CharIndexWithQuotes(@ExpressionToSearch VARCHAR(8000), 12 | @ExpressionToFind VARCHAR(255) = ',', 13 | @QuotesOn Bit = 0) 14 | RETURNS int 15 | AS 16 | BEGIN 17 | IF @QuotesOn = 0 OR LEFT(@ExpressionToSearch, 1) <> '"' 18 | RETURN CHARINDEX(@ExpressionToFind, @ExpressionToSearch) 19 | 20 | DECLARE @vEndQuotePosition Int 21 | SET @vEndQuotePosition = NULLIF(CHARINDEX('"', @ExpressionToSearch, 2),0) 22 | 23 | RETURN CHARINDEX(@ExpressionToFind, @ExpressionToSearch, Coalesce(@vEndQuotePosition, LEN(@ExpressionToSearch))) 24 | END 25 | GO 26 | 27 | /* 28 | DECLARE @test varchar(30); 29 | SET @test = '"This,is,a",sentence' 30 | SELECT dbo.CharIndexWithQuotes(@test, ',', 1) 31 | */ 32 | -------------------------------------------------------------------------------- /string/GetNthWord.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetNthWord 3 | -- Notes: 4 | -- Dependencies: dbo.CharIndexWithQuotes 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-03-29 Dave Intial 8 | --====================================================== 9 | IF OBJECT_ID('GetNthWord', 'FN') IS NOT NULL 10 | DROP FUNCTION GetNthWord 11 | GO 12 | CREATE FUNCTION GetNthWord( @ExpressionToSearch nvarchar(max), 13 | @ExpressionToFind nvarchar(255) = ',', 14 | @Occurrence INT, 15 | @DoubleQuotesOn BIT = 0) 16 | RETURNS nvarchar(max) 17 | AS 18 | BEGIN 19 | 20 | -- Declare variables and place-holders 21 | DECLARE @vFound INT = @Occurrence 22 | DECLARE @vWord nvarchar(max) = @ExpressionToSearch 23 | DECLARE @vEnd int 24 | -- 25 | DECLARE @vResult nvarchar(max) 26 | 27 | -- Start an infinite loop that will only end when the Nth word is found 28 | WHILE 1=1 29 | BEGIN 30 | -- Loop break (1) 31 | IF @vFound = 1 32 | BEGIN 33 | SET @vEnd = dbo.CharIndexWithQuotes(@vWord, @ExpressionToFind, @DoubleQuotesOn) 34 | IF @vEnd IS NULL or @vEnd = 0 35 | BEGIN 36 | SET @vEnd = LEN(@vWord) 37 | END 38 | BREAK; 39 | END 40 | 41 | -- Loop break (2) 42 | -- If the selected word is beyond the number of words, NULL is returned 43 | IF Coalesce(dbo.CharIndexWithQuotes(@vWord, @ExpressionToFind, @DoubleQuotesOn),0) = 0 44 | BEGIN 45 | SET @vWord = NULL; 46 | BREAK; 47 | END 48 | 49 | -- Eliminate characters from @ExpressionToSearch 50 | -- Each iteration of the loop will remove the first word fromt the left 51 | SET @vWord = RIGHT(@vWord, LEN(@vWord) - dbo.CharIndexWithQuotes(@vWord, @ExpressionToFind, @DoubleQuotesOn)); 52 | SET @vFound = @vFound - 1 53 | END 54 | 55 | SET @vResult = LEFT(@vWord,@vEnd - (CASE WHEN @vEnd = LEN(@vWord) THEN 0 ELSE 1 END)) 56 | IF LEFT(@vResult,1) = '"' 57 | SET @vResult = RIGHT(@vResult, LEN(@vResult)-1) 58 | IF RIGHT(@vResult,1) = '"' 59 | SET @vResult = LEFT(@vResult, LEN(@vResult)-1) 60 | IF RIGHT(@vResult,1) = @ExpressionToFind 61 | SET @vResult = LEFT(@vResult, LEN(@vResult)-1) 62 | 63 | RETURN @vResult; 64 | END 65 | GO 66 | 67 | /* 68 | DECLARE @test nvarchar(max); 69 | SET @test = 'This,"is,a",sentence,"which,is,more",than,that,xxx' 70 | SELECT dbo.GetNthWord(@test,',', 1, 1) 71 | SELECT dbo.GetNthWord(@test,',', 2, 1) 72 | SELECT dbo.GetNthWord(@test,',', 3, 1) 73 | SELECT dbo.GetNthWord(@test,',', 4, 1) 74 | SELECT dbo.GetNthWord(@test,',', 5, 1) 75 | SELECT dbo.GetNthWord(@test,',', 6, 1) 76 | */ 77 | -------------------------------------------------------------------------------- /string/GetRandomSentence.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetRandomSentence 3 | -- Notes: USAGE WITH CAUTION!! This is using a permenant table called BipsData (script below) 4 | -- Dependencies: 5 | -- View VWRAND 6 | -- Table BipsData 7 | -- History: 8 | -- Date Author Description 9 | -- 2019-09-24 DN Intial 10 | --====================================================== 11 | /* 12 | --Referenec: https://github.com/bitcoin/bips/blob/master/bip-0039/english.txt 13 | DROP TABLE IF EXISTS BipsData 14 | GO 15 | CREATE TABLE BipsData (Id INT NOT NULL IDENTITY(1,1), RecordText nvarchar(255)) 16 | GO 17 | INSERT 18 | INTO BipsData (RecordText) 19 | SELECT Value 20 | FROM STRING_SPLIT('abandon,ability,able,about,above,absent,absorb,abstract,absurd,abuse,access,accident,account,accuse,achieve,acid,acoustic,acquire,across,act,action,actor,actress,actual,adapt,add,addict,address,adjust,admit,adult,advance,advice,aerobic,affair,afford,afraid,again,age,agent,agree,ahead,aim,air,airport,aisle,alarm,album,alcohol,alert,alien,all,alley,allow,almost,alone,alpha,already,also,alter,always,amateur,amazing,among,amount,amused,analyst,anchor,ancient,anger,angle,angry,animal,ankle,announce,annual,another,answer,antenna,antique,anxiety,any,apart,apology,appear,apple,approve,april,arch,arctic,area,arena,argue,arm,armed,armor,army,around,arrange,arrest,arrive,arrow,art,artefact,artist,artwork,ask,aspect,assault,asset,assist,assume,asthma,athlete,atom,attack,attend,attitude,attract,auction,audit,august,aunt,author,auto,autumn,average,avocado,avoid,awake,aware,away,awesome,awful,awkward,axis,baby,bachelor,bacon,badge,bag,balance,balcony,ball,bamboo,banana,banner,bar,barely,bargain,barrel,base,basic,basket,battle,beach,bean,beauty,because,become,beef,before,begin,behave,behind,believe,below,belt,bench,benefit,best,betray,better,between,beyond,bicycle,bid,bike,bind,biology,bird,birth,bitter,black,blade,blame,blanket,blast,bleak,bless,blind,blood,blossom,blouse,blue,blur,blush,board,boat,body,boil,bomb,bone,bonus,book,boost,border,boring,borrow,boss,bottom,bounce,box,boy,bracket,brain,brand,brass,brave,bread,breeze,brick,bridge,brief,bright,bring,brisk,broccoli,broken,bronze,broom,brother,brown,brush,bubble,buddy,budget,buffalo,build,bulb,bulk,bullet,bundle,bunker,burden,burger,burst,bus,business,busy,butter,buyer,buzz,cabbage,cabin,cable,cactus,cage,cake,call,calm,camera,camp,can,canal,cancel,candy,cannon,canoe,canvas,canyon,capable,capital,captain,car,carbon,card,cargo,carpet,carry,cart,case,cash,casino,castle,casual,cat,catalog,catch,category,cattle,caught,cause,caution,cave,ceiling,celery,cement,census,century,cereal,certain,chair,chalk,champion,change,chaos,chapter,charge,chase,chat,cheap,check,cheese,chef,cherry,chest,chicken,chief,child,chimney,choice,choose,chronic,chuckle,chunk,churn,cigar,cinnamon,circle,citizen,city,civil,claim,clap,clarify,claw,clay,clean,clerk,clever,click,client,cliff,climb,clinic,clip,clock,clog,close,cloth,cloud,clown,club,clump,cluster,clutch,coach,coast,coconut,code,coffee,coil,coin,collect,color,column,combine,come,comfort,comic,common,company,concert,conduct,confirm,congress,connect,consider,control,convince,cook,cool,copper,copy,coral,core,corn,correct,cost,cotton,couch,country,couple,course,cousin,cover,coyote,crack,cradle,craft,cram,crane,crash,crater,crawl,crazy,cream,credit,creek,crew,cricket,crime,crisp,critic,crop,cross,crouch,crowd,crucial,cruel,cruise,crumble,crunch,crush,cry,crystal,cube,culture,cup,cupboard,curious,current,curtain,curve,cushion,custom,cute,cycle,dad,damage,damp,dance,danger,daring,dash,daughter,dawn,day,deal,debate,debris,decade,december,decide,decline,decorate,decrease,deer,defense,define,defy,degree,delay,deliver,demand,demise,denial,dentist,deny,depart,depend,deposit,depth,deputy,derive,describe,desert,design,desk,despair,destroy,detail,detect,develop,device,devote,diagram,dial,diamond,diary,dice,diesel,diet,differ,digital,dignity,dilemma,dinner,dinosaur,direct,dirt,disagree,discover,disease,dish,dismiss,disorder,display,distance,divert,divide,divorce,dizzy,doctor,document,dog,doll,dolphin,domain,donate,donkey,donor,door,dose,double,dove,draft,dragon,drama,drastic,draw,dream,dress,drift,drill,drink,drip,drive,drop,drum,dry,duck,dumb,dune,during,dust,dutch,duty,dwarf,dynamic,eager,eagle,early,earn,earth,easily,east,easy,echo,ecology,economy,edge,edit,educate,effort,egg,eight,either,elbow,elder,electric,elegant,element,elephant,elevator,elite,else,embark,embody,embrace,emerge,emotion,employ,empower,empty,enable,enact,end,endless,endorse,enemy,energy,enforce,engage,engine,enhance,enjoy,enlist,enough,enrich,enroll,ensure,enter,entire,entry,envelope,episode,equal,equip,era,erase,erode,erosion,error,erupt,escape,essay,essence,estate,eternal,ethics,evidence,evil,evoke,evolve,exact,example,excess,exchange,excite,exclude,excuse,execute,exercise,exhaust,exhibit,exile,exist,exit,exotic,expand,expect,expire,explain,expose,express,extend,extra,eye,eyebrow,fabric,face,faculty,fade,faint,faith,fall,false,fame,family,famous,fan,fancy,fantasy,farm,fashion,fat,fatal,father,fatigue,fault,favorite,feature,february,federal,fee,feed,feel,female,fence,festival,fetch,fever,few,fiber,fiction,field,figure,file,film,filter,final,find,fine,finger,finish,fire,firm,first,fiscal,fish,fit,fitness,fix,flag,flame,flash,flat,flavor,flee,flight,flip,float,flock,floor,flower,fluid,flush,fly,foam,focus,fog,foil,fold,follow,food,foot,force,forest,forget,fork,fortune,forum,forward,fossil,foster,found,fox,fragile,frame,frequent,fresh,friend,fringe,frog,front,frost,frown,frozen,fruit,fuel,fun,funny,furnace,fury,future,gadget,gain,galaxy,gallery,game,gap,garage,garbage,garden,garlic,garment,gas,gasp,gate,gather,gauge,gaze,general,genius,genre,gentle,genuine,gesture,ghost,giant,gift,giggle,ginger,giraffe,girl,give,glad,glance,glare,glass,glide,glimpse,globe,gloom,glory,glove,glow,glue,goat,goddess,gold,good,goose,gorilla,gospel,gossip,govern,gown,grab,grace,grain,grant,grape,grass,gravity,great,green,grid,grief,grit,grocery,group,grow,grunt,guard,guess,guide,guilt,guitar,gun,gym,habit,hair,half,hammer,hamster,hand,happy,harbor,hard,harsh,harvest,hat,have,hawk,hazard,head,health,heart,heavy,hedgehog,height,hello,helmet,help,hen,hero,hidden,high,hill,hint,hip,hire,history,hobby,hockey,hold,hole,holiday,hollow,home,honey,hood,hope,horn,horror,horse,hospital,host,hotel,hour,hover,hub,huge,human,humble,humor,hundred,hungry,hunt,hurdle,hurry,hurt,husband,hybrid,ice,icon,idea,identify,idle,ignore,ill,illegal,illness,image,imitate,immense,immune,impact,impose,improve,impulse,inch,include,income,increase,index,indicate,indoor,industry,infant,inflict,inform,inhale,inherit,initial,inject,injury,inmate,inner,innocent,input,inquiry,insane,insect,inside,inspire,install,intact,interest,into,invest,invite,involve,iron,island,isolate,issue,item,ivory,jacket,jaguar,jar,jazz,jealous,jeans,jelly,jewel,job,join,joke,journey,joy,judge,juice,jump,jungle,junior,junk,just,kangaroo,keen,keep,ketchup,key,kick,kid,kidney,kind,kingdom,kiss,kit,kitchen,kite,kitten,kiwi,knee,knife,knock,know,lab,label,labor,ladder,lady,lake,lamp,language,laptop,large,later,latin,laugh,laundry,lava,law,lawn,lawsuit,layer,lazy,leader,leaf,learn,leave,lecture,left,leg,legal,legend,leisure,lemon,lend,length,lens,leopard,lesson,letter,level,liar,liberty,library,license,life,lift,light,like,limb,limit,link,lion,liquid,list,little,live,lizard,load,loan,lobster,local,lock,logic,lonely,long,loop,lottery,loud,lounge,love,loyal,lucky,luggage,lumber,lunar,lunch,luxury,lyrics,machine,mad,magic,magnet,maid,mail,main,major,make,mammal,man,manage,mandate,mango,mansion,manual,maple,marble,march,margin,marine,market,marriage,mask,mass,master,match,material,math,matrix,matter,maximum,maze,meadow,mean,measure,meat,mechanic,medal,media,melody,melt,member,memory,mention,menu,mercy,merge,merit,merry,mesh,message,metal,method,middle,midnight,milk,million,mimic,mind,minimum,minor,minute,miracle,mirror,misery,miss,mistake,mix,mixed,mixture,mobile,model,modify,mom,moment,monitor,monkey,monster,month,moon,moral,more,morning,mosquito,mother,motion,motor,mountain,mouse,move,movie,much,muffin,mule,multiply,muscle,museum,mushroom,music,must,mutual,myself,mystery,myth,naive,name,napkin,narrow,nasty,nation,nature,near,neck,need,negative,neglect,neither,nephew,nerve,nest,net,network,neutral,never,news,next,nice,night,noble,noise,nominee,noodle,normal,north,nose,notable,note,nothing,notice,novel,now,nuclear,number,nurse,nut,oak,obey,object,oblige,obscure,observe,obtain,obvious,occur,ocean,october,odor,off,offer,office,often,oil,okay,old,olive,olympic,omit,once,one,onion,online,only,open,opera,opinion,oppose,option,orange,orbit,orchard,order,ordinary,organ,orient,original,orphan,ostrich,other,outdoor,outer,output,outside,oval,oven,over,own,owner,oxygen,oyster,ozone,pact,paddle,page,pair,palace,palm,panda,panel,panic,panther,paper,parade,parent,park,parrot,party,pass,patch,path,patient,patrol,pattern,pause,pave,payment,peace,peanut,pear,peasant,pelican,pen,penalty,pencil,people,pepper,perfect,permit,person,pet,phone,photo,phrase,physical,piano,picnic,picture,piece,pig,pigeon,pill,pilot,pink,pioneer,pipe,pistol,pitch,pizza,place,planet,plastic,plate,play,please,pledge,pluck,plug,plunge,poem,poet,point,polar,pole,police,pond,pony,pool,popular,portion,position,possible,post,potato,pottery,poverty,powder,power,practice,praise,predict,prefer,prepare,present,pretty,prevent,price,pride,primary,print,priority,prison,private,prize,problem,process,produce,profit,program,project,promote,proof,property,prosper,protect,proud,provide,public,pudding,pull,pulp,pulse,pumpkin,punch,pupil,puppy,purchase,purity,purpose,purse,push,put,puzzle,pyramid,quality,quantum,quarter,question,quick,quit,quiz,quote,rabbit,raccoon,race,rack,radar,radio,rail,rain,raise,rally,ramp,ranch,random,range,rapid,rare,rate,rather,raven,raw,razor,ready,real,reason,rebel,rebuild,recall,receive,recipe,record,recycle,reduce,reflect,reform,refuse,region,regret,regular,reject,relax,release,relief,rely,remain,remember,remind,remove,render,renew,rent,reopen,repair,repeat,replace,report,require,rescue,resemble,resist,resource,response,result,retire,retreat,return,reunion,reveal,review,reward,rhythm,rib,ribbon,rice,rich,ride,ridge,rifle,right,rigid,ring,riot,ripple,risk,ritual,rival,river,road,roast,robot,robust,rocket,romance,roof,rookie,room,rose,rotate,rough,round,route,royal,rubber,rude,rug,rule,run,runway,rural,sad,saddle,sadness,safe,sail,salad,salmon,salon,salt,salute,same,sample,sand,satisfy,satoshi,sauce,sausage,save,say,scale,scan,scare,scatter,scene,scheme,school,science,scissors,scorpion,scout,scrap,screen,script,scrub,sea,search,season,seat,second,secret,section,security,seed,seek,segment,select,sell,seminar,senior,sense,sentence,series,service,session,settle,setup,seven,shadow,shaft,shallow,share,shed,shell,sheriff,shield,shift,shine,ship,shiver,shock,shoe,shoot,shop,short,shoulder,shove,shrimp,shrug,shuffle,shy,sibling,sick,side,siege,sight,sign,silent,silk,silly,silver,similar,simple,since,sing,siren,sister,situate,six,size,skate,sketch,ski,skill,skin,skirt,skull,slab,slam,sleep,slender,slice,slide,slight,slim,slogan,slot,slow,slush,small,smart,smile,smoke,smooth,snack,snake,snap,sniff,snow,soap,soccer,social,sock,soda,soft,solar,soldier,solid,solution,solve,someone,song,soon,sorry,sort,soul,sound,soup,source,south,space,spare,spatial,spawn,speak,special,speed,spell,spend,sphere,spice,spider,spike,spin,spirit,split,spoil,sponsor,spoon,sport,spot,spray,spread,spring,spy,square,squeeze,squirrel,stable,stadium,staff,stage,stairs,stamp,stand,start,state,stay,steak,steel,stem,step,stereo,stick,still,sting,stock,stomach,stone,stool,story,stove,strategy,street,strike,strong,struggle,student,stuff,stumble,style,subject,submit,subway,success,such,sudden,suffer,sugar,suggest,suit,summer,sun,sunny,sunset,super,supply,supreme,sure,surface,surge,surprise,surround,survey,suspect,sustain,swallow,swamp,swap,swarm,swear,sweet,swift,swim,swing,switch,sword,symbol,symptom,syrup,system,table,tackle,tag,tail,talent,talk,tank,tape,target,task,taste,tattoo,taxi,teach,team,tell,ten,tenant,tennis,tent,term,test,text,thank,that,theme,then,theory,there,they,thing,this,thought,three,thrive,throw,thumb,thunder,ticket,tide,tiger,tilt,timber,time,tiny,tip,tired,tissue,title,toast,tobacco,today,toddler,toe,together,toilet,token,tomato,tomorrow,tone,tongue,tonight,tool,tooth,top,topic,topple,torch,tornado,tortoise,toss,total,tourist,toward,tower,town,toy,track,trade,traffic,tragic,train,transfer,trap,trash,travel,tray,treat,tree,trend,trial,tribe,trick,trigger,trim,trip,trophy,trouble,truck,true,truly,trumpet,trust,truth,try,tube,tuition,tumble,tuna,tunnel,turkey,turn,turtle,twelve,twenty,twice,twin,twist,two,type,typical,ugly,umbrella,unable,unaware,uncle,uncover,under,undo,unfair,unfold,unhappy,uniform,unique,unit,universe,unknown,unlock,until,unusual,unveil,update,upgrade,uphold,upon,upper,upset,urban,urge,usage,use,used,useful,useless,usual,utility,vacant,vacuum,vague,valid,valley,valve,van,vanish,vapor,various,vast,vault,vehicle,velvet,vendor,venture,venue,verb,verify,version,very,vessel,veteran,viable,vibrant,vicious,victory,video,view,village,vintage,violin,virtual,virus,visa,visit,visual,vital,vivid,vocal,voice,void,volcano,volume,vote,voyage,wage,wagon,wait,walk,wall,walnut,want,warfare,warm,warrior,wash,wasp,waste,water,wave,way,wealth,weapon,wear,weasel,weather,web,wedding,weekend,weird,welcome,west,wet,whale,what,wheat,wheel,when,where,whip,whisper,wide,width,wife,wild,will,win,window,wine,wing,wink,winner,winter,wire,wisdom,wise,wish,witness,wolf,woman,wonder,wood,wool,word,work,world,worry,worth,wrap,wreck,wrestle,wrist,write,wrong,yard,year,yellow,you,young,youth,zebra,zero,zone,zoo',',') 21 | GO 22 | SELECT * FROM BipsData 23 | -- 24 | DROP VIEW IF EXISTS VWRAND 25 | GO 26 | CREATE VIEW VWRAND 27 | AS 28 | SELECT RAND() AS RandValue 29 | GO 30 | */ 31 | DROP FUNCTION IF EXISTS GetRandomSentence 32 | GO 33 | CREATE FUNCTION GetRandomSentence(@NoOfWord INT) 34 | RETURNS NVARCHAR(MAX) 35 | AS 36 | BEGIN 37 | DECLARE @Result NVARCHAR(MAX) = '' 38 | DECLARE @BipsLengt INT = 2048 39 | 40 | DECLARE @vCount INT = 0 41 | WHILE @vCount < @NoOfWord 42 | BEGIN 43 | SELECT @Result += RecordText + ' ' 44 | FROM BipsData 45 | WHERE Id = ABS(CHECKSUM((SELECT RandValue FROM VWRAND))) % 2048 46 | 47 | SET @vCount = @vCount + 1 48 | END 49 | 50 | --RESULT 51 | RETURN TRIM(UPPER(LEFT(@Result,1)) + SUBSTRING(@Result,2,LEN(@Result))) 52 | END 53 | /* 54 | SELECT dbo.GetRandomSentence(1) 55 | SELECT dbo.GetRandomSentence(2) 56 | SELECT dbo.GetRandomSentence(3) 57 | */ 58 | -------------------------------------------------------------------------------- /string/GetRandomString.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetRandomString (support to generate 512 characters in maximum) 3 | -- Notes: Run script to create VWRAND to have workaround usage of RAND function 4 | -- OR: convert this to be a stored procedure if you'd like not to create the SQL View 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-06-19 DN Intial 8 | --====================================================== 9 | /* 10 | DROP VIEW IF EXISTS VWRAND 11 | GO 12 | CREATE VIEW VWRAND 13 | AS 14 | SELECT RAND() AS RandValue 15 | GO 16 | */ 17 | DROP FUNCTION IF EXISTS GetRandomString 18 | GO 19 | CREATE FUNCTION GetRandomString (@Length SmallInt = 40, @IncludeNumber Bit = 0, @IncludeSpecialCharacters Bit = 0) 20 | RETURNS varchar(512) 21 | AS 22 | BEGIN 23 | DECLARE @UpperCaseLetters varchar(26) = 'ABCDEFGHIJKLMNOPQRSTUVWXYZ' 24 | DECLARE @LowerCaseLetters varchar(26) = 'abcdefghijklmnopqrstuvwxyz' 25 | DECLARE @NumberLetters varchar(10) = '1234567890' 26 | DECLARE @SpecialLetters varchar(33) = '!"#$%&''()*+,-./:;<=>?@[\]^_`{|}~' 27 | 28 | DECLARE @vSourceLetters varchar(95) = '' 29 | DECLARE @vSourceLettersLen Int = 95 30 | DECLARE @vResult varchar(512) = '' 31 | 32 | SET @vSourceLetters += @UpperCaseLetters 33 | SET @vSourceLetters += @LowerCaseLetters 34 | IF @IncludeNumber = 1 SET @vSourceLetters += @NumberLetters 35 | IF @IncludeSpecialCharacters = 1 SET @vSourceLetters += @SpecialLetters 36 | 37 | SET @vSourceLettersLen = LEN(@vSourceLetters) 38 | 39 | WHILE LEN(@vResult) < @Length 40 | BEGIN 41 | SET @vResult = @vResult + SUBSTRING(@vSourceLetters, (ABS(CHECKSUM((SELECT RandValue FROM VWRAND)))%@vSourceLettersLen)+1, 1) 42 | END 43 | 44 | --RESULT 45 | RETURN @vResult 46 | END 47 | /* 48 | SELECT dbo.GetRandomString(-1 ,0, 0) 49 | SELECT dbo.GetRandomString(0 ,0, 0) 50 | SELECT dbo.GetRandomString(10 ,0, 0) 51 | SELECT dbo.GetRandomString(10 ,1, 0) 52 | SELECT dbo.GetRandomString(512,0, 0) 53 | SELECT dbo.GetRandomString(512,0, 1) 54 | SELECT dbo.GetRandomString(40 ,0, 1) 55 | */ 56 | -------------------------------------------------------------------------------- /string/RegexRemove.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: Regex remove characters that not existing in pattern 3 | -- Result is a table with 1 ROW only 4 | -- Notes: 5 | -- History: 6 | -- Date Author Description 7 | -- 2020-04-22 Dave Intial 8 | --====================================================== 9 | DROP FUNCTION IF EXISTS [dbo].[RegexRemove] 10 | GO 11 | CREATE FUNCTION [dbo].[RegexRemove] (@Input NVARCHAR(4000), @Pattern VARCHAR(256)) 12 | RETURNS TABLE 13 | AS 14 | RETURN 15 | ( 16 | WITH E1(N) AS 17 | ( 18 | SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL 19 | SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL 20 | SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 21 | ) --10E+1 or 10 rows 22 | ,E2(N) AS 23 | ( 24 | SELECT 1 FROM E1 a, E1 b 25 | ) --10E+2 or 100 rows 26 | ,E4(N) AS 27 | ( 28 | SELECT 1 FROM E2 a, E2 b 29 | ) --10E+4 or 10,000 rows max 30 | ,cteTally(N) AS 31 | ( 32 | --==== This provides the "base" CTE and limits the number of rows right up front 33 | -- for both a performance gain and prevention of accidental "overruns" 34 | SELECT TOP (ISNULL(LEN(@Input),0)) ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) FROM E4 35 | ) 36 | SELECT [Output] 37 | FROM 38 | ( 39 | SELECT SUBSTRING(@Input,N,1) 40 | FROM cteTally 41 | WHERE SUBSTRING(@Input,N,1) LIKE '%'+@Pattern+'%' 42 | ORDER BY N 43 | FOR XML PATH('') 44 | ) S ([Output]) 45 | ) 46 | GO 47 | /* 48 | SELECT [Output] FROM [dbo].[RegexRemove] ('ANNDH--Ass+%1826', '[a-zA-Z0-9]') 49 | --Output = ANNDHAss1826 50 | */ -------------------------------------------------------------------------------- /string/ReplaceManyToSingle.sql: -------------------------------------------------------------------------------- 1 | --================================================================================ 2 | -- Usage: Replace any cases of multiple inputs by single input in a string 3 | -- Notes: 4 | -- History: 5 | -- Date Author Description 6 | -- 2019-07-20 DN Intial 7 | --================================================================================ 8 | DROP FUNCTION IF EXISTS ReplaceManyToSingle 9 | GO 10 | CREATE FUNCTION ReplaceManyToSingle(@String nvarchar(max), @SingleInput char(1)) 11 | RETURNS nvarchar(max) 12 | AS 13 | BEGIN 14 | RETURN REPLACE(REPLACE(REPLACE(REPLACE(@String,@SingleInput,'{0}{1}'),'{1}{0}',''),'{1}',''),'{0}',@SingleInput) 15 | END 16 | GO 17 | 18 | /* 19 | SELECT dbo.ReplaceManyToSingle('Thisssssss is one of the bad sentencessssssssssssssssssssssssssss','s')--any multi to single 's' 20 | SELECT dbo.ReplaceManyToSingle('This is one of the bad sentences',' ')--any multi to single space 21 | SELECT dbo.ReplaceManyToSingle('This''''''''''''s one of the sentences which''''''s bad','''')--any multi to single quote 22 | */ 23 | -------------------------------------------------------------------------------- /string/SplitString-less2016.sql: -------------------------------------------------------------------------------- 1 | --============================================================================================================================================= 2 | -- Usage: This is to split string into pieces (supporting earlier 2016 3 | -- Notes: 4 | -- History: 5 | -- Date By Description 6 | -- 2020-04-22 DN Created. 7 | --============================================================================================================================================= 8 | --use CTUser 9 | IF OBJECT_ID('StringSplit', 'IF') IS NOT NULL 10 | DROP FUNCTION dbo.StringSplit 11 | GO 12 | 13 | 14 | CREATE FUNCTION [dbo].[StringSplit] 15 | ( 16 | @Text nvarchar(4000), 17 | @Delimiter char(1) 18 | ) 19 | RETURNS TABLE 20 | AS 21 | RETURN 22 | WITH E1(N) AS 23 | ( 24 | SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL 25 | SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL 26 | SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 27 | ) --10E+1 or 10 rows 28 | ,E2(N) AS 29 | ( 30 | SELECT 1 FROM E1 a, E1 b 31 | ) --10E+2 or 100 rows 32 | ,E4(N) AS 33 | ( 34 | SELECT 1 FROM E2 a, E2 b 35 | ) --10E+4 or 10,000 rows max 36 | ,cteTally(N) AS 37 | ( 38 | --==== This provides the "base" CTE and limits the number of rows right up front 39 | -- for both a performance gain and prevention of accidental "overruns" 40 | SELECT TOP (ISNULL(LEN(@Text),0)) ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) FROM E4 41 | ) 42 | ,cteStart(N1) AS 43 | ( 44 | --==== This returns N+1 (starting position of each "element" just once for each delimiter) 45 | SELECT 1 UNION ALL 46 | SELECT t.N+1 FROM cteTally t WHERE SUBSTRING(@Text,t.N,1) = @Delimiter 47 | ) 48 | ,cteLen(N1,L1) AS 49 | ( 50 | --==== Return start and length (for use in substring) 51 | SELECT s.N1, 52 | ISNULL(NULLIF(CHARINDEX(@Delimiter,@Text,s.N1),0)-s.N1,8000) 53 | FROM cteStart s 54 | ) 55 | SELECT SUBSTRING(@Text, l.N1, l.L1) [Value], 56 | ROW_NUMBER() OVER (ORDER BY l.N1) as Idx 57 | FROM cteLen l 58 | WHERE SUBSTRING(@Text, l.N1, l.L1) != '' 59 | GO 60 | /* 61 | SELECT * FROM dbo.StringSplit('sql1,sql2', ',') 62 | */ -------------------------------------------------------------------------------- /string/SplitString.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: SplitString with supporting value's order returned 3 | -- From SQL 2016 and later 4 | -- Notes: 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-03-29 Dave Intial 8 | --====================================================== 9 | DROP FUNCTION IF EXISTS SplitString 10 | GO 11 | CREATE FUNCTION SplitString(@String nvarchar(max), @Delimiter char(1), @WithOrder bit) 12 | RETURNS @Result TABLE (Piece nvarchar(max), OrderNo int) 13 | AS 14 | BEGIN 15 | INSERT 16 | INTO @Result 17 | ( 18 | Piece, 19 | OrderNo 20 | ) 21 | SELECT value, 22 | CASE 23 | WHEN @WithOrder = 0 THEN NULL 24 | ELSE ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) 25 | END AS OrderNo 26 | FROM STRING_SPLIT(@String, @Delimiter) 27 | 28 | RETURN 29 | END 30 | GO 31 | 32 | /* 33 | SELECT * FROM dbo.SplitString('This,is,a,sentence,splitted by,comma',',',0) 34 | SELECT * FROM dbo.SplitString('This,is,a,sentence,splitted by,comma',',',1) 35 | */ 36 | -------------------------------------------------------------------------------- /string/String2Base64.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: Convert to Base64 3 | -- Notes: 4 | -- History: 5 | -- Date Author Description 6 | -- 2020-05-25 DN Intial 7 | --====================================================== 8 | DROP FUNCTION IF EXISTS String2Base64 9 | GO 10 | CREATE FUNCTION String2Base64(@String nvarchar(max)) 11 | RETURNS nvarchar(max) 12 | AS 13 | BEGIN 14 | RETURN 15 | ( 16 | SELECT CONVERT(XML, N'').value('xs:base64Binary(xs:hexBinary(sql:column("bin")))', 'NVARCHAR(MAX)') AS Base64Encoding 17 | FROM ( 18 | SELECT CONVERT(VARBINARY(MAX),@String) AS bin 19 | ) AS D 20 | ) 21 | END 22 | GO 23 | 24 | /* 25 | SELECT dbo.[String2Base64]('username:password') 26 | */ -------------------------------------------------------------------------------- /string/Trim.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: Remove leading & trailling spaces of a string 3 | -- < SQL 2016 4 | -- Notes: 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-09-19 Dave Intial 8 | --====================================================== 9 | DROP FUNCTION IF EXISTS [Trim] 10 | GO 11 | CREATE FUNCTION [Trim](@String nvarchar(max)) 12 | RETURNS nvarchar(max) 13 | AS 14 | BEGIN 15 | RETURN LTRIM(RTRIM(@String)) 16 | END 17 | GO 18 | 19 | /* 20 | SELECT dbo.[Trim](' This is to be trimmed ') 21 | */ 22 | -------------------------------------------------------------------------------- /utility/CompareTableSchema.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: CompareTableSchema 3 | -- Notes: 4 | -- Parameters: 5 | -- History: 6 | -- Date Author Description 7 | -- 2020-12-24 DN Intial 8 | --====================================================== 9 | DROP PROCEDURE IF EXISTS [CompareTableSchema] 10 | GO 11 | CREATE PROCEDURE [dbo].[CompareTableSchema] @SourceDatabase sysname = NULL, 12 | @SourceSchema sysname = 'dbo', 13 | @SourceTable sysname = '#tSource', 14 | @DestinationDatabase sysname = NULL, 15 | @DestinationSchema sysname = 'dbo', 16 | @DestinationTable sysname = 'Test' 17 | AS 18 | BEGIN 19 | SET NOCOUNT ON 20 | 21 | DECLARE @vSQL nvarchar(4000) 22 | 23 | IF @SourceDatabase IS NULL SET @SourceDatabase = DB_NAME() 24 | IF @DestinationDatabase IS NULL SET @DestinationDatabase = DB_NAME() 25 | 26 | DECLARE @tSSchema TABLE (Name sysname, DataType sysname, MaxLength int, Precision int, Scale int, IsNullable bit) 27 | DECLARE @tDSchema TABLE (Name sysname, DataType sysname, MaxLength int, Precision int, Scale int, IsNullable bit) 28 | 29 | SET @vSQL = FORMATMESSAGE(N'SELECT name,TYPE_NAME(user_type_id) as data_type, max_length, precision, scale, is_nullable FROM %s.sys.columns WHERE Object_ID = OBJECT_ID(''%s.%s.%s'')', @SourceDatabase,@SourceDatabase, @SourceSchema, @SourceTable) 30 | INSERT INTO @tSSchema EXEC sp_executesql @vSQL 31 | 32 | SET @vSQL = FORMATMESSAGE(N'SELECT name,TYPE_NAME(user_type_id) as data_type, max_length, precision, scale, is_nullable FROM %s.sys.columns WHERE Object_ID = OBJECT_ID(''%s.%s.%s'')', @DestinationDatabase,@DestinationDatabase, @DestinationSchema, @DestinationTable) 33 | INSERT INTO @tDSchema EXEC sp_executesql @vSQL 34 | 35 | --RESULT 36 | SELECT FORMATMESSAGE(N'%s column''s data type is differred in %s.%s.%s table comparing to the source one', D.Name, @DestinationDatabase, @DestinationSchema, @DestinationTable) as Messages, 37 | D.Name as ColumnName 38 | FROM @tSSchema S 39 | JOIN @tDSchema D 40 | ON S.Name = D.Name 41 | WHERE S.DataType <> D.DataType 42 | UNION ALL 43 | SELECT FORMATMESSAGE(N'String binary could be truncated in %s column (lenght = %d, expected = %d) of %s.%s.%s table comparing to the source one', D.Name, D.MaxLength, S.MaxLength, @DestinationDatabase, @DestinationSchema, @DestinationTable) as Messages, 44 | D.Name as ColumnName 45 | FROM @tSSchema S 46 | JOIN @tDSchema D 47 | ON S.Name = D.Name 48 | WHERE S.DataType = D.DataType 49 | AND D.MaxLength < S.MaxLength 50 | RETURN 51 | END 52 | /* 53 | Use M1Master 54 | DROP TABLE IF EXISTS #tSource 55 | CREATE TABLE #tSource (FirstName varchar(255), LastName nvarchar(255)) 56 | 57 | DROP TABLE IF EXISTS Destination 58 | CREATE TABLE Destination (FirstName nvarchar(255), LastName nvarchar(250)) 59 | 60 | EXEC [dbo].[CompareTableSchema] @SourceDatabase = 'tempdb', @SourceTable = '#tSource', 61 | @DestinationDatabase = 'M1Master', @DestinationTable = 'Destination' 62 | */ 63 | -------------------------------------------------------------------------------- /utility/DateAddBusinessDays.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: DateAddBusinessDays 3 | -- History: 4 | -- Date Author Description 5 | -- 2020-06-10 DN Intial 6 | --====================================================== 7 | DROP FUNCTION IF EXISTS DateAddBusinessDays 8 | GO 9 | CREATE FUNCTION DateAddBusinessDays 10 | ( 11 | @Days int, 12 | @Date datetime 13 | ) 14 | RETURNS datetime 15 | AS 16 | BEGIN 17 | DECLARE @DayOfWeek int 18 | SET @DayOfWeek = CASE 19 | WHEN @Days < 0 THEN (@@DateFirst + DATEPART(weekday, @Date) - 20) % 7 20 | ELSE (@@DateFirst + DATEPART(weekday, @Date) - 2) % 7 21 | END; 22 | 23 | IF @DayOfWeek = 6 24 | SET @Days = @Days - 1 25 | ELSE IF @DayOfWeek = -6 26 | SET @Days = @Days + 1; 27 | 28 | RETURN @Date + @Days + (@Days + @DayOfWeek) / 5 * 2; 29 | END 30 | /* 31 | SELECT dbo.DateAddBusinessDays(-2,GETDATE()) 32 | SELECT dbo.DateAddBusinessDays(5,GETDATE()) 33 | */ -------------------------------------------------------------------------------- /utility/FileExists.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: Check file path existing 3 | -- Notes: 4 | -- History: 5 | -- Date Author Description 6 | -- 2020-04-24 DN Intial 7 | --====================================================== 8 | DROP FUNCTION IF EXISTS dbo.FileExists 9 | GO 10 | CREATE FUNCTION dbo.FileExists(@Path varchar(512)) 11 | RETURNS BIT 12 | AS 13 | BEGIN 14 | DECLARE @Result INT 15 | EXEC master.dbo.xp_fileexist @Path, @Result OUTPUT 16 | RETURN CAST(@Result as BIT) 17 | END; 18 | GO 19 | 20 | /* 21 | SELECT dbo.FileExists('C:\Temp\textFile.txt') as FileExists 22 | */ -------------------------------------------------------------------------------- /utility/FindStringData.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: FindStringData 3 | -- Notes: Depends on DbExec 4 | -- History: 5 | -- Date Author Description 6 | -- 2020-09-04 DN Intial 7 | --====================================================== 8 | DROP PROCEDURE IF EXISTS dbo.FindStringData 9 | GO 10 | CREATE PROCEDURE dbo.FindStringData @SearchPattern sysname 11 | AS 12 | BEGIN 13 | SET NOCOUNT ON; 14 | 15 | DROP TABLE IF EXISTS ##temp 16 | CREATE TABLE ##temp (ColumnName sysname) 17 | DECLARE @vSQL nvarchar(MAX) = ''; 18 | 19 | SELECT @vSQL += FORMATMESSAGE('IF EXISTS(SELECT TOP 1 1 FROM [%s].[%s] WHERE [%s] LIKE ''%s'') INSERT INTO ##temp (ColumnName) SELECT ''%s'';', 20 | TABLE_SCHEMA, TABLE_NAME, COLUMN_NAME, @SearchPattern, FORMATMESSAGE('[%s].[%s].[%s]', TABLE_SCHEMA, TABLE_NAME, COLUMN_NAME)) 21 | FROM INFORMATION_SCHEMA.COLUMNS 22 | WHERE DATA_TYPE LIKE '%char%'; 23 | 24 | --Searching... 25 | EXEC (@vSQL) 26 | 27 | --RESULT 28 | SELECT * FROM ##temp 29 | 30 | RETURN; 31 | END 32 | GO 33 | 34 | /* 35 | EXEC FindStringData @SearchPattern='%promo%' 36 | */ 37 | 38 | -------------------------------------------------------------------------------- /utility/GetAllDatesInMonth.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetAllDatesInMonth - to get list date 3 | -- Notes: 4 | -- Parameters: 5 | -- History: 6 | -- Date Author Description 7 | -- 2020-07-24 DN Intial 8 | --====================================================== 9 | DROP FUNCTION IF EXISTS GetAllDatesInMonth 10 | GO 11 | CREATE FUNCTION GetAllDatesInMonth 12 | ( 13 | @Date DATE 14 | ) 15 | RETURNS TABLE 16 | AS 17 | RETURN WITH 18 | T4 AS (SELECT 1 N UNION ALL SELECT 1 N UNION ALL SELECT 1 N UNION ALL SELECT 1 N),-- 4 19 | T16 AS (SELECT 1 N FROM T4 x, T4 y),-- 16 20 | Tally AS (SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) N FROM T16 x, T16 y)-- 256 21 | SELECT DATEADD(DAY,N-1,DATEADD(DAY,1-DATEPART(DAY,@Date),@Date)) as [Date] 22 | FROM Tally 23 | WHERE N <= DATEDIFF(DAY, @Date, DATEADD(MONTH, 1, @Date)) 24 | GO 25 | /* 26 | SELECT [Date] FROM dbo.GetAllDatesInMonth('2020-01-01') 27 | SELECT [Date] FROM dbo.GetAllDatesInMonth('2020-02-01') 28 | SELECT [Date] FROM dbo.GetAllDatesInMonth('2020-03-01') 29 | SELECT [Date] FROM dbo.GetAllDatesInMonth('2020-04-01') 30 | SELECT [Date] FROM dbo.GetAllDatesInMonth('2020-05-01') 31 | SELECT [Date] FROM dbo.GetAllDatesInMonth('2020-06-01') 32 | SELECT [Date] FROM dbo.GetAllDatesInMonth('2020-07-01') 33 | SELECT [Date] FROM dbo.GetAllDatesInMonth('2020-08-01') 34 | SELECT [Date] FROM dbo.GetAllDatesInMonth('2020-09-01') 35 | SELECT [Date] FROM dbo.GetAllDatesInMonth('2020-10-01') 36 | SELECT [Date] FROM dbo.GetAllDatesInMonth('2020-11-01') 37 | SELECT [Date] FROM dbo.GetAllDatesInMonth('2020-12-01') 38 | */ -------------------------------------------------------------------------------- /utility/GetCalendar.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetCalendar - to get list date 3 | -- Notes: 4 | -- Parameters: 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-06-24 DN Intial 8 | --====================================================== 9 | DROP FUNCTION IF EXISTS GetCalendar 10 | GO 11 | CREATE FUNCTION GetCalendar 12 | ( 13 | @Date DATE = NULL, 14 | @BackDay INT = 30 15 | ) 16 | RETURNS 17 | @Result TABLE (Id INT, DateValue DATE) 18 | AS 19 | BEGIN 20 | ;WITH cte AS 21 | ( 22 | SELECT TOP (@BackDay) ROW_NUMBER() OVER (ORDER BY s1.[object_id]) AS Id 23 | FROM sys.all_objects AS s1 24 | CROSS JOIN sys.all_objects AS s2 25 | ORDER BY s1.[object_id] 26 | ) 27 | INSERT INTO @Result (Id, DateValue) 28 | SELECT Id, 29 | DATEADD(DAY,-Id,DATEADD(Day,1,COALESCE(@Date,GETDATE()))) 30 | FROM cte 31 | RETURN 32 | END 33 | GO 34 | /* 35 | SELECT * FROM dbo.GetCalendar(default,default)--return date from today back to 30 days 36 | SELECT * FROM dbo.GetCalendar('2019-06-25', 20)--return date from '2019-06-25' back to 20 days 37 | */ -------------------------------------------------------------------------------- /utility/GetDFColumns.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetDFColumns - to get list of Primary Key columns 3 | -- Notes: 4 | -- Parameters: 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-06-24 DN Intial 8 | --====================================================== 9 | DROP FUNCTION IF EXISTS GetDFColumns 10 | GO 11 | CREATE FUNCTION GetDFColumns 12 | ( 13 | @Schema sysname = 'dbo', 14 | @Table sysname 15 | ) 16 | RETURNS @Result TABLE 17 | ( 18 | TableSchema sysname, 19 | TableName sysname, 20 | ColumnName sysname, 21 | ConstraintName sysname 22 | ) 23 | AS 24 | BEGIN 25 | INSERT 26 | INTO @Result 27 | SELECT schemas.name as TABLE_SCHEMA, 28 | tables.name as TABLE_NAME, 29 | all_columns.name as COLUMN_NAME, 30 | default_constraints.name as CONSTRAINT_NAME 31 | FROM sys.all_columns 32 | JOIN sys.tables 33 | ON all_columns.object_id = tables.object_id 34 | JOIN sys.schemas 35 | ON tables.schema_id = schemas.schema_id 36 | JOIN sys.default_constraints 37 | ON all_columns.default_object_id = default_constraints.object_id 38 | WHERE schemas.name = @Schema 39 | AND tables.name = @Table 40 | 41 | RETURN 42 | END 43 | 44 | /* 45 | SELECT * FROM dbo.GetDFColumns(default, 'Tenant') 46 | SELECT * FROM dbo.GetDFColumns(default, 'Tenant-NOT_EXISTS') 47 | */ -------------------------------------------------------------------------------- /utility/GetFakeJSON.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetFakeJson - to get fake data in json format 3 | -- Dependencies: 4 | -- Function string/GetRandomSentence 5 | -- Function utility/GetRandomNumber 6 | -- Function utility/GetRandomDate 7 | -- Notes: From SQL 2016 8 | -- Parameters: 9 | -- History: 10 | -- Date Author Description 11 | -- 2019-09-20 DN Intial 12 | --====================================================== 13 | DROP PROCEDURE IF EXISTS GetFakeJson 14 | GO 15 | CREATE PROCEDURE GetFakeJson @Fields nvarchar(max) /*'Field1, Field2, Field3, Field4'*/, 16 | @FieldTypes nvarchar(max) /*'Number, String, Date, Bit'*/, 17 | @FieldLengths nvarchar(max) = NULL /*'null, 10, null, null' --null used for other type than string*/, 18 | @NoRecord INT = 10, 19 | @Debug BIT = 0 20 | AS 21 | BEGIN 22 | SET NOCOUNT ON 23 | -- 24 | DROP TABLE IF EXISTS ##tResult 25 | CREATE TABLE ##tResult (dummy BIT) 26 | 27 | --Constants 28 | DECLARE @DefaultStringLength varchar(2) = '10' 29 | 30 | --Variables 31 | DECLARE @vSQL nvarchar(max) 32 | DECLARE @vInsertSQL nvarchar(max) 33 | DECLARE @vFields TABLE (Idx INT, Name nvarchar(255)) 34 | DECLARE @vTypes TABLE (Idx INT, Name nvarchar(255)) 35 | DECLARE @vLengths TABLE (Idx INT, Name nvarchar(255)) 36 | DECLARE @vFieldName nvarchar(255) 37 | DECLARE @vFieldType nvarchar(255) 38 | DECLARE @vFieldLength INT 39 | DECLARE @vFieldTypeCalculated nvarchar(255) 40 | DECLARE @vLoop INT = 1 41 | 42 | INSERT INTO @vFields SELECT ROW_NUMBER() OVER (ORDER BY GETDATE()), VALUE FROM STRING_SPLIT(@Fields, ',') 43 | INSERT INTO @vTypes SELECT ROW_NUMBER() OVER (ORDER BY GETDATE()), VALUE FROM STRING_SPLIT(@FieldTypes, ',') 44 | INSERT INTO @vLengths SELECT ROW_NUMBER() OVER (ORDER BY GETDATE()), VALUE FROM STRING_SPLIT(@FieldLengths, ',') 45 | 46 | --CREATE table containing fake data 47 | SET @vInsertSQL = 'INSERT INTO ##tResult (' + @Fields + ') SELECT ' 48 | DECLARE cField CURSOR FOR 49 | SELECT F.Name as FieldName, 50 | COALESCE(T.Name, 'String') as FieldType, 51 | CASE COALESCE(T.Name, 'String') 52 | WHEN 'Date' THEN 'date' 53 | WHEN 'Number' THEN 'int' 54 | WHEN 'Bit' THEN 'bit' 55 | ELSE 'nvarchar(255)'--default to string 56 | END as FieldTypeCalculated, 57 | CONVERT(INT,COALESCE(NULLIF(L.Name,'null'),@DefaultStringLength)) as FieldLength 58 | FROM @vFields F 59 | LEFT JOIN @vTypes T 60 | ON T.Idx = F.Idx 61 | LEFT JOIN @vLengths L 62 | ON L.Idx = F.Idx 63 | 64 | OPEN cField 65 | FETCH NEXT FROM cField INTO @vFieldName, @vFieldType, @vFieldTypeCalculated, @vFieldLength 66 | WHILE @@FETCH_STATUS = 0 67 | BEGIN 68 | SET @vSQL = 'ALTER TABLE ##tResult ADD ' + QUOTENAME(@vFieldName) + ' ' + @vFieldTypeCalculated 69 | IF @Debug = 1 PRINT @vSQL 70 | SET @vInsertSQL += CASE @vFieldType 71 | WHEN 'Number' THEN 'dbo.GetRandomNumber(255),' 72 | WHEN 'Date' THEN 'dbo.GetRandomDate(),' 73 | WHEN 'Bit' THEN 'dbo.GetRandomNumber(2),' 74 | ELSE 'LEFT(dbo.GetRandomSentence('+ CONVERT(varchar, ABS(CHECKSUM(RAND()))%5+1) +'), ' + CONVERT(varchar,@vFieldLength) + '),' 75 | END 76 | EXEC(@vSQL) 77 | 78 | FETCH NEXT FROM cField INTO @vFieldName, @vFieldType, @vFieldTypeCalculated, @vFieldLength 79 | END 80 | CLOSE cField 81 | DEALLOCATE cField 82 | 83 | --INSERT fake data 84 | IF @Debug = 1 PRINT @vInsertSQL 85 | SET @vInsertSQL = LEFT(@vInsertSQL, LEN(@vInsertSQL)-1) 86 | WHILE @vLoop < @NoRecord 87 | BEGIN 88 | EXEC(@vInsertSQL) 89 | SET @vLoop = @vLoop + 1 90 | END 91 | 92 | --REMOVE dummy column 93 | ALTER TABLE ##tResult DROP COLUMN dummy; 94 | 95 | --RESULT HERE-- 96 | IF @Debug = 1 SELECT *FROM ##tResult 97 | SELECT * 98 | FROM ##tResult FOR JSON AUTO, INCLUDE_NULL_VALUES 99 | 100 | RETURN 101 | END 102 | 103 | /* 104 | EXEC dbo.GetFakeJson @Fields = 'Make,Model,Dealership,Yard,SalesPerson,Phone,WalkIn,Email,Other,Total,TestDrives,TestDrivesCount,TestDriveConversion,TestDrivePhoneConversion,TestDriveWalkInConversion,TestDriveEmailConversion,TestDriveOtherConversion,Sales,SalesConversion,SalesPhoneConversion,SalesWalkInConversion,SalesEmailConversion,SalesOtherConversion', 105 | @FieldTypes = 'Number,String,String,Date,Bit,String,String,String,String,String,String,String,Date,String,String,String,String,String,Number,String,String,String,Bit', 106 | --@FieldLengths = 'null,30', 107 | @Debug = 1 108 | 109 | EXEC dbo.GetFakeJson @Fields = 'Make,Model,Dealership,Yard,SalesPerson,Phone,WalkIn,Email,Other,Total,TestDrives,TestDrivesCount,TestDriveConversion,TestDrivePhoneConversion,TestDriveWalkInConversion,TestDriveEmailConversion,TestDriveOtherConversion,Sales,SalesConversion,SalesPhoneConversion,SalesWalkInConversion,SalesEmailConversion,SalesOtherConversion', 110 | @FieldTypes = 'Number,String,String,Date,Bit,String,String,String,String,String,String,String,Date,String,String,String,String,String,Number,String,String,String,Bit', 111 | @Debug = 0 112 | */ 113 | -------------------------------------------------------------------------------- /utility/GetFilesInFolder.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetFilesInFolder 3 | -- Notes: xp_cmdshell needs enabling 4 | -- EXEC sp_configure 'xp_cmdshell', 1 5 | -- RECONFIGURE; 6 | -- Parameters: 7 | -- History: 8 | -- Date Author Description 9 | -- 2019-05-23 DN Intial 10 | --====================================================== 11 | DROP PROCEDURE IF EXISTS GetFilesInFolder 12 | GO 13 | CREATE PROCEDURE [dbo].[GetFilesInFolder] @Folder varchar(256) = NULL, 14 | @MarginIndex INT = 39, 15 | @Debug BIT = 0 16 | AS 17 | BEGIN 18 | SET NOCOUNT ON 19 | DECLARE @vCommand nvarchar(4000) = 'DIR "' + @Folder + '" /A-D /T:W' 20 | 21 | IF OBJECT_ID('tempdb.dbo.#tOutput','U') IS NOT NULL DROP TABLE #tOutput 22 | CREATE TABLE #tOutput (ID INT IDENTITY(1,1), OUTPUT VARCHAR(255) NULL) 23 | 24 | INSERT 25 | INTO #tOutput (OUTPUT) 26 | EXEC master.dbo.xp_cmdshell @vCommand 27 | 28 | IF @Debug = 1 29 | SELECT * FROM #tOutput 30 | 31 | SELECT LTRIM(RTRIM(Q1.FileName)) as FileName, 32 | CONVERT(DATETIME,SUBSTRING(Q1.ModifiedDate,7,4)+'-'+SUBSTRING(Q1.ModifiedDate,4,2)+'-'+SUBSTRING(Q1.ModifiedDate,1,2)+' '+SUBSTRING(Q1.ModifiedDate,12,6)+':00') ModifiedDate 33 | FROM 34 | ( 35 | SELECT SUBSTRING(OUTPUT,1,17) ModifiedDate, 36 | SUBSTRING(OUTPUT,CHARINDEX(' ',OUTPUT,@MarginIndex)+1,LEN(OUTPUT)-CHARINDEX(' ',OUTPUT,@MarginIndex)) FileName 37 | FROM #tOutput 38 | WHERE OUTPUT IS NOT NULL 39 | AND ID > 4 40 | AND ID < (SELECT MAX(id) FROM #tOutput)-2 41 | ) Q1 42 | ORDER BY 2 DESC 43 | 44 | RETURN 45 | END 46 | GO 47 | /* 48 | EXEC dbo.GetFilesInFolder @Folder = 'C:\Temp' 49 | EXEC dbo.GetFilesInFolder @Folder = 'C:\Temp', @MarginIndex = 31 50 | EXEC dbo.GetFilesInFolder @Folder = 'D:\FTP\Temp', @Debug = 1 51 | */ 52 | 53 | 54 | -------------------------------------------------------------------------------- /utility/GetFirstResultSchema.sql: -------------------------------------------------------------------------------- 1 | --================================================================================ 2 | -- Usage: GetFirstResultSchema - to get schema's first result returned from SQL 3 | -- Notes: 4 | -- Parameters: 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-07-08 DN Intial 8 | --================================================================================ 9 | DROP PROCEDURE IF EXISTS GetFirstResultSchema 10 | GO 11 | CREATE PROCEDURE GetFirstResultSchema @TSql nvarchar(max) 12 | AS 13 | BEGIN 14 | EXEC sp_describe_first_result_set @tsql = @TSql 15 | 16 | RETURN 17 | END 18 | GO 19 | /* 20 | EXEC dbo.GetFirstResultSchema 'SELECT * FROM sys.tables' 21 | */ -------------------------------------------------------------------------------- /utility/GetHierachicalTables.sql: -------------------------------------------------------------------------------- 1 | EXEC sp_MSdependencies @intrans = 1 -------------------------------------------------------------------------------- /utility/GetPKColumns.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetPKColumns - to get list of Primary Key columns 3 | -- Notes: 4 | -- Parameters: 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-06-24 DN Intial 8 | --====================================================== 9 | DROP FUNCTION IF EXISTS GetPKColumns 10 | GO 11 | CREATE FUNCTION GetPKColumns 12 | ( 13 | @Schema sysname = 'dbo', 14 | @Table sysname 15 | ) 16 | RETURNS @Result TABLE 17 | ( 18 | TableSchema sysname, 19 | TableName sysname, 20 | ColumnName sysname, 21 | ColumnOrder Int 22 | ) 23 | AS 24 | BEGIN 25 | INSERT 26 | INTO @Result 27 | SELECT T.TABLE_SCHEMA, 28 | T.TABLE_NAME, 29 | C.COLUMN_NAME, 30 | ROW_NUMBER() OVER(ORDER BY C.ORDINAL_POSITION) AS COLUMN_ORDER 31 | FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS T 32 | JOIN INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE CU 33 | ON CU.Constraint_Name = T.Constraint_Name 34 | AND CU.Table_Name = T.Table_Name 35 | JOIN INFORMATION_SCHEMA.COLUMNS C 36 | ON C.TABLE_SCHEMA = T.TABLE_SCHEMA 37 | AND C.TABLE_NAME = T.TABLE_NAME 38 | AND C.COLUMN_NAME = CU.COLUMN_NAME 39 | WHERE T.CONSTRAINT_TYPE = 'PRIMARY KEY' 40 | AND T.TABLE_SCHEMA = @Schema 41 | AND T.TABLE_NAME = @Table 42 | ORDER BY 4 43 | 44 | RETURN 45 | END 46 | 47 | /* 48 | SELECT * FROM dbo.GetPKColumns(default, 'CommandLog') 49 | SELECT * FROM dbo.GetPKColumns(default, 'CommandLog-NOT_EXISTS') 50 | */ -------------------------------------------------------------------------------- /utility/GetRandomDate.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetRandomDate 3 | -- Notes: Run script to create VWRAND to have workaround usage of RAND function 4 | -- OR: convert this to be a stored procedure if you'd like not to create the SQL View 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-09-20 DN Intial 8 | --====================================================== 9 | /* 10 | DROP VIEW IF EXISTS VWRAND 11 | GO 12 | CREATE VIEW VWRAND 13 | AS 14 | SELECT RAND() AS RandValue 15 | GO 16 | */ 17 | DROP FUNCTION IF EXISTS GetRandomDate 18 | GO 19 | CREATE FUNCTION GetRandomDate() 20 | RETURNS Date 21 | AS 22 | BEGIN 23 | DECLARE @vStart DATE = '1980-01-01' 24 | DECLARE @vEnd DATE = GETDATE() 25 | 26 | --RESULT 27 | RETURN DATEADD(DAY, ABS(CHECKSUM((SELECT RandValue FROM VWRAND))) % ( 1 + DATEDIFF(DAY, @vStart ,@vEnd)), @vStart) 28 | END 29 | /* 30 | SELECT dbo.GetRandomDate() 31 | */ -------------------------------------------------------------------------------- /utility/GetRandomNumber.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetRandomNumber 3 | -- Notes: Run script to create VWRAND to have workaround usage of RAND function 4 | -- OR: convert this to be a stored procedure if you'd like not to create the SQL View 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-09-20 DN Intial 8 | --====================================================== 9 | /* 10 | DROP VIEW IF EXISTS VWRAND 11 | GO 12 | CREATE VIEW VWRAND 13 | AS 14 | SELECT RAND() AS RandValue 15 | GO 16 | */ 17 | DROP FUNCTION IF EXISTS GetRandomNumber 18 | GO 19 | CREATE FUNCTION GetRandomNumber(@BaseNumber INT) 20 | RETURNS INT 21 | AS 22 | BEGIN 23 | --RESULT 24 | RETURN ABS(CHECKSUM((SELECT RandValue FROM VWRAND)))%@BaseNumber 25 | END 26 | /* 27 | SELECT dbo.GetRandomNumber(255) 28 | SELECT dbo.GetRandomNumber(2) 29 | */ 30 | -------------------------------------------------------------------------------- /utility/GetTableSize.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetTableSize 3 | -- Notes: 4 | -- Parameters: 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-05-23 DN Intial 8 | --====================================================== 9 | DROP PROCEDURE IF EXISTS GetTableSize 10 | GO 11 | CREATE PROCEDURE [dbo].[GetTableSize] @TableNamePattern varchar(256) = NULL 12 | AS 13 | BEGIN 14 | SET NOCOUNT ON 15 | 16 | SELECT t.name AS TableName, 17 | p.rows AS [Rows], 18 | (SUM(a.total_pages) * 8) AS SizeInBytes, 19 | CAST(((SUM(a.total_pages) * 8) / CAST(1024 AS DECIMAL)) AS NUMERIC(36, 2)) AS SizeInMegaBytes, 20 | CAST(((SUM(a.total_pages) * 8) / CAST(1024 AS DECIMAL) / CAST(1024 AS DECIMAL)) AS NUMERIC(36, 5)) AS SizeInGigaBytes 21 | FROM sys.tables t WITH (NOLOCK) 22 | JOIN sys.indexes i WITH (NOLOCK) 23 | ON t.OBJECT_ID = i.OBJECT_ID 24 | JOIN sys.partitions p WITH (NOLOCK) 25 | ON i.object_id = p.OBJECT_ID 26 | AND i.index_id = p.index_id 27 | JOIN sys.allocation_units a WITH (NOLOCK) 28 | ON p.partition_id = a.container_id 29 | WHERE t.name LIKE @TableNamePattern ESCAPE '\' 30 | AND t.is_ms_shipped = 0 31 | AND a.total_pages > 0 32 | GROUP BY t.name, 33 | p.rows 34 | ORDER BY 3 DESC 35 | 36 | RETURN 37 | END 38 | GO 39 | /* 40 | EXEC GetTableSize '%' --get size of all tables 41 | EXEC GetTableSize @TableNamePattern = 'User%' --get size of tables prefixed by 'User' 42 | EXEC GetTableSize @TableNamePattern = '\_%' --get size of tables prefixed by '_' 43 | */ 44 | -------------------------------------------------------------------------------- /utility/IsIdentityColumn.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: IsIdentityColumn - to return if an identity column 3 | -- Notes: 4 | -- Parameters: 5 | -- History: 6 | -- Date Author Description 7 | -- 2019-06-24 DN Intial 8 | --====================================================== 9 | DROP FUNCTION IF EXISTS IsIdentityColumn 10 | GO 11 | CREATE FUNCTION IsIdentityColumn 12 | ( 13 | @Schema sysname = 'dbo', 14 | @Table sysname, 15 | @Column sysname 16 | ) 17 | RETURNS BIT 18 | AS 19 | BEGIN 20 | RETURN COALESCE(COLUMNPROPERTY(OBJECT_ID(@Schema+'.'+@Table),@Column,'IsIdentity'),0) 21 | END 22 | 23 | /* 24 | SELECT dbo.IsIdentityColumn(default, 'Base01','ID') 25 | SELECT dbo.IsIdentityColumn(default, 'Base02','ID') 26 | */ -------------------------------------------------------------------------------- /utility/Script-FakeDataGeneration.sql: -------------------------------------------------------------------------------- 1 | DECLARE @vTableName sysname = 'Base01' 2 | 3 | ;WITH CTE AS 4 | ( 5 | SELECT UPPER(TABLE_NAME) AS TABLE_NAME, 6 | STRING_AGG(UPPER(COLUMN_NAME),', ') WITHIN GROUP (ORDER BY ORDINAL_POSITION) AS COL_LIST, 7 | STRING_AGG(''''+CASE 8 | WHEN DATA_TYPE LIKE '%char' THEN dbo.GetRandomString(CHARACTER_MAXIMUM_LENGTH,0) 9 | ELSE CONVERT(VARCHAR,CEILING(RAND()*10)) 10 | END+'''',', ') WITHIN GROUP (ORDER BY ORDINAL_POSITION) AS COL_VALUE 11 | FROM INFORMATION_SCHEMA.COLUMNS 12 | WHERE COLUMN_NAME NOT IN ('ID','CREATE_DATE','UPDATE_DATE') 13 | AND TABLE_NAME = @vTableName 14 | GROUP BY TABLE_NAME 15 | ) 16 | SELECT 'INSERT INTO '+TABLE_NAME+' ('+COL_LIST+') VALUES('+COL_VALUE+')' 17 | FROM CTE 18 | UNION ALL 19 | SELECT 'INSERT INTO '+TABLE_NAME+' ('+COL_LIST+') VALUES('+COL_VALUE+')' 20 | FROM CTE 21 | UNION ALL 22 | SELECT 'INSERT INTO '+TABLE_NAME+' ('+COL_LIST+') VALUES('+COL_VALUE+')' 23 | FROM CTE 24 | UNION ALL 25 | SELECT 'INSERT INTO '+TABLE_NAME+' ('+COL_LIST+') VALUES('+COL_VALUE+')' 26 | FROM CTE 27 | UNION ALL 28 | SELECT 'INSERT INTO '+TABLE_NAME+' ('+COL_LIST+') VALUES('+COL_VALUE+')' 29 | FROM CTE 30 | UNION ALL 31 | SELECT 'INSERT INTO '+TABLE_NAME+' ('+COL_LIST+') VALUES('+COL_VALUE+')' 32 | FROM CTE -------------------------------------------------------------------------------- /web-call/API.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: API (supported methods: GET,POST,...) 3 | -- Notes: 4 | -- Dependencies: Required to enable 'show advanced options' and 'Ole Automation Procedures' 5 | /* 6 | sp_configure 'show advanced options', 1; 7 | go 8 | RECONFIGURE; 9 | GO 10 | sp_configure 'Ole Automation Procedures', 1; 11 | GO 12 | RECONFIGURE; 13 | GO 14 | */ 15 | -- History: 16 | -- Date Author Description 17 | -- 2020-05-21 DN Intial 18 | --====================================================== 19 | DROP PROCEDURE IF EXISTS API 20 | GO 21 | CREATE PROCEDURE API @Url varchar(8000), 22 | @Method varchar(5) = 'GET',--POST 23 | @BodyData nvarchar(max) = NULL,--normally json object string : '{"key":"value"}', 24 | @Authorization varchar(8000) = NULL,--Basic auth token, Api key,... 25 | @ContentType varchar(255) = 'application/json'--'application/xml' 26 | AS 27 | BEGIN 28 | SET NOCOUNT ON; 29 | 30 | DECLARE @vWin int --token of WinHttp object 31 | DECLARE @vReturnCode int 32 | DECLARE @tResponse TABLE (ResponseText nvarchar(max)) 33 | 34 | --Creates an instance of WinHttp.WinHttpRequest 35 | --Doc: https://docs.microsoft.com/en-us/windows/desktop/winhttp/winhttp-versions 36 | --Version of 5.0 is no longer supported 37 | EXEC @vReturnCode = sp_OACreate 'WinHttp.WinHttpRequest.5.1',@vWin OUT 38 | IF @vReturnCode <> 0 GOTO EXCEPTION 39 | 40 | --Opens an HTTP connection to an HTTP resource. 41 | --Doc: https://docs.microsoft.com/en-us/windows/desktop/winhttp/iwinhttprequest-open 42 | EXEC @vReturnCode = sp_OAMethod @vWin, 'Open', NULL, @Method/*Method*/, @Url /*Url*/, 'false' /*IsAsync*/ 43 | IF @vReturnCode <> 0 GOTO EXCEPTION 44 | 45 | IF @Authorization IS NOT NULL 46 | BEGIN 47 | EXEC @vReturnCode = sp_OAMethod @vWin, 'SetRequestHeader', NULL, 'Authorization', @Authorization 48 | IF @vReturnCode <> 0 GOTO EXCEPTION 49 | END 50 | 51 | IF @ContentType IS NOT NULL 52 | BEGIN 53 | EXEC @vReturnCode = sp_OAMethod @vWin, 'SetRequestHeader', NULL, 'Content-Type', @ContentType 54 | IF @vReturnCode <> 0 GOTO EXCEPTION 55 | END 56 | 57 | --Sends an HTTP request to an HTTP server. 58 | --Doc: https://docs.microsoft.com/en-us/windows/desktop/winhttp/iwinhttprequest-send 59 | IF @BodyData IS NOT NULL 60 | BEGIN 61 | EXEC @vReturnCode = sp_OAMethod @vWin,'Send', NULL, @BodyData 62 | IF @vReturnCode <> 0 GOTO EXCEPTION 63 | END 64 | ELSE 65 | BEGIN 66 | EXEC @vReturnCode = sp_OAMethod @vWin,'Send' 67 | IF @vReturnCode <> 0 GOTO EXCEPTION 68 | END 69 | 70 | IF @vReturnCode <> 0 GOTO EXCEPTION 71 | 72 | --Get Response text 73 | --Doc: https://docs.microsoft.com/en-us/sql/relational-databases/system-stored-procedures/sp-oagetproperty-transact-sql 74 | INSERT INTO @tResponse (ResponseText) 75 | EXEC @vReturnCode = sp_OAGetProperty @vWin,'ResponseText' 76 | IF @vReturnCode <> 0 GOTO EXCEPTION 77 | 78 | IF @vReturnCode = 0 79 | GOTO RESULT 80 | 81 | EXCEPTION: 82 | BEGIN 83 | DECLARE @tException TABLE 84 | ( 85 | Error binary(4), 86 | Source varchar(8000), 87 | Description varchar(8000), 88 | HelpFile varchar(8000), 89 | HelpID varchar(8000) 90 | ) 91 | 92 | INSERT INTO @tException EXEC sp_OAGetErrorInfo @vWin 93 | INSERT 94 | INTO @tResponse 95 | ( 96 | ResponseText 97 | ) 98 | SELECT ( 99 | SELECT * 100 | FROM @tException 101 | FOR JSON AUTO 102 | ) AS ResponseText 103 | END 104 | 105 | --FINALLY 106 | RESULT: 107 | --Dispose objects 108 | IF @vWin IS NOT NULL 109 | EXEC sp_OADestroy @vWin 110 | 111 | --Result 112 | SELECT * 113 | FROM @tResponse 114 | 115 | RETURN 116 | END 117 | /* 118 | EXEC API @Url = 'http://example.com/' 119 | EXEC API @Method = 'GET', @Url = 'http://dummy.restapiexample.com/api/v1/employees' 120 | 121 | Send Grid Email: 122 | EXEC API @Method = 'POST', 123 | @Url = 'https://api.sendgrid.com/v3/mail/send', 124 | @Authorization = 'Bearer your-api-key', 125 | @ContentType = 'application/json', 126 | @BodyData = '{ 127 | "personalizations": [ 128 | { 129 | "to": [ 130 | { 131 | "email": "your-email@domain" 132 | } 133 | ], 134 | } 135 | ], 136 | "from": { 137 | "email": "noreply@domain", 138 | "name": "No Reply" 139 | }, 140 | "template_id": "your-template_id" 141 | }' 142 | */ 143 | -------------------------------------------------------------------------------- /web-call/ApiCovid19.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: ApiCovid19 3 | -- Notes: Practical exercise of API.sql 4 | -- CAUTION!! This is scripted inside with real tables DROP and CREATE 5 | -- History: 6 | -- Date Author Description 7 | -- 2020-06-11 DN Intial 8 | --====================================================== 9 | DROP PROCEDURE IF EXISTS [dbo].ApiCovid19 10 | GO 11 | CREATE PROCEDURE [dbo].ApiCovid19 @Url varchar(8000) = 'https://api.covid19api.com', 12 | @Method varchar(5) = 'GET',--POST 13 | @ContentType varchar(255) = 'application/json'--'application/xml' 14 | AS 15 | BEGIN 16 | SET NOCOUNT ON; 17 | 18 | DECLARE @vWin int --token of WinHttp object 19 | DECLARE @vReturnCode int 20 | DECLARE @tResponse TABLE (ResponseText nvarchar(max)) 21 | DECLARE @vResponse nvarchar(max) 22 | 23 | --Creates an instance of WinHttp.WinHttpRequest 24 | --Doc: https://docs.microsoft.com/en-us/windows/desktop/winhttp/winhttp-versions 25 | --Version of 5.0 is no longer supported 26 | EXEC @vReturnCode = sp_OACreate 'WinHttp.WinHttpRequest.5.1',@vWin OUT 27 | IF @vReturnCode <> 0 GOTO EXCEPTION 28 | 29 | --Opens an HTTP connection to an HTTP resource. 30 | --Doc: https://docs.microsoft.com/en-us/windows/desktop/winhttp/iwinhttprequest-open 31 | EXEC @vReturnCode = sp_OAMethod @vWin, 'Open', NULL, @Method/*Method*/, @Url /*Url*/, 'false' /*IsAsync*/ 32 | IF @vReturnCode <> 0 GOTO EXCEPTION 33 | 34 | IF @ContentType IS NOT NULL 35 | BEGIN 36 | EXEC @vReturnCode = sp_OAMethod @vWin, 'SetRequestHeader', NULL, 'Content-Type', @ContentType 37 | IF @vReturnCode <> 0 GOTO EXCEPTION 38 | END 39 | 40 | --Sends an HTTP request to an HTTP server. 41 | --Doc: https://docs.microsoft.com/en-us/windows/desktop/winhttp/iwinhttprequest-send 42 | EXEC @vReturnCode = sp_OAMethod @vWin,'Send' 43 | IF @vReturnCode <> 0 GOTO EXCEPTION 44 | 45 | --Get Response text 46 | --Doc: https://docs.microsoft.com/en-us/sql/relational-databases/system-stored-procedures/sp-oagetproperty-transact-sql 47 | INSERT INTO @tResponse (ResponseText) 48 | EXEC @vReturnCode = sp_OAGetProperty @vWin,'ResponseText' 49 | IF @vReturnCode <> 0 GOTO EXCEPTION 50 | 51 | IF @vReturnCode = 0 52 | GOTO RESULT 53 | 54 | EXCEPTION: 55 | BEGIN 56 | DECLARE @tException TABLE 57 | ( 58 | Error binary(4), 59 | Source varchar(8000), 60 | Description varchar(8000), 61 | HelpFile varchar(8000), 62 | HelpID varchar(8000) 63 | ) 64 | 65 | INSERT INTO @tException EXEC sp_OAGetErrorInfo @vWin 66 | INSERT 67 | INTO @tResponse 68 | ( 69 | ResponseText 70 | ) 71 | SELECT ( 72 | SELECT * 73 | FROM @tException 74 | FOR JSON AUTO 75 | ) AS ResponseText 76 | END 77 | 78 | --FINALLY 79 | RESULT: 80 | 81 | --Crawling Routes 82 | SELECT @vResponse = ResponseText 83 | FROM @tResponse 84 | 85 | DROP TABLE IF EXISTS ApiCovid19Route 86 | CREATE TABLE ApiCovid19Route 87 | ( 88 | RouteName nvarchar(255), 89 | Name nvarchar(255), 90 | Description nvarchar(4000), 91 | Path nvarchar(255) 92 | ) 93 | 94 | INSERT 95 | INTO ApiCovid19Route 96 | SELECT N'allRoute' as RouteName,Name,Description,Path 97 | FROM OPENJSON(@vResponse) 98 | WITH (Name nvarchar(255) N'$.allRoute.Name', Description nvarchar(4000) N'$.allRoute.Description', Path nvarchar(255) N'$.allRoute.Path') 99 | UNION ALL 100 | SELECT N'countriesRoute' as RouteName,Name,Description,Path 101 | FROM OPENJSON(@vResponse) 102 | WITH (Name nvarchar(255) N'$.countriesRoute.Name', Description nvarchar(4000) N'$.countriesRoute.Description', Path nvarchar(255) N'$.countriesRoute.Path') 103 | UNION ALL 104 | SELECT N'countryDayOneRoute' as RouteName,Name,Description,Path 105 | FROM OPENJSON(@vResponse) 106 | WITH (Name nvarchar(255) N'$.countryDayOneRoute.Name', Description nvarchar(4000) N'$.countryDayOneRoute.Description', Path nvarchar(255) N'$.countryDayOneRoute.Path') 107 | UNION ALL 108 | SELECT N'countryDayOneTotalRoute' as RouteName,Name,Description,Path 109 | FROM OPENJSON(@vResponse) 110 | WITH (Name nvarchar(255) N'$.countryDayOneTotalRoute.Name', Description nvarchar(4000) N'$.countryDayOneTotalRoute.Description', Path nvarchar(255) N'$.countryDayOneTotalRoute.Path') 111 | UNION ALL 112 | SELECT N'countryRoute' as RouteName,Name,Description,Path 113 | FROM OPENJSON(@vResponse) 114 | WITH (Name nvarchar(255) N'$.countryRoute.Name', Description nvarchar(4000) N'$.countryRoute.Description', Path nvarchar(255) N'$.countryRoute.Path') 115 | UNION ALL 116 | SELECT N'countryStatusDayOneLiveRoute' as RouteName,Name,Description,Path 117 | FROM OPENJSON(@vResponse) 118 | WITH (Name nvarchar(255) N'$.countryStatusDayOneLiveRoute.Name', Description nvarchar(4000) N'$.countryStatusDayOneLiveRoute.Description', Path nvarchar(255) N'$.countryStatusDayOneLiveRoute.Path') 119 | UNION ALL 120 | SELECT N'countryStatusDayOneRoute' as RouteName,Name,Description,Path 121 | FROM OPENJSON(@vResponse) 122 | WITH (Name nvarchar(255) N'$.countryStatusDayOneRoute.Name', Description nvarchar(4000) N'$.countryStatusDayOneRoute.Description', Path nvarchar(255) N'$.countryStatusDayOneRoute.Path') 123 | UNION ALL 124 | SELECT N'countryStatusDayOneTotalRoute' as RouteName,Name,Description,Path 125 | FROM OPENJSON(@vResponse) 126 | WITH (Name nvarchar(255) N'$.countryStatusDayOneTotalRoute.Name', Description nvarchar(4000) N'$.countryStatusDayOneTotalRoute.Description', Path nvarchar(255) N'$.countryStatusDayOneTotalRoute.Path') 127 | UNION ALL 128 | SELECT N'countryStatusLiveRoute' as RouteName,Name,Description,Path 129 | FROM OPENJSON(@vResponse) 130 | WITH (Name nvarchar(255) N'$.countryStatusLiveRoute.Name', Description nvarchar(4000) N'$.countryStatusLiveRoute.Description', Path nvarchar(255) N'$.countryStatusLiveRoute.Path') 131 | UNION ALL 132 | SELECT N'countryStatusRoute' as RouteName,Name,Description,Path 133 | FROM OPENJSON(@vResponse) 134 | WITH (Name nvarchar(255) N'$.countryStatusRoute.Name', Description nvarchar(4000) N'$.countryStatusRoute.Description', Path nvarchar(255) N'$.countryStatusRoute.Path') 135 | UNION ALL 136 | SELECT N'countryStatusTotalRoute' as RouteName,Name,Description,Path 137 | FROM OPENJSON(@vResponse) 138 | WITH (Name nvarchar(255) N'$.countryStatusTotalRoute.Name', Description nvarchar(4000) N'$.countryStatusTotalRoute.Description', Path nvarchar(255) N'$.countryStatusTotalRoute.Path') 139 | UNION ALL 140 | SELECT N'countryTotalRoute' as RouteName,Name,Description,Path 141 | FROM OPENJSON(@vResponse) 142 | WITH (Name nvarchar(255) N'$.countryTotalRoute.Name', Description nvarchar(4000) N'$.countryTotalRoute.Description', Path nvarchar(255) N'$.countryTotalRoute.Path') 143 | UNION ALL 144 | SELECT N'exportRoute' as RouteName,Name,Description,Path 145 | FROM OPENJSON(@vResponse) 146 | WITH (Name nvarchar(255) N'$.exportRoute.Name', Description nvarchar(4000) N'$.exportRoute.Description', Path nvarchar(255) N'$.exportRoute.Path') 147 | UNION ALL 148 | SELECT N'liveCountryRoute' as RouteName,Name,Description,Path 149 | FROM OPENJSON(@vResponse) 150 | WITH (Name nvarchar(255) N'$.liveCountryRoute.Name', Description nvarchar(4000) N'$.liveCountryRoute.Description', Path nvarchar(255) N'$.liveCountryRoute.Path') 151 | UNION ALL 152 | SELECT N'liveCountryStatusAfterDateRoute' as RouteName,Name,Description,Path 153 | FROM OPENJSON(@vResponse) 154 | WITH (Name nvarchar(255) N'$.liveCountryStatusAfterDateRoute.Name', Description nvarchar(4000) N'$.liveCountryStatusAfterDateRoute.Description', Path nvarchar(255) N'$.liveCountryStatusAfterDateRoute.Path') 155 | UNION ALL 156 | SELECT N'liveCountryStatusRoute' as RouteName,Name,Description,Path 157 | FROM OPENJSON(@vResponse) 158 | WITH (Name nvarchar(255) N'$.liveCountryStatusRoute.Name', Description nvarchar(4000) N'$.liveCountryStatusRoute.Description', Path nvarchar(255) N'$.liveCountryStatusRoute.Path') 159 | UNION ALL 160 | SELECT N'summaryRoute' as RouteName,Name,Description,Path 161 | FROM OPENJSON(@vResponse) 162 | WITH (Name nvarchar(255) N'$.summaryRoute.Name', Description nvarchar(4000) N'$.summaryRoute.Description', Path nvarchar(255) N'$.summaryRoute.Path') 163 | UNION ALL 164 | SELECT N'webhookRoute' as RouteName,Name,Description,Path 165 | FROM OPENJSON(@vResponse) 166 | WITH (Name nvarchar(255) N'$.webhookRoute.Name', Description nvarchar(4000) N'$.webhookRoute.Description', Path nvarchar(255) N'$.webhookRoute.Path') 167 | 168 | --Crawling COuntries 169 | DROP TABLE IF EXISTS ApiCovid19Countries 170 | CREATE TABLE ApiCovid19Countries 171 | ( 172 | Country nvarchar(255), 173 | Slug nvarchar(255), 174 | ISO2 varchar(2) 175 | ) 176 | 177 | DECLARE @vRoute nvarchar(255) 178 | SELECT @vRoute = @Url + Path 179 | FROM ApiCovid19Route 180 | WHERE RouteName = 'countriesRoute' 181 | PRINT 'GET ' + @vRoute 182 | 183 | EXEC @vReturnCode = sp_OAMethod @vWin, 'Open', NULL, @Method/*Method*/, @vRoute /*Url*/, 'false' /*IsAsync*/ 184 | IF @vReturnCode <> 0 GOTO EXCEPTION 185 | EXEC @vReturnCode = sp_OAMethod @vWin, 'SetRequestHeader', NULL, 'Content-Type', @ContentType 186 | IF @vReturnCode <> 0 GOTO EXCEPTION 187 | EXEC @vReturnCode = sp_OAMethod @vWin,'Send' 188 | IF @vReturnCode <> 0 GOTO EXCEPTION 189 | DELETE FROM @tResponse 190 | INSERT INTO @tResponse (ResponseText) 191 | EXEC @vReturnCode = sp_OAGetProperty @vWin,'ResponseText' 192 | IF @vReturnCode <> 0 GOTO EXCEPTION 193 | SELECT @vResponse = ResponseText 194 | FROM @tResponse 195 | 196 | INSERT 197 | INTO ApiCovid19Countries 198 | SELECT Country,Slug,ISO2 199 | FROM OPENJSON(@vResponse) 200 | WITH (Country nvarchar(255) N'$.Country', Slug nvarchar(255) N'$.Slug', ISO2 varchar(2) N'$.ISO2') 201 | 202 | --Crawling countryDayOneRoute 203 | DECLARE @vCountry nvarchar(255) 204 | DROP TABLE IF EXISTS ApiCovid19CountryDayOne 205 | CREATE TABLE ApiCovid19CountryDayOne 206 | ( 207 | Country nvarchar(255), 208 | CountryCode varchar(10), 209 | Province nvarchar(255), 210 | City nvarchar(255), 211 | CityCode nvarchar(255), 212 | Lat decimal(10,7), 213 | Lon decimal(10,7), 214 | Confirmed decimal(17,2), 215 | Deaths decimal(17,2), 216 | Recovered decimal(17,2), 217 | Active decimal(17,2), 218 | Date DateTime 219 | ) 220 | Declare c CURSOR FOR 221 | SELECT Slug 222 | FROM ApiCovid19Countries 223 | ORDER BY 1 224 | OPEN c 225 | FETCH NEXT FROM c INTO @vCountry 226 | WHILE @@FETCH_STATUS = 0 227 | BEGIN 228 | SELECT TOP 1 @vRoute = @Url + LEFT(Path, CHARINDEX(':',Path,1)-1) + @vCountry 229 | FROM ApiCovid19Route 230 | WHERE RouteName = 'countryDayOneRoute' 231 | PRINT 'GET ' + @vRoute 232 | 233 | EXEC @vReturnCode = sp_OAMethod @vWin, 'Open', NULL, @Method/*Method*/, @vRoute /*Url*/, 'false' /*IsAsync*/ 234 | IF @vReturnCode <> 0 GOTO EXCEPTION 235 | EXEC @vReturnCode = sp_OAMethod @vWin, 'SetRequestHeader', NULL, 'Content-Type', @ContentType 236 | IF @vReturnCode <> 0 GOTO EXCEPTION 237 | EXEC @vReturnCode = sp_OAMethod @vWin,'Send' 238 | IF @vReturnCode <> 0 GOTO EXCEPTION 239 | DELETE FROM @tResponse 240 | INSERT INTO @tResponse (ResponseText) 241 | EXEC @vReturnCode = sp_OAGetProperty @vWin,'ResponseText' 242 | IF @vReturnCode <> 0 GOTO EXCEPTION 243 | SELECT @vResponse = ResponseText 244 | FROM @tResponse 245 | 246 | INSERT 247 | INTO ApiCovid19CountryDayOne 248 | SELECT Country,CountryCode,Province,City,CityCode,Lat,Lon,Confirmed,Deaths,Recovered,Active,Date 249 | FROM OPENJSON(@vResponse) 250 | WITH ( 251 | Country nvarchar(255) N'$.Country', 252 | CountryCode varchar(10) N'$.CountryCode', 253 | Province nvarchar(255) N'$.Province', 254 | City nvarchar(255) N'$.City', 255 | CityCode nvarchar(255) N'$.CityCode', 256 | Lat decimal(10,7) N'$.Lat', 257 | Lon decimal(10,7) N'$.Lon', 258 | Confirmed decimal(17,2) N'$.Confirmed', 259 | Deaths decimal(17,2) N'$.Deaths', 260 | Recovered decimal(17,2) N'$.Recovered', 261 | Active decimal(17,2) N'$.Active', 262 | Date DateTime N'$.Date' 263 | ) 264 | 265 | 266 | FETCH NEXT FROM c INTO @vCountry 267 | END 268 | CLOSE c 269 | DEALLOCATE c 270 | 271 | --Crawling summaryRoute 272 | DROP TABLE IF EXISTS ApiCovid19Summary 273 | CREATE TABLE ApiCovid19Summary 274 | ( 275 | Country nvarchar(255), 276 | CountryCode varchar(2), 277 | Slug nvarchar(255), 278 | NewConfirmed INT, 279 | TotalConfirmed INT, 280 | NewDeaths INT, 281 | TotalDeaths INT, 282 | NewRecovered INT, 283 | TotalRecovered INT, 284 | Date DATETIME 285 | ) 286 | 287 | SET @vRoute = '' 288 | SELECT @vRoute = @Url + Path 289 | FROM ApiCovid19Route 290 | WHERE RouteName = 'summaryRoute' 291 | PRINT 'GET ' + @vRoute 292 | 293 | EXEC @vReturnCode = sp_OAMethod @vWin, 'Open', NULL, @Method/*Method*/, @vRoute /*Url*/, 'false' /*IsAsync*/ 294 | IF @vReturnCode <> 0 GOTO EXCEPTION 295 | EXEC @vReturnCode = sp_OAMethod @vWin, 'SetRequestHeader', NULL, 'Content-Type', @ContentType 296 | IF @vReturnCode <> 0 GOTO EXCEPTION 297 | EXEC @vReturnCode = sp_OAMethod @vWin,'Send' 298 | IF @vReturnCode <> 0 GOTO EXCEPTION 299 | DELETE FROM @tResponse 300 | INSERT INTO @tResponse (ResponseText) 301 | EXEC @vReturnCode = sp_OAGetProperty @vWin,'ResponseText' 302 | IF @vReturnCode <> 0 GOTO EXCEPTION 303 | SELECT @vResponse = ResponseText 304 | FROM @tResponse 305 | 306 | INSERT 307 | INTO ApiCovid19Summary 308 | SELECT 'Global' as Country,NULL as CountryCode, NULL as Slug,NewConfirmed,TotalConfirmed,NewDeaths,TotalDeaths,NewRecovered,TotalRecovered,Date 309 | FROM OPENJSON(@vResponse) 310 | WITH ( 311 | NewConfirmed INT N'$.Global.NewConfirmed', 312 | TotalConfirmed INT N'$.Global.TotalConfirmed', 313 | NewDeaths INT N'$.Global.NewDeaths', 314 | TotalDeaths INT N'$.Global.TotalDeaths', 315 | NewRecovered INT N'$.Global.NewRecovered', 316 | TotalRecovered INT N'$.Global.TotalRecovered', 317 | Date DATETIME N'$.Global.Date' 318 | ) 319 | UNION ALL 320 | SELECT Country,CountryCode,Slug,NewConfirmed,TotalConfirmed,NewDeaths,TotalDeaths,NewRecovered,TotalRecovered,Date 321 | FROM OPENJSON(@vResponse) 322 | WITH ( 323 | CountryJson nvarchar(max) N'$.Countries' AS JSON 324 | ) as C 325 | CROSS APPLY OPENJSON (C.CountryJson) 326 | WITH ( 327 | Country nvarchar(255) N'$.Country', 328 | CountryCode varchar(2) N'$.CountryCode', 329 | Slug nvarchar(255) N'$.Slug', 330 | NewConfirmed INT N'$.NewConfirmed', 331 | TotalConfirmed INT N'$.TotalConfirmed', 332 | NewDeaths INT N'$.NewDeaths', 333 | TotalDeaths INT N'$.TotalDeaths', 334 | NewRecovered INT N'$.NewRecovered', 335 | TotalRecovered INT N'$.TotalRecovered', 336 | Date DATETIME N'$.Date' 337 | ) as CD 338 | 339 | --Dispose objects 340 | IF @vWin IS NOT NULL 341 | EXEC sp_OADestroy @vWin 342 | 343 | RETURN 344 | END 345 | GO 346 | /* 347 | EXEC ApiCovid19 348 | 349 | SELECT * FROM ApiCovid19Route 350 | SELECT * FROM ApiCovid19Countries 351 | SELECT TOP 100 * FROM ApiCovid19CountryDayOne ORDER BY DATE DESC 352 | SELECT * FROM ApiCovid19Summary ORDER BY DATE DESC 353 | */ 354 | 355 | 356 | -------------------------------------------------------------------------------- /web-call/GetHttpRequest.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetHttpRequest 3 | -- Notes: 4 | -- Dependencies: Required to enable 'show advanced options' and 'Ole Automation Procedures' 5 | -- sp_configure 'show advanced options', 1; 6 | -- go 7 | -- RECONFIGURE; 8 | -- GO 9 | -- sp_configure 'Ole Automation Procedures', 1; 10 | -- GO 11 | -- RECONFIGURE; 12 | -- GO 13 | -- 14 | -- History: 15 | -- Date Author Description 16 | -- 2019-04-08 DN Intial 17 | --====================================================== 18 | IF OBJECT_ID('GetHttpRequest', 'FN') IS NOT NULL 19 | DROP FUNCTION GetHttpRequest 20 | GO 21 | CREATE FUNCTION GetHttpRequest(@Url varchar(8000), @StatusOnly Bit = 0) 22 | RETURNS nvarchar(max) 23 | AS 24 | BEGIN 25 | DECLARE @vWin int --token of WinHttp object 26 | DECLARE @vReturnCode int 27 | DECLARE @vResponse varchar(8000) 28 | DECLARE @vPropertyName varchar(128) 29 | 30 | SET @Url = Replace(@Url,'%20',' ') 31 | SET @vPropertyName = Case WHEN @StatusOnly = 0 THEN 'ResponseText' ELSE 'StatusText' END 32 | 33 | --Creates an instance of WinHttp.WinHttpRequest 34 | --Doc: https://docs.microsoft.com/en-us/windows/desktop/winhttp/winhttp-versions 35 | --Version of 5.0 is no longer supported 36 | EXEC @vReturnCode = sp_OACreate 'WinHttp.WinHttpRequest.5.1',@vWin OUT 37 | IF @vReturnCode <> 0 EXEC sp_OAGetErrorInfo @vWin 38 | 39 | --Opens an HTTP connection to an HTTP resource. 40 | --Doc: https://docs.microsoft.com/en-us/windows/desktop/winhttp/iwinhttprequest-open 41 | EXEC @vReturnCode = sp_OAMethod @vWin, 'Open', NULL, 'GET'/*Method*/, @Url /*Url*/, 'false' /*IsAsync*/ 42 | IF @vReturnCode <> 0 EXEC sp_OAGetErrorInfo @vWin 43 | 44 | --Sends an HTTP request to an HTTP server. 45 | --Doc: https://docs.microsoft.com/en-us/windows/desktop/winhttp/iwinhttprequest-send 46 | EXEC @vReturnCode = sp_OAMethod @vWin,'Send' 47 | IF @vReturnCode <> 0 EXEC sp_OAGetErrorInfo @vWin 48 | 49 | --Get Response text 50 | --Doc: https://docs.microsoft.com/en-us/sql/relational-databases/system-stored-procedures/sp-oagetproperty-transact-sql 51 | EXEC @vReturnCode = sp_OAGetProperty @vWin,@vPropertyName,@vResponse OUTPUT 52 | IF @vReturnCode <> 0 EXEC sp_OAGetErrorInfo @vWin 53 | 54 | --Dispose objects 55 | EXEC @vReturnCode = sp_OADestroy @vWin 56 | IF @vReturnCode <> 0 EXEC sp_OAGetErrorInfo @vWin 57 | 58 | --RESULT 59 | RETURN @vResponse 60 | END 61 | /* 62 | select dbo.GetHttpRequest('http://example.com/',0) 63 | select dbo.GetHttpRequest('http://dummy.restapiexample.com/api/v1/employees',0) 64 | */ 65 | -------------------------------------------------------------------------------- /web-call/async/APIAsync.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: APIAsync 3 | -- Notes: 4 | -- Dependencies: Required to enable 'show advanced options' and 'Ole Automation Procedures' 5 | /* 6 | sp_configure 'show advanced options', 1; 7 | go 8 | RECONFIGURE; 9 | GO 10 | sp_configure 'Ole Automation Procedures', 1; 11 | GO 12 | RECONFIGURE; 13 | GO 14 | */ 15 | -- History: 16 | -- Date Author Description 17 | -- 2020-05-21 DN Intial 18 | --====================================================== 19 | DROP PROCEDURE IF EXISTS APIAsync 20 | GO 21 | CREATE PROCEDURE APIAsync @Url varchar(8000), 22 | @Method varchar(5) = 'GET',--POST 23 | @BodyData nvarchar(max) = NULL,--normally json object string : '{"key":"value"}', 24 | @Authorization varchar(8000) = NULL,--Basic auth token, APIAsync key,... 25 | @ContentType varchar(255) = 'application/json'--'application/xml' 26 | AS 27 | BEGIN 28 | SET NOCOUNT ON; 29 | 30 | DECLARE @vWin int --token of WinHttp object 31 | DECLARE @vReturnCode int 32 | DECLARE @tResponse TABLE (ResponseText nvarchar(4000)) 33 | 34 | -- NOTE: Maximum 256 instances. NO MORE!. Ref: https://docs.microsoft.com/en-us/windows/win32/wmisdk/creating-an-instance 35 | EXEC @vReturnCode = sp_OACreate 'WinHttp.WinHttpRequest.5.1',@vWin OUT 36 | IF @vReturnCode <> 0 GOTO EXCEPTION 37 | 38 | -- This section can be put in a loop 39 | -- Store Win object into a temp table 40 | PRINT 'Win = ' + CONVERT(varchar(255), @vWin) 41 | SELECT @vReturnCode = dbo.SendAsync(@vWin, @Url, @Method, @BodyData, @Authorization, @ContentType) 42 | IF @vReturnCode <> 0 GOTO EXCEPTION 43 | 44 | 45 | -- This section can be put in a loop 46 | -- Process for each Win object from the temp table 47 | PRINT 'Get response by Win = ' + CONVERT(varchar(255), @vWin) 48 | INSERT 49 | INTO @tResponse 50 | SELECT ResponseText 51 | FROM dbo.GetResponseAsync(@vWin) 52 | WHERE ResponseText IS NOT NULL 53 | 54 | IF @vReturnCode = 0 55 | GOTO RESULT 56 | 57 | EXCEPTION: 58 | BEGIN 59 | DECLARE @tException TABLE 60 | ( 61 | Error binary(4), 62 | Source varchar(8000), 63 | Description varchar(8000), 64 | HelpFile varchar(8000), 65 | HelpID varchar(8000) 66 | ) 67 | 68 | INSERT INTO @tException EXEC sp_OAGetErrorInfo @vWin 69 | INSERT 70 | INTO @tResponse 71 | ( 72 | ResponseText 73 | ) 74 | SELECT ( 75 | SELECT * 76 | FROM @tException 77 | FOR JSON AUTO 78 | ) AS ResponseText 79 | END 80 | 81 | --FINALLY 82 | RESULT: 83 | --Dispose objects 84 | IF @vWin IS NOT NULL 85 | EXEC sp_OADestroy @vWin 86 | 87 | --Result 88 | SELECT * 89 | FROM @tResponse 90 | 91 | RETURN 92 | END 93 | /* 94 | EXEC APIAsync @Method = 'GET', @Url = 'http://dummy.restapiexample.com/api/v1/employees' 95 | EXEC API @Method = 'GET', @Url = 'http://dummy.restapiexample.com/api/v1/employees' 96 | 97 | */ 98 | -------------------------------------------------------------------------------- /web-call/async/GetResponseAsync.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: GetResponseAsync 3 | -- Notes: 4 | -- Dependencies: Required to enable 'show advanced options' and 'Ole Automation Procedures' 5 | /* 6 | sp_configure 'show advanced options', 1; 7 | go 8 | RECONFIGURE; 9 | GO 10 | sp_configure 'Ole Automation Procedures', 1; 11 | GO 12 | RECONFIGURE; 13 | GO 14 | */ 15 | -- History: 16 | -- Date Author Description 17 | -- 2020-05-21 DN Intial 18 | --====================================================== 19 | DROP FUNCTION IF EXISTS GetResponseAsync 20 | GO 21 | CREATE FUNCTION GetResponseAsync (@Win INT) 22 | RETURNS @Result TABLE (Win INT, ResponseText nvarchar(4000)) 23 | AS 24 | BEGIN 25 | DECLARE @vResponse nvarchar(4000) 26 | DECLARE @vTimeoutSec INT = 60 27 | DECLARE @vSuccess BIT = 0 28 | 29 | --Wait 30 | EXEC sp_OAMethod @Win, 'WaitForResponse', NULL, @vTimeoutSec, @vSuccess OUT 31 | 32 | --Response 33 | IF @vSuccess IS NOT NULL 34 | BEGIN 35 | EXEC sp_OAGetProperty @Win,'ResponseText', @vResponse OUT 36 | INSERT INTO @Result SELECT @Win, @vResponse 37 | END 38 | 39 | IF @Win IS NOT NULL EXEC sp_OADestroy @Win 40 | 41 | RETURN 42 | END 43 | /* 44 | -- See APIAsync 45 | */ 46 | -------------------------------------------------------------------------------- /web-call/async/SendAsync.sql: -------------------------------------------------------------------------------- 1 | --====================================================== 2 | -- Usage: SendAsync 3 | -- Notes: 4 | -- Dependencies: Required to enable 'show advanced options' and 'Ole Automation Procedures' 5 | /* 6 | sp_configure 'show advanced options', 1; 7 | go 8 | RECONFIGURE; 9 | GO 10 | sp_configure 'Ole Automation Procedures', 1; 11 | GO 12 | RECONFIGURE; 13 | GO 14 | */ 15 | -- History: 16 | -- Date Author Description 17 | -- 2020-06-17 DN Intial 18 | --====================================================== 19 | DROP FUNCTION IF EXISTS SendAsync 20 | GO 21 | CREATE FUNCTION SendAsync ( 22 | @Win INT, 23 | @Url varchar(8000), 24 | @Method varchar(5) = 'GET',--POST 25 | @BodyData nvarchar(max) = NULL,--normally json object string : '{"key":"value"}', 26 | @Authorization varchar(8000) = NULL,--Basic auth token, SendAsync key,... 27 | @ContentType varchar(255) = 'application/json'--'application/xml' 28 | ) 29 | RETURNS INT 30 | AS 31 | BEGIN 32 | DECLARE @vReturnCode int 33 | DECLARE @tResponse TABLE (ResponseText nvarchar(max)) 34 | 35 | EXEC @vReturnCode = sp_OAMethod @Win, 'Open', NULL, @Method/*Method*/, @Url /*Url*/, 'true' /*IsAsync*/ 36 | IF @vReturnCode <> 0 GOTO RESULT 37 | 38 | IF @Authorization IS NOT NULL 39 | BEGIN 40 | EXEC @vReturnCode = sp_OAMethod @Win, 'SetRequestHeader', NULL, 'Authorization', @Authorization 41 | IF @vReturnCode <> 0 GOTO RESULT 42 | END 43 | 44 | IF @ContentType IS NOT NULL 45 | BEGIN 46 | EXEC @vReturnCode = sp_OAMethod @Win, 'SetRequestHeader', NULL, 'Content-Type', @ContentType 47 | IF @vReturnCode <> 0 GOTO RESULT 48 | END 49 | 50 | IF @BodyData IS NOT NULL 51 | BEGIN 52 | EXEC @vReturnCode = sp_OAMethod @Win,'Send', NULL, @BodyData 53 | IF @vReturnCode <> 0 GOTO RESULT 54 | END 55 | ELSE 56 | BEGIN 57 | EXEC @vReturnCode = sp_OAMethod @Win,'Send' 58 | IF @vReturnCode <> 0 GOTO RESULT 59 | END 60 | 61 | RESULT: 62 | RETURN @vReturnCode 63 | END 64 | /* 65 | -- See APIAsync 66 | */ 67 | --------------------------------------------------------------------------------