diff --git a/CreateALogBackupToAzureBlobStorage_OutilDUrgence.sql b/CreateALogBackupToAzureBlobStorage_OutilDUrgence.sql new file mode 100644 index 0000000..e304a7a --- /dev/null +++ b/CreateALogBackupToAzureBlobStorage_OutilDUrgence.sql @@ -0,0 +1,108 @@ +SET NOCOUNT ON + +-- Backup all databases already backuped in Azure. +-- Script is mirroring aware +-- Do not run the script within the same second otherwise backupschain could be mixed up and unuseable + + +-- The script won't work if any of the following is true: +-- - The database has never been backup yet to Azure using smart backups +-- - The database had a guid fork and no backup was yet done to Azure using smart backups +-- - Smart backup configuration is not set properly +-- - Azure Data storage does not exist +-- - Database recovery model is not set to FULL + + +------------------------------------------------------ +-- Start configuration section + +DECLARE @IsFullBackup AS BIT = 0 -- 0 = Log backup, 1 = Full backup + +-- End configuration section +------------------------------------------------------ + + +-- Validation + +IF (@IsFullBackup IS NULL) +BEGIN + RAISERROR ('Configuration @IsFullBackup cannot be NULL. Allowed configuration: 0 = Log backup, 1 = Full backup.', 16, 1) + RETURN +END + + + +-- Do not change the remainder configuration + +DECLARE @DebugMode AS BIT = 0 + +DECLARE @StorageURLPrefix AS NVARCHAR(MAX) = 'https://' +DECLARE @StorageURLSuffixe AS NVARCHAR(MAX) = '.blob.core.windows.net/' + +DECLARE @BackupFileExtension AS NVARCHAR(3) = 'log' +DECLARE @BackupCommandType AS NVARCHAR(8) = 'LOG' +DECLARE @BackupHeaderNameBackupType AS NVARCHAR(4) = 'LOG' + +DECLARE @QueryToExecuteBackup AS NVARCHAR(MAX) +DECLARE @CurrentDateForBackup AS DATETIME2(0) = GETDATE() +DECLARE @FormattedCurrentDateForBackup AS NVARCHAR(25) = FORMAT(@CurrentDateForBackup, 'yyyyMMddHHmmss') + +DECLARE @GuidLength AS INT = 32 + + + +IF (@IsFullBackup = 1) +BEGIN + SET @BackupFileExtension = 'bak' + SET @BackupCommandType = 'DATABASE' + SET @BackupHeaderNameBackupType = 'FULL' +END + +SELECT + @QueryToExecuteBackup = CONCAT(@QueryToExecuteBackup, +' +BACKUP ', @BackupCommandType, ' [', frmGetDBUrl.[name], '] TO URL = N''', frmGetDBUrl.FullFileNameToUrl ,''' WITH CREDENTIAL = N''AutoBackup_Credential'' , NOFORMAT, NOINIT, NAME = N''', frmGetDBUrl.[name], '-', @BackupHeaderNameBackupType, ' Database Backup'', NOSKIP, NOREWIND, NOUNLOAD, COMPRESSION, STATS = 10, CHECKSUM') + +FROM ( + + SELECT + databases.[name] + , CONCAT(@StorageURLPrefix, caGetLastestBackupInfo.AzureStorageKey, @StorageURLSuffixe, LOWER(@@SERVERNAME), '-mssqlserver/', databases.[name], '_', caGetLastestBackupInfo.LastestBackupGUID, '_', @FormattedCurrentDateForBackup, LEFT(RIGHT(SYSDATETIMEOFFSET(), 6), 3), '.', @BackupFileExtension) AS 'FullFileNameToUrl' + + FROM + sys.databases + + CROSS APPLY ( + + SELECT TOP 1 + SUBSTRING(backupmediafamily.physical_device_name, PATINDEX(CONCAT('%', backupset.database_name, '_%'), backupmediafamily.physical_device_name) + LEN(backupset.database_name) + 1, 32) AS 'LastestBackupGUID' + , SUBSTRING(backupmediafamily.physical_device_name, LEN(@StorageURLPrefix) + 1, PATINDEX(CONCAT('%', @StorageURLSuffixe, '%'), backupmediafamily.physical_device_name) - LEN(@StorageURLPrefix) - 1) AS 'AzureStorageKey' + + FROM + msdb.dbo.backupmediafamily + + INNER JOIN msdb.dbo.backupset + ON msdb.dbo.backupmediafamily.media_set_id = msdb.dbo.backupset.media_set_id + + WHERE + backupset.database_name = databases.[name] + AND backupmediafamily.physical_device_name LIKE CONCAT(@StorageURLPrefix, '%') + AND backupset.is_copy_only = 0 + + ORDER BY + backupset.backup_finish_date DESC + + ) caGetLastestBackupInfo + + WHERE + databases.state_desc = 'ONLINE' + AND databases.recovery_model_desc = 'FULL' + +) frmGetDBUrl +OPTION (RECOMPILE) + + +PRINT @QueryToExecuteBackup +PRINT '' +IF (@DebugMode = 0) EXEC sp_executeSQL @QueryToExecuteBackup + diff --git a/Fondation_Anonymized.sql b/Fondation_Anonymized.sql new file mode 100644 index 0000000..f018735 --- /dev/null +++ b/Fondation_Anonymized.sql @@ -0,0 +1,41 @@ +--** Script Fondation_Anonymized + +SET XACT_ABORT ON +SET NOCOUNT ON + + + +IF(DB_NAME() NOT LIKE '%Foundation') +BEGIN + RAISERROR ('This is not a foundation database.', 16, 1) + RETURN +END + + + +BEGIN TRANSACTION + + +UPDATE dbo.[Provider] + SET ProviderDetails.modify('replace value of (/Provider/Values/UserName/text())[1] with "azure_44af00f85254c176fe9605819c2ab3e8@azure.com"') +WHERE + [Provider].[name] = 'SmtpMailProvider' and [Provider].[ImplementationTypeName] = 'SmtpMailProvider' + +UPDATE dbo.[Provider] + SET ProviderDetails.modify('replace value of (/Provider/Values/Password/text())[1] with "3ye3bSOqMcVi8mr7"') +WHERE + [Provider].[name] = 'SmtpMailProvider' and [Provider].[ImplementationTypeName] = 'SmtpMailProvider' + +UPDATE dbo.[Provider] + SET ProviderDetails.modify('replace value of (/Provider/Values/SenderAddress/text())[1] with "Customer COmpany Name Test <no-reply-test@Company.ca>"') +WHERE + [Provider].[name] = 'SmtpMailProvider' and [Provider].[ImplementationTypeName] = 'SmtpMailProvider' + +UPDATE dbo.[Provider] + SET ProviderDetails.modify('replace value of (/Provider/Values/TemporaryPassword/text())[1] with "Qwerty123!"') +WHERE + [Provider].[name] = 'AzureDirectoryProvider' and [Provider].[ImplementationTypeName] = 'AzureDirectoryProvider' + +COMMIT +GO + diff --git a/Order_Anonymized.sql b/Order_Anonymized.sql new file mode 100644 index 0000000..80a6805 --- /dev/null +++ b/Order_Anonymized.sql @@ -0,0 +1,138 @@ +--** Script Order_Anonymized + +SET XACT_ABORT ON +SET NOCOUNT ON + + +--************************************************************* +-- *** Configuration Section +-- *** Modify the variables in this section foy your needs +--************************************************************* + + + +-- START OF CONFIGURATION SECTION + +-- *********************************************************************************************** +-- *********************************************************************************************** + +-- Did you ran Profile_Anonymized.sql first? + +-- Nothing to configure here, +-- Will run with the choice of one or all customer_id selected in the Profile_Anonymized script + +-- END OF CONFIGURATION SECTION + +-- *********************************************************************************************** +-- *********************************************************************************************** + + + + + + + + + + + + +-- ******************************** +-- *** Start of Program +-- ******************************** + + + +--*********************************************************** +-- *** If not connected to the right Database, script exits +-- ********************************************************** +IF(DB_NAME() NOT LIKE '%Order') +BEGIN + RAISERROR ('This is not an order database.', 16, 1) + RETURN +END + + + +--**************************************************************** +-- *** If no CustomerProfileToAnonymize table found, script exists +-- *************************************************************** +IF OBJECT_ID('tempdb..##CustomerProfileToAnonymize') IS NULL +BEGIN + RAISERROR ('You have to run Profile_Anonymized script first', 16, 1) + RETURN +END + + + +-- ********************************************************************************** +-- *** Update the ORDER table to anonymized colums related to customer(s) selected +-- ********************************************************************************** +UPDATE [ORDER] SET + [ORDER].Email = CONCAT(CustomerProfileToAnonymize.CustomerEntityName, ' ', [ORDER].OrderNumber, CustomerProfileToAnonymize.AnonymizedFakeEmailSuffixe) + , [ORDER].CustomerPhone = CustomerProfileToAnonymize.AnonymizedPhoneNumber + , [ORDER].CustomerName = CONCAT(CustomerProfileToAnonymize.CustomerEntityName, ' ', [ORDER].OrderNumber) + +FROM + dbo.[ORDER] + +INNER JOIN + ##CustomerProfileToAnonymize CustomerProfileToAnonymize + ON CustomerProfileToAnonymize.Id = [ORDER].Customer_Id +OPTION (RECOMPILE) + + + + +-- ***************************************************************************************** +-- *** Update the SHIPMENTADDRESS table to anonymized colums related to customer(s) selected +-- ***************************************************************************************** +UPDATE SHIPMENTADDRESS SET + SHIPMENTADDRESS.LastName = CONCAT(CustomerProfileToAnonymize.CustomerEntityName, ' ', SHIPMENTADDRESS.TransactionOrderNumber) + , SHIPMENTADDRESS.FirstName = CONCAT(CustomerProfileToAnonymize.CustomerEntityName, ' ', SHIPMENTADDRESS.TransactionOrderNumber) + , SHIPMENTADDRESS.PhoneNumber = CustomerProfileToAnonymize.AnonymizedPhoneNumber + +FROM + dbo.SHIPMENTADDRESS + +INNER JOIN + dbo.[ORDER] + ON [ORDER].TransactionOrderNumber = SHIPMENTADDRESS.TransactionOrderNumber + +INNER JOIN + ##CustomerProfileToAnonymize CustomerProfileToAnonymize + ON CustomerProfileToAnonymize.Id = [ORDER].Customer_Id +OPTION (RECOMPILE) + + + + +-- **************************************************************************************** +-- *** Update the PAYMENTADDRESS table to anonymized colums related to customer(s) selected +-- **************************************************************************************** +UPDATE PAYMENTADDRESS SET + PAYMENTADDRESS.LastName = CONCAT(CustomerProfileToAnonymize.CustomerEntityName, ' ', PAYMENTADDRESS.TransactionOrderNumber) + , PAYMENTADDRESS.FirstName = CONCAT(CustomerProfileToAnonymize.CustomerEntityName, ' ', PAYMENTADDRESS.TransactionOrderNumber) + , PAYMENTADDRESS.PhoneNumber = CustomerProfileToAnonymize.AnonymizedPhoneNumber + +FROM + dbo.PAYMENTADDRESS + +INNER JOIN + dbo.[ORDER] + ON [ORDER].TransactionOrderNumber = PAYMENTADDRESS.TransactionOrderNumber + +INNER JOIN + ##CustomerProfileToAnonymize CustomerProfileToAnonymize + ON CustomerProfileToAnonymize.Id = [ORDER].Customer_Id + + + + +-- ************************************************************* +-- *** The temporary table CustomerProfileToAnonymize is dropped +-- *** It is no longger needed +-- ************************************************************* +IF OBJECT_ID('tempdb..##CustomerProfileToAnonymize') IS NOT NULL + DROP TABLE ##CustomerProfileToAnonymize +GO diff --git a/PanoptaSQLSmartBackupCheck.sql b/PanoptaSQLSmartBackupCheck.sql new file mode 100644 index 0000000..fceefd8 --- /dev/null +++ b/PanoptaSQLSmartBackupCheck.sql @@ -0,0 +1,64 @@ +DECLARE @TimeBeforeExpiration AS DATETIME2(3) = DATEADD(HOUR, -24, GETDATE()) + +SELECT + databases.name AS 'DatabaseName' + , CASE WHEN oaBackupExist.Exist = 1 THEN 1 ELSE 0 END AS 'UseableBackupExist' + +FROM + sys.databases + +OUTER APPLY ( + + SELECT TOP 1 + 1 AS 'Exist' + , fab.backup_finish_date + + FROM + msdb.smart_admin.fn_available_backups(databases.name) fab + + WHERE + fab.backup_finish_date >= @TimeBeforeExpiration + + ORDER BY + fab.backup_finish_date DESC + +) oaGetBackupStatus + +OUTER APPLY ( + + SELECT TOP 1 + 1 AS 'Exist' + , smart_backup_files.backup_finish_date + + FROM + msdb.dbo.smart_backup_files + + WHERE + smart_backup_files.[status] = 'A' + AND smart_backup_files.database_name = databases.name + AND smart_backup_files.backup_finish_date >= @TimeBeforeExpiration + + ORDER BY + smart_backup_files.last_modified_utc DESC + +) oaBackupExist + +WHERE + databases.state_desc = 'ONLINE' + AND ( + databases.[name] LIKE '%foundation' OR + databases.[name] LIKE '%marketing' OR + databases.[name] LIKE '%membership' OR + databases.[name] LIKE '%messaging' OR + databases.[name] LIKE '%order' OR + databases.[name] LIKE '%pickandpack' OR + databases.[name] LIKE '%pnp' OR + databases.[name] LIKE '%product' OR + databases.[name] LIKE '%profile' OR + databases.[name] LIKE '%Archive' OR + databases.[name] LIKE '%Reporting' OR + databases.[name] LIKE '%DataWarehouse' + ) + +ORDER BY + databases.[name] \ No newline at end of file diff --git a/Profile_Anonymized.sql b/Profile_Anonymized.sql new file mode 100644 index 0000000..a83824e --- /dev/null +++ b/Profile_Anonymized.sql @@ -0,0 +1,394 @@ +--** Script Profile_Anonymized + + +SET XACT_ABORT ON +SET NOCOUNT ON + + +-- ************************************************************* +-- *** Configuration Section +-- *** Modify the variables in this section foy your needs +-- ************************************************************* + + + +-- START OF CONFIGURATION SECTION + +-- *********************************************************************************************** +-- *********************************************************************************************** + +-- ************************************************************* +-- *** Choose 1 or All customer to be Anonymize *** +-- *** 1 = Specify 1 Customer +-- *** 2 = All Customers +-- ************************************************************* + +DECLARE @CustomerSelection INT = 1 + + + + +-- ************************************************************* +-- *** Specify the ID of the customer to be Anonymize +-- *** If you don't have the Customer_ID, you can do select the Customer_ID from the table Customer +-- *** including the info you have in the search criteria of the where clause +-- *** ex: select Customer_Id from Customer where email=' ' +-- *** or: select Customer_Id from Customer where FirstName=' ' and LastName= ' ' +-- +-- If the script is halted because of a deadlock or locking, re-run it +-- +-- At least only one row must be needed for a particular customer +-- Make sure to correctly uniquely identify the customer +-- Fields requires to be precise, no wildcard accepted +-- +-- If you want all customer to be anonymized, you must enter the value 2 for +-- the variable @CustomerSelection just one step up of this scipt +-- The variable @Customer_IdToAnonymize won't be taken into account. +-- ************************************************************* + +DECLARE @Customer_IdToAnonymize INT = + + + + +-- END OF CONFIGURATION SECTION + +-- *********************************************************************************************** +-- *********************************************************************************************** + + + + + + + + +-- **************************************************************** +-- Values that will be use for the columns to be anonymized +-- The following customer fields are anonymized: +-- 'Username', 'FirstName', 'LastName', 'PhoneNumber', 'Email', +-- 'CellNumber', 'PhoneNumberWork', 'FaxNumber' +-- **************************************************************** +DECLARE @AnonymizedPhoneNumber AS VARCHAR(32) = '555-555-5555' +DECLARE @AnonymizedFakeEmailSuffixe AS NVARCHAR(64) = '@orckestrafake.com' +DECLARE @AnonymizedAuditNewValueSuffixe AS NVARCHAR(128) = 'Anonymized Audit NewValue' +DECLARE @AnonymizedAuditOldValueSuffixe AS NVARCHAR(128) = 'Anonymized Audit OldValue' +DECLARE @AnonymizedCustomerPrefix AS NVARCHAR(16) = @CustomerEntityName + + +DECLARE @DisableProfileChanges INT = 1 + + + +-- *************************************************** +-- *** The name of the entity for Customer +-- *************************************************** +DECLARE @CustomerEntityName AS SYSNAME = 'CUSTOMER' + + +-- *************************************************** +-- *** The name of the entity for Address +-- *************************************************** +DECLARE @AddressEntityName AS SYSNAME = 'ADDRESS' + + + + + + + + + +-- ******************************** +-- *** Start of Program +-- ******************************** + + +--*********************************************************** +-- *** If not connected to the right Database, script exits +-- ********************************************************** +IF(DB_NAME() NOT LIKE '%Profile') +BEGIN + RAISERROR ('This is not a profile database.', 16, 1) + RETURN +END + + +-- ******************************************************************** +-- *** If the value of @CustomerSelection is not valid, exit the script +-- ******************************************************************** +IF (@CustomerSelection != 2 AND @CustomerSelection ! = 1) +BEGIN + RAISERROR ('The value enter for @CustomerSelection is not valid', 16, 1) + RETURN +END + + + +-- ************************************************************* +-- *** Creating the temporary table(##CustomerProfileToAnonymize) +-- *** to contain the customer_ID(s) to be Anonymize +-- *** The columns to be anonymized are added to the table +-- *** The table is dropped before creating it +-- ************************************************************* + +IF OBJECT_ID('tempdb..##CustomerProfileToAnonymize') IS NOT NULL + DROP TABLE ##CustomerProfileToAnonymize + + +CREATE TABLE ##CustomerProfileToAnonymize ( + Customer_Id INT NOT NULL + , Id UNIQUEIDENTIFIER NOT NULL + , UserName NVARCHAR(256) NULL + , FirstName NVARCHAR(64) NULL + , LastName NVARCHAR(64) NULL + , Email NVARCHAR(256) NULL + , PhoneNumber VARCHAR(32) NULL + , CellNumber VARCHAR(32) NULL + , PhoneNumberWork VARCHAR(32) NULL + , FaxNumber VARCHAR(32) NULL + , AnonymizedPhoneNumber VARCHAR(32) NOT NULL + , AnonymizedFakeEmailSuffixe NVARCHAR(64) NOT NULL + , CustomerEntityName SYSNAME NOT NULL + , PRIMARY KEY CLUSTERED (Customer_Id) + , UNIQUE NONCLUSTERED (Id) +) + + +-- ************************************************************* +-- *** Inserting in a temporary table(##CustomerProfileToAnonymize) +-- *** the customer ID(s) to be Anonymize +-- ************************************************************* + +BEGIN + INSERT INTO ##CustomerProfileToAnonymize + SELECT + CUSTOMER.Customer_Id + , CUSTOMER.Id + , CUSTOMER.UserName + , CUSTOMER.FirstName + , CUSTOMER.LastName + , CUSTOMER.Email + , CUSTOMER.PhoneNumber + , CUSTOMER.CellNumber + , CUSTOMER.PhoneNumberWork + , CUSTOMER.FaxNumber + , @AnonymizedPhoneNumber + , @AnonymizedFakeEmailSuffixe + , @CustomerEntityName + + FROM + dbo.CUSTOMER + + WHERE + (CUSTOMER.CUSTOMER_Id = @Customer_IdToAnonymize AND @CustomerSelection = 1) + OR + @CustomerSelection = 2 + OPTION(RECOMPILE) +END + + + + + + +--*********************************************************** +-- *** If no Customer found for the selection, script exists +-- ********************************************************** +IF NOT EXISTS (select 1 from ##CustomerProfileToAnonymize) +BEGIN + RAISERROR ('No Customer selected or database does not contain any customer', 16, 1) + RETURN +END + + +DECLARE @QueryToExecute AS NVARCHAR(MAX) +DECLARE @NumberOfRowChanged INT = 1; +DECLARE @CurrentMessageToDisplay AS NVARCHAR(MAX); + + + + +--*********************************************************** +-- *** Disabling triggers on Customer and Address entities +-- ********************************************************** +IF (@DisableProfileChanges = 1) +BEGIN + SET @QueryToExecute = CONCAT('DISABLE TRIGGER ALL ON dbo.[', @AddressEntityName, ']') + EXEC sp_executeSQL @QueryToExecute + + SET @QueryToExecute = CONCAT('DISABLE TRIGGER ALL ON dbo.', @CustomerEntityName) + EXEC sp_executeSQL @QueryToExecute +END + + + + + +--********************************************************************************** +-- *** Update the Address table to anonymized columns related to customer(s) selected +-- ********************************************************************************* +UPDATE [ADDRESS] + SET [ADDRESS].LastName = SUBSTRING(CONCAT(@AnonymizedCustomerPrefix, [ADDRESS].Address_Id), 0, 64) + , [ADDRESS].FirstName = SUBSTRING(CONCAT(@AnonymizedCustomerPrefix, [ADDRESS].Address_Id), 0, 64) + , [ADDRESS].PhoneNumber = CustomerProfileToAnonymize.AnonymizedPhoneNumber + +FROM + dbo.[ADDRESS] + +INNER JOIN + dbo.RELATIONSHIP + ON RELATIONSHIP.Child_Id = [ADDRESS].Address_Id + +INNER JOIN + dbo.ENTITY parentEntity + ON parentEntity.Entity_Id = RELATIONSHIP.ParentEntity_Id + +INNER JOIN + dbo.ENTITY childEntity + ON childEntity.Entity_Id = RELATIONSHIP.ChildEntity_Id + +INNER JOIN + ##CustomerProfileToAnonymize CustomerProfileToAnonymize + ON CustomerProfileToAnonymize.Customer_Id = RELATIONSHIP.Parent_Id + +WHERE + parentEntity.EntityName = @CustomerEntityName + AND childEntity.EntityName = @AddressEntityName +OPTION (RECOMPILE) + + +SET @NumberOfRowChanged = @@ROWCOUNT; + +SET @CurrentMessageToDisplay = CONCAT('Number of sanitanized address rows: ', @NumberOfRowChanged) +RAISERROR (@CurrentMessageToDisplay, 0, 1) WITH NOWAIT + + + + + +--********************************************************************************** +-- *** Update the Customer table to anonymized colums related to customer(s) selected +-- ********************************************************************************* +UPDATE CUSTOMER + SET CUSTOMER.Email = CONCAT(@AnonymizedCustomerPrefix, CUSTOMER.Customer_Id, CustomerProfileToAnonymize.AnonymizedFakeEmailSuffixe) + , CUSTOMER.Username = CONCAT(@AnonymizedCustomerPrefix, CUSTOMER.Customer_Id) + , CUSTOMER.FirstName = CONCAT(@AnonymizedCustomerPrefix, CUSTOMER.Customer_Id) + , CUSTOMER.LastName = CONCAT(@AnonymizedCustomerPrefix, CUSTOMER.Customer_Id) + , CUSTOMER.PhoneNumber = CustomerProfileToAnonymize.AnonymizedPhoneNumber + , CUSTOMER.CellNumber = CustomerProfileToAnonymize.AnonymizedPhoneNumber + , CUSTOMER.PhoneNumberWork = CustomerProfileToAnonymize.AnonymizedPhoneNumber + , CUSTOMER.FaxNumber = CustomerProfileToAnonymize.AnonymizedPhoneNumber + +FROM + dbo.CUSTOMER + +INNER JOIN + ##CustomerProfileToAnonymize CustomerProfileToAnonymize + ON CustomerProfileToAnonymize.Customer_Id = CUSTOMER.Customer_Id + +OPTION (RECOMPILE) + + +SET @NumberOfRowChanged = @@ROWCOUNT; +SET @CurrentMessageToDisplay = CONCAT('Number of sanitanized customer rows: ', @NumberOfRowChanged) +RAISERROR (@CurrentMessageToDisplay, 0, 1) WITH NOWAIT + + + + + +--********************************************************************************** +-- Update the Audit table to anonymized colums related to the customer EntityName +-- audit changes of the selected customer(s) +-- Filter by the columnName : +-- 'Username', 'FirstName', 'LastName', 'PhoneNumber', 'Email', +-- 'CellNumber', 'PhoneNumberWork', 'FaxNumber' +--********************************************************************************** +UPDATE [AUDIT] SET + [AUDIT].OldValue = CASE WHEN [AUDIT].Operation IN ('U', 'D') THEN CONCAT([AUDIT].TableName, ': ', @AnonymizedAuditNewValueSuffixe) ELSE NULL END + , [AUDIT].NewValue = CASE WHEN [AUDIT].Operation IN ('I', 'U') THEN CONCAT([AUDIT].TableName, ': ', @AnonymizedAuditOldValueSuffixe) ELSE NULL END + +FROM + [Audit].[AUDIT] + +INNER JOIN + ##CustomerProfileToAnonymize CustomerProfileToAnonymize + ON CustomerProfileToAnonymize.Id = [AUDIT].[Entity_Id] + +WHERE + [AUDIT].TableName = @CustomerEntityName + AND [AUDIT].ColumnName IN ('Username', 'FirstName', 'LastName', 'PhoneNumber', 'Email', 'CellNumber', 'PhoneNumberWork', 'FaxNumber') +OPTION (RECOMPILE) + + +SET @NumberOfRowChanged = @@ROWCOUNT; + +SET @CurrentMessageToDisplay = CONCAT('Number of sanitanized customer audit rows: ', @NumberOfRowChanged) +RAISERROR (@CurrentMessageToDisplay, 0, 1) WITH NOWAIT + + + + +--******************************************************************************************* +-- Update the Audit table to anonymized colums related to the Address table +-- audit changes of the selected customer(s) +-- Filter by the columnName : +-- 'Username', 'FirstName', 'LastName', 'PhoneNumber', 'Email', +-- 'CellNumber', 'PhoneNumberWork', 'FaxNumber' +--******************************************************************************************* +UPDATE [AUDIT] SET + [AUDIT].OldValue = CASE WHEN [AUDIT].Operation IN ('U', 'D') THEN CONCAT([AUDIT].TableName, ': ', @AnonymizedAuditNewValueSuffixe) ELSE NULL END + , [AUDIT].NewValue = CASE WHEN [AUDIT].Operation IN ('I', 'U') THEN CONCAT([AUDIT].TableName, ': ', @AnonymizedAuditOldValueSuffixe) ELSE NULL END + +FROM + [Audit].[AUDIT] + +INNER JOIN + dbo.[ADDRESS] + ON [ADDRESS].Id = [AUDIT].[Entity_Id] + +INNER JOIN + dbo.RELATIONSHIP + ON RELATIONSHIP.Child_Id = [ADDRESS].Address_Id + +INNER JOIN + dbo.ENTITY parentEntity + ON parentEntity.Entity_Id = RELATIONSHIP.ParentEntity_Id + +INNER JOIN + dbo.ENTITY childEntity + ON childEntity.Entity_Id = RELATIONSHIP.ChildEntity_Id + +INNER JOIN + ##CustomerProfileToAnonymize CustomerProfileToAnonymize + ON CustomerProfileToAnonymize.Customer_Id = RELATIONSHIP.Parent_Id + +WHERE + parentEntity.EntityName = @CustomerEntityName + AND childEntity.EntityName = @AddressEntityName + AND [AUDIT].TableName = @AddressEntityName + AND [AUDIT].ColumnName IN ('FirstName', 'LastName', 'PhoneNumber') +OPTION (RECOMPILE) + + +SET @NumberOfRowChanged = @@ROWCOUNT; +SET @CurrentMessageToDisplay = CONCAT('Number of sanitanized address audit rows: ', @NumberOfRowChanged) +RAISERROR (@CurrentMessageToDisplay, 0, 1) WITH NOWAIT + + + + +--*********************************************************** +-- *** RE-Enabling triggers on Customer and Address entities +-- ********************************************************** +IF (@DisableProfileChanges = 1) +BEGIN + SET @QueryToExecute = CONCAT('ENABLE TRIGGER ALL ON dbo.[', @AddressEntityName, ']') + EXEC sp_executeSQL @QueryToExecute + + SET @QueryToExecute = CONCAT('ENABLE TRIGGER ALL ON dbo.', @CustomerEntityName) + EXEC sp_executeSQL @QueryToExecute +END + +GO diff --git a/Sample Project/CreateALogBackupToAzureBlobStorage_OutilDUrgence.sql b/Sample Project/CreateALogBackupToAzureBlobStorage_OutilDUrgence.sql new file mode 100644 index 0000000..e304a7a --- /dev/null +++ b/Sample Project/CreateALogBackupToAzureBlobStorage_OutilDUrgence.sql @@ -0,0 +1,108 @@ +SET NOCOUNT ON + +-- Backup all databases already backuped in Azure. +-- Script is mirroring aware +-- Do not run the script within the same second otherwise backupschain could be mixed up and unuseable + + +-- The script won't work if any of the following is true: +-- - The database has never been backup yet to Azure using smart backups +-- - The database had a guid fork and no backup was yet done to Azure using smart backups +-- - Smart backup configuration is not set properly +-- - Azure Data storage does not exist +-- - Database recovery model is not set to FULL + + +------------------------------------------------------ +-- Start configuration section + +DECLARE @IsFullBackup AS BIT = 0 -- 0 = Log backup, 1 = Full backup + +-- End configuration section +------------------------------------------------------ + + +-- Validation + +IF (@IsFullBackup IS NULL) +BEGIN + RAISERROR ('Configuration @IsFullBackup cannot be NULL. Allowed configuration: 0 = Log backup, 1 = Full backup.', 16, 1) + RETURN +END + + + +-- Do not change the remainder configuration + +DECLARE @DebugMode AS BIT = 0 + +DECLARE @StorageURLPrefix AS NVARCHAR(MAX) = 'https://' +DECLARE @StorageURLSuffixe AS NVARCHAR(MAX) = '.blob.core.windows.net/' + +DECLARE @BackupFileExtension AS NVARCHAR(3) = 'log' +DECLARE @BackupCommandType AS NVARCHAR(8) = 'LOG' +DECLARE @BackupHeaderNameBackupType AS NVARCHAR(4) = 'LOG' + +DECLARE @QueryToExecuteBackup AS NVARCHAR(MAX) +DECLARE @CurrentDateForBackup AS DATETIME2(0) = GETDATE() +DECLARE @FormattedCurrentDateForBackup AS NVARCHAR(25) = FORMAT(@CurrentDateForBackup, 'yyyyMMddHHmmss') + +DECLARE @GuidLength AS INT = 32 + + + +IF (@IsFullBackup = 1) +BEGIN + SET @BackupFileExtension = 'bak' + SET @BackupCommandType = 'DATABASE' + SET @BackupHeaderNameBackupType = 'FULL' +END + +SELECT + @QueryToExecuteBackup = CONCAT(@QueryToExecuteBackup, +' +BACKUP ', @BackupCommandType, ' [', frmGetDBUrl.[name], '] TO URL = N''', frmGetDBUrl.FullFileNameToUrl ,''' WITH CREDENTIAL = N''AutoBackup_Credential'' , NOFORMAT, NOINIT, NAME = N''', frmGetDBUrl.[name], '-', @BackupHeaderNameBackupType, ' Database Backup'', NOSKIP, NOREWIND, NOUNLOAD, COMPRESSION, STATS = 10, CHECKSUM') + +FROM ( + + SELECT + databases.[name] + , CONCAT(@StorageURLPrefix, caGetLastestBackupInfo.AzureStorageKey, @StorageURLSuffixe, LOWER(@@SERVERNAME), '-mssqlserver/', databases.[name], '_', caGetLastestBackupInfo.LastestBackupGUID, '_', @FormattedCurrentDateForBackup, LEFT(RIGHT(SYSDATETIMEOFFSET(), 6), 3), '.', @BackupFileExtension) AS 'FullFileNameToUrl' + + FROM + sys.databases + + CROSS APPLY ( + + SELECT TOP 1 + SUBSTRING(backupmediafamily.physical_device_name, PATINDEX(CONCAT('%', backupset.database_name, '_%'), backupmediafamily.physical_device_name) + LEN(backupset.database_name) + 1, 32) AS 'LastestBackupGUID' + , SUBSTRING(backupmediafamily.physical_device_name, LEN(@StorageURLPrefix) + 1, PATINDEX(CONCAT('%', @StorageURLSuffixe, '%'), backupmediafamily.physical_device_name) - LEN(@StorageURLPrefix) - 1) AS 'AzureStorageKey' + + FROM + msdb.dbo.backupmediafamily + + INNER JOIN msdb.dbo.backupset + ON msdb.dbo.backupmediafamily.media_set_id = msdb.dbo.backupset.media_set_id + + WHERE + backupset.database_name = databases.[name] + AND backupmediafamily.physical_device_name LIKE CONCAT(@StorageURLPrefix, '%') + AND backupset.is_copy_only = 0 + + ORDER BY + backupset.backup_finish_date DESC + + ) caGetLastestBackupInfo + + WHERE + databases.state_desc = 'ONLINE' + AND databases.recovery_model_desc = 'FULL' + +) frmGetDBUrl +OPTION (RECOMPILE) + + +PRINT @QueryToExecuteBackup +PRINT '' +IF (@DebugMode = 0) EXEC sp_executeSQL @QueryToExecuteBackup + diff --git a/Sample Project/Fondation_Anonymized.sql b/Sample Project/Fondation_Anonymized.sql new file mode 100644 index 0000000..f018735 --- /dev/null +++ b/Sample Project/Fondation_Anonymized.sql @@ -0,0 +1,41 @@ +--** Script Fondation_Anonymized + +SET XACT_ABORT ON +SET NOCOUNT ON + + + +IF(DB_NAME() NOT LIKE '%Foundation') +BEGIN + RAISERROR ('This is not a foundation database.', 16, 1) + RETURN +END + + + +BEGIN TRANSACTION + + +UPDATE dbo.[Provider] + SET ProviderDetails.modify('replace value of (/Provider/Values/UserName/text())[1] with "azure_44af00f85254c176fe9605819c2ab3e8@azure.com"') +WHERE + [Provider].[name] = 'SmtpMailProvider' and [Provider].[ImplementationTypeName] = 'SmtpMailProvider' + +UPDATE dbo.[Provider] + SET ProviderDetails.modify('replace value of (/Provider/Values/Password/text())[1] with "3ye3bSOqMcVi8mr7"') +WHERE + [Provider].[name] = 'SmtpMailProvider' and [Provider].[ImplementationTypeName] = 'SmtpMailProvider' + +UPDATE dbo.[Provider] + SET ProviderDetails.modify('replace value of (/Provider/Values/SenderAddress/text())[1] with "Customer COmpany Name Test <no-reply-test@Company.ca>"') +WHERE + [Provider].[name] = 'SmtpMailProvider' and [Provider].[ImplementationTypeName] = 'SmtpMailProvider' + +UPDATE dbo.[Provider] + SET ProviderDetails.modify('replace value of (/Provider/Values/TemporaryPassword/text())[1] with "Qwerty123!"') +WHERE + [Provider].[name] = 'AzureDirectoryProvider' and [Provider].[ImplementationTypeName] = 'AzureDirectoryProvider' + +COMMIT +GO + diff --git a/Sample Project/Order_Anonymized.sql b/Sample Project/Order_Anonymized.sql new file mode 100644 index 0000000..80a6805 --- /dev/null +++ b/Sample Project/Order_Anonymized.sql @@ -0,0 +1,138 @@ +--** Script Order_Anonymized + +SET XACT_ABORT ON +SET NOCOUNT ON + + +--************************************************************* +-- *** Configuration Section +-- *** Modify the variables in this section foy your needs +--************************************************************* + + + +-- START OF CONFIGURATION SECTION + +-- *********************************************************************************************** +-- *********************************************************************************************** + +-- Did you ran Profile_Anonymized.sql first? + +-- Nothing to configure here, +-- Will run with the choice of one or all customer_id selected in the Profile_Anonymized script + +-- END OF CONFIGURATION SECTION + +-- *********************************************************************************************** +-- *********************************************************************************************** + + + + + + + + + + + + +-- ******************************** +-- *** Start of Program +-- ******************************** + + + +--*********************************************************** +-- *** If not connected to the right Database, script exits +-- ********************************************************** +IF(DB_NAME() NOT LIKE '%Order') +BEGIN + RAISERROR ('This is not an order database.', 16, 1) + RETURN +END + + + +--**************************************************************** +-- *** If no CustomerProfileToAnonymize table found, script exists +-- *************************************************************** +IF OBJECT_ID('tempdb..##CustomerProfileToAnonymize') IS NULL +BEGIN + RAISERROR ('You have to run Profile_Anonymized script first', 16, 1) + RETURN +END + + + +-- ********************************************************************************** +-- *** Update the ORDER table to anonymized colums related to customer(s) selected +-- ********************************************************************************** +UPDATE [ORDER] SET + [ORDER].Email = CONCAT(CustomerProfileToAnonymize.CustomerEntityName, ' ', [ORDER].OrderNumber, CustomerProfileToAnonymize.AnonymizedFakeEmailSuffixe) + , [ORDER].CustomerPhone = CustomerProfileToAnonymize.AnonymizedPhoneNumber + , [ORDER].CustomerName = CONCAT(CustomerProfileToAnonymize.CustomerEntityName, ' ', [ORDER].OrderNumber) + +FROM + dbo.[ORDER] + +INNER JOIN + ##CustomerProfileToAnonymize CustomerProfileToAnonymize + ON CustomerProfileToAnonymize.Id = [ORDER].Customer_Id +OPTION (RECOMPILE) + + + + +-- ***************************************************************************************** +-- *** Update the SHIPMENTADDRESS table to anonymized colums related to customer(s) selected +-- ***************************************************************************************** +UPDATE SHIPMENTADDRESS SET + SHIPMENTADDRESS.LastName = CONCAT(CustomerProfileToAnonymize.CustomerEntityName, ' ', SHIPMENTADDRESS.TransactionOrderNumber) + , SHIPMENTADDRESS.FirstName = CONCAT(CustomerProfileToAnonymize.CustomerEntityName, ' ', SHIPMENTADDRESS.TransactionOrderNumber) + , SHIPMENTADDRESS.PhoneNumber = CustomerProfileToAnonymize.AnonymizedPhoneNumber + +FROM + dbo.SHIPMENTADDRESS + +INNER JOIN + dbo.[ORDER] + ON [ORDER].TransactionOrderNumber = SHIPMENTADDRESS.TransactionOrderNumber + +INNER JOIN + ##CustomerProfileToAnonymize CustomerProfileToAnonymize + ON CustomerProfileToAnonymize.Id = [ORDER].Customer_Id +OPTION (RECOMPILE) + + + + +-- **************************************************************************************** +-- *** Update the PAYMENTADDRESS table to anonymized colums related to customer(s) selected +-- **************************************************************************************** +UPDATE PAYMENTADDRESS SET + PAYMENTADDRESS.LastName = CONCAT(CustomerProfileToAnonymize.CustomerEntityName, ' ', PAYMENTADDRESS.TransactionOrderNumber) + , PAYMENTADDRESS.FirstName = CONCAT(CustomerProfileToAnonymize.CustomerEntityName, ' ', PAYMENTADDRESS.TransactionOrderNumber) + , PAYMENTADDRESS.PhoneNumber = CustomerProfileToAnonymize.AnonymizedPhoneNumber + +FROM + dbo.PAYMENTADDRESS + +INNER JOIN + dbo.[ORDER] + ON [ORDER].TransactionOrderNumber = PAYMENTADDRESS.TransactionOrderNumber + +INNER JOIN + ##CustomerProfileToAnonymize CustomerProfileToAnonymize + ON CustomerProfileToAnonymize.Id = [ORDER].Customer_Id + + + + +-- ************************************************************* +-- *** The temporary table CustomerProfileToAnonymize is dropped +-- *** It is no longger needed +-- ************************************************************* +IF OBJECT_ID('tempdb..##CustomerProfileToAnonymize') IS NOT NULL + DROP TABLE ##CustomerProfileToAnonymize +GO diff --git a/Sample Project/PanoptaSQLSmartBackupCheck.sql b/Sample Project/PanoptaSQLSmartBackupCheck.sql new file mode 100644 index 0000000..fceefd8 --- /dev/null +++ b/Sample Project/PanoptaSQLSmartBackupCheck.sql @@ -0,0 +1,64 @@ +DECLARE @TimeBeforeExpiration AS DATETIME2(3) = DATEADD(HOUR, -24, GETDATE()) + +SELECT + databases.name AS 'DatabaseName' + , CASE WHEN oaBackupExist.Exist = 1 THEN 1 ELSE 0 END AS 'UseableBackupExist' + +FROM + sys.databases + +OUTER APPLY ( + + SELECT TOP 1 + 1 AS 'Exist' + , fab.backup_finish_date + + FROM + msdb.smart_admin.fn_available_backups(databases.name) fab + + WHERE + fab.backup_finish_date >= @TimeBeforeExpiration + + ORDER BY + fab.backup_finish_date DESC + +) oaGetBackupStatus + +OUTER APPLY ( + + SELECT TOP 1 + 1 AS 'Exist' + , smart_backup_files.backup_finish_date + + FROM + msdb.dbo.smart_backup_files + + WHERE + smart_backup_files.[status] = 'A' + AND smart_backup_files.database_name = databases.name + AND smart_backup_files.backup_finish_date >= @TimeBeforeExpiration + + ORDER BY + smart_backup_files.last_modified_utc DESC + +) oaBackupExist + +WHERE + databases.state_desc = 'ONLINE' + AND ( + databases.[name] LIKE '%foundation' OR + databases.[name] LIKE '%marketing' OR + databases.[name] LIKE '%membership' OR + databases.[name] LIKE '%messaging' OR + databases.[name] LIKE '%order' OR + databases.[name] LIKE '%pickandpack' OR + databases.[name] LIKE '%pnp' OR + databases.[name] LIKE '%product' OR + databases.[name] LIKE '%profile' OR + databases.[name] LIKE '%Archive' OR + databases.[name] LIKE '%Reporting' OR + databases.[name] LIKE '%DataWarehouse' + ) + +ORDER BY + databases.[name] \ No newline at end of file diff --git a/Sample Project/Profile_Anonymized.sql b/Sample Project/Profile_Anonymized.sql new file mode 100644 index 0000000..a83824e --- /dev/null +++ b/Sample Project/Profile_Anonymized.sql @@ -0,0 +1,394 @@ +--** Script Profile_Anonymized + + +SET XACT_ABORT ON +SET NOCOUNT ON + + +-- ************************************************************* +-- *** Configuration Section +-- *** Modify the variables in this section foy your needs +-- ************************************************************* + + + +-- START OF CONFIGURATION SECTION + +-- *********************************************************************************************** +-- *********************************************************************************************** + +-- ************************************************************* +-- *** Choose 1 or All customer to be Anonymize *** +-- *** 1 = Specify 1 Customer +-- *** 2 = All Customers +-- ************************************************************* + +DECLARE @CustomerSelection INT = 1 + + + + +-- ************************************************************* +-- *** Specify the ID of the customer to be Anonymize +-- *** If you don't have the Customer_ID, you can do select the Customer_ID from the table Customer +-- *** including the info you have in the search criteria of the where clause +-- *** ex: select Customer_Id from Customer where email=' ' +-- *** or: select Customer_Id from Customer where FirstName=' ' and LastName= ' ' +-- +-- If the script is halted because of a deadlock or locking, re-run it +-- +-- At least only one row must be needed for a particular customer +-- Make sure to correctly uniquely identify the customer +-- Fields requires to be precise, no wildcard accepted +-- +-- If you want all customer to be anonymized, you must enter the value 2 for +-- the variable @CustomerSelection just one step up of this scipt +-- The variable @Customer_IdToAnonymize won't be taken into account. +-- ************************************************************* + +DECLARE @Customer_IdToAnonymize INT = + + + + +-- END OF CONFIGURATION SECTION + +-- *********************************************************************************************** +-- *********************************************************************************************** + + + + + + + + +-- **************************************************************** +-- Values that will be use for the columns to be anonymized +-- The following customer fields are anonymized: +-- 'Username', 'FirstName', 'LastName', 'PhoneNumber', 'Email', +-- 'CellNumber', 'PhoneNumberWork', 'FaxNumber' +-- **************************************************************** +DECLARE @AnonymizedPhoneNumber AS VARCHAR(32) = '555-555-5555' +DECLARE @AnonymizedFakeEmailSuffixe AS NVARCHAR(64) = '@orckestrafake.com' +DECLARE @AnonymizedAuditNewValueSuffixe AS NVARCHAR(128) = 'Anonymized Audit NewValue' +DECLARE @AnonymizedAuditOldValueSuffixe AS NVARCHAR(128) = 'Anonymized Audit OldValue' +DECLARE @AnonymizedCustomerPrefix AS NVARCHAR(16) = @CustomerEntityName + + +DECLARE @DisableProfileChanges INT = 1 + + + +-- *************************************************** +-- *** The name of the entity for Customer +-- *************************************************** +DECLARE @CustomerEntityName AS SYSNAME = 'CUSTOMER' + + +-- *************************************************** +-- *** The name of the entity for Address +-- *************************************************** +DECLARE @AddressEntityName AS SYSNAME = 'ADDRESS' + + + + + + + + + +-- ******************************** +-- *** Start of Program +-- ******************************** + + +--*********************************************************** +-- *** If not connected to the right Database, script exits +-- ********************************************************** +IF(DB_NAME() NOT LIKE '%Profile') +BEGIN + RAISERROR ('This is not a profile database.', 16, 1) + RETURN +END + + +-- ******************************************************************** +-- *** If the value of @CustomerSelection is not valid, exit the script +-- ******************************************************************** +IF (@CustomerSelection != 2 AND @CustomerSelection ! = 1) +BEGIN + RAISERROR ('The value enter for @CustomerSelection is not valid', 16, 1) + RETURN +END + + + +-- ************************************************************* +-- *** Creating the temporary table(##CustomerProfileToAnonymize) +-- *** to contain the customer_ID(s) to be Anonymize +-- *** The columns to be anonymized are added to the table +-- *** The table is dropped before creating it +-- ************************************************************* + +IF OBJECT_ID('tempdb..##CustomerProfileToAnonymize') IS NOT NULL + DROP TABLE ##CustomerProfileToAnonymize + + +CREATE TABLE ##CustomerProfileToAnonymize ( + Customer_Id INT NOT NULL + , Id UNIQUEIDENTIFIER NOT NULL + , UserName NVARCHAR(256) NULL + , FirstName NVARCHAR(64) NULL + , LastName NVARCHAR(64) NULL + , Email NVARCHAR(256) NULL + , PhoneNumber VARCHAR(32) NULL + , CellNumber VARCHAR(32) NULL + , PhoneNumberWork VARCHAR(32) NULL + , FaxNumber VARCHAR(32) NULL + , AnonymizedPhoneNumber VARCHAR(32) NOT NULL + , AnonymizedFakeEmailSuffixe NVARCHAR(64) NOT NULL + , CustomerEntityName SYSNAME NOT NULL + , PRIMARY KEY CLUSTERED (Customer_Id) + , UNIQUE NONCLUSTERED (Id) +) + + +-- ************************************************************* +-- *** Inserting in a temporary table(##CustomerProfileToAnonymize) +-- *** the customer ID(s) to be Anonymize +-- ************************************************************* + +BEGIN + INSERT INTO ##CustomerProfileToAnonymize + SELECT + CUSTOMER.Customer_Id + , CUSTOMER.Id + , CUSTOMER.UserName + , CUSTOMER.FirstName + , CUSTOMER.LastName + , CUSTOMER.Email + , CUSTOMER.PhoneNumber + , CUSTOMER.CellNumber + , CUSTOMER.PhoneNumberWork + , CUSTOMER.FaxNumber + , @AnonymizedPhoneNumber + , @AnonymizedFakeEmailSuffixe + , @CustomerEntityName + + FROM + dbo.CUSTOMER + + WHERE + (CUSTOMER.CUSTOMER_Id = @Customer_IdToAnonymize AND @CustomerSelection = 1) + OR + @CustomerSelection = 2 + OPTION(RECOMPILE) +END + + + + + + +--*********************************************************** +-- *** If no Customer found for the selection, script exists +-- ********************************************************** +IF NOT EXISTS (select 1 from ##CustomerProfileToAnonymize) +BEGIN + RAISERROR ('No Customer selected or database does not contain any customer', 16, 1) + RETURN +END + + +DECLARE @QueryToExecute AS NVARCHAR(MAX) +DECLARE @NumberOfRowChanged INT = 1; +DECLARE @CurrentMessageToDisplay AS NVARCHAR(MAX); + + + + +--*********************************************************** +-- *** Disabling triggers on Customer and Address entities +-- ********************************************************** +IF (@DisableProfileChanges = 1) +BEGIN + SET @QueryToExecute = CONCAT('DISABLE TRIGGER ALL ON dbo.[', @AddressEntityName, ']') + EXEC sp_executeSQL @QueryToExecute + + SET @QueryToExecute = CONCAT('DISABLE TRIGGER ALL ON dbo.', @CustomerEntityName) + EXEC sp_executeSQL @QueryToExecute +END + + + + + +--********************************************************************************** +-- *** Update the Address table to anonymized columns related to customer(s) selected +-- ********************************************************************************* +UPDATE [ADDRESS] + SET [ADDRESS].LastName = SUBSTRING(CONCAT(@AnonymizedCustomerPrefix, [ADDRESS].Address_Id), 0, 64) + , [ADDRESS].FirstName = SUBSTRING(CONCAT(@AnonymizedCustomerPrefix, [ADDRESS].Address_Id), 0, 64) + , [ADDRESS].PhoneNumber = CustomerProfileToAnonymize.AnonymizedPhoneNumber + +FROM + dbo.[ADDRESS] + +INNER JOIN + dbo.RELATIONSHIP + ON RELATIONSHIP.Child_Id = [ADDRESS].Address_Id + +INNER JOIN + dbo.ENTITY parentEntity + ON parentEntity.Entity_Id = RELATIONSHIP.ParentEntity_Id + +INNER JOIN + dbo.ENTITY childEntity + ON childEntity.Entity_Id = RELATIONSHIP.ChildEntity_Id + +INNER JOIN + ##CustomerProfileToAnonymize CustomerProfileToAnonymize + ON CustomerProfileToAnonymize.Customer_Id = RELATIONSHIP.Parent_Id + +WHERE + parentEntity.EntityName = @CustomerEntityName + AND childEntity.EntityName = @AddressEntityName +OPTION (RECOMPILE) + + +SET @NumberOfRowChanged = @@ROWCOUNT; + +SET @CurrentMessageToDisplay = CONCAT('Number of sanitanized address rows: ', @NumberOfRowChanged) +RAISERROR (@CurrentMessageToDisplay, 0, 1) WITH NOWAIT + + + + + +--********************************************************************************** +-- *** Update the Customer table to anonymized colums related to customer(s) selected +-- ********************************************************************************* +UPDATE CUSTOMER + SET CUSTOMER.Email = CONCAT(@AnonymizedCustomerPrefix, CUSTOMER.Customer_Id, CustomerProfileToAnonymize.AnonymizedFakeEmailSuffixe) + , CUSTOMER.Username = CONCAT(@AnonymizedCustomerPrefix, CUSTOMER.Customer_Id) + , CUSTOMER.FirstName = CONCAT(@AnonymizedCustomerPrefix, CUSTOMER.Customer_Id) + , CUSTOMER.LastName = CONCAT(@AnonymizedCustomerPrefix, CUSTOMER.Customer_Id) + , CUSTOMER.PhoneNumber = CustomerProfileToAnonymize.AnonymizedPhoneNumber + , CUSTOMER.CellNumber = CustomerProfileToAnonymize.AnonymizedPhoneNumber + , CUSTOMER.PhoneNumberWork = CustomerProfileToAnonymize.AnonymizedPhoneNumber + , CUSTOMER.FaxNumber = CustomerProfileToAnonymize.AnonymizedPhoneNumber + +FROM + dbo.CUSTOMER + +INNER JOIN + ##CustomerProfileToAnonymize CustomerProfileToAnonymize + ON CustomerProfileToAnonymize.Customer_Id = CUSTOMER.Customer_Id + +OPTION (RECOMPILE) + + +SET @NumberOfRowChanged = @@ROWCOUNT; +SET @CurrentMessageToDisplay = CONCAT('Number of sanitanized customer rows: ', @NumberOfRowChanged) +RAISERROR (@CurrentMessageToDisplay, 0, 1) WITH NOWAIT + + + + + +--********************************************************************************** +-- Update the Audit table to anonymized colums related to the customer EntityName +-- audit changes of the selected customer(s) +-- Filter by the columnName : +-- 'Username', 'FirstName', 'LastName', 'PhoneNumber', 'Email', +-- 'CellNumber', 'PhoneNumberWork', 'FaxNumber' +--********************************************************************************** +UPDATE [AUDIT] SET + [AUDIT].OldValue = CASE WHEN [AUDIT].Operation IN ('U', 'D') THEN CONCAT([AUDIT].TableName, ': ', @AnonymizedAuditNewValueSuffixe) ELSE NULL END + , [AUDIT].NewValue = CASE WHEN [AUDIT].Operation IN ('I', 'U') THEN CONCAT([AUDIT].TableName, ': ', @AnonymizedAuditOldValueSuffixe) ELSE NULL END + +FROM + [Audit].[AUDIT] + +INNER JOIN + ##CustomerProfileToAnonymize CustomerProfileToAnonymize + ON CustomerProfileToAnonymize.Id = [AUDIT].[Entity_Id] + +WHERE + [AUDIT].TableName = @CustomerEntityName + AND [AUDIT].ColumnName IN ('Username', 'FirstName', 'LastName', 'PhoneNumber', 'Email', 'CellNumber', 'PhoneNumberWork', 'FaxNumber') +OPTION (RECOMPILE) + + +SET @NumberOfRowChanged = @@ROWCOUNT; + +SET @CurrentMessageToDisplay = CONCAT('Number of sanitanized customer audit rows: ', @NumberOfRowChanged) +RAISERROR (@CurrentMessageToDisplay, 0, 1) WITH NOWAIT + + + + +--******************************************************************************************* +-- Update the Audit table to anonymized colums related to the Address table +-- audit changes of the selected customer(s) +-- Filter by the columnName : +-- 'Username', 'FirstName', 'LastName', 'PhoneNumber', 'Email', +-- 'CellNumber', 'PhoneNumberWork', 'FaxNumber' +--******************************************************************************************* +UPDATE [AUDIT] SET + [AUDIT].OldValue = CASE WHEN [AUDIT].Operation IN ('U', 'D') THEN CONCAT([AUDIT].TableName, ': ', @AnonymizedAuditNewValueSuffixe) ELSE NULL END + , [AUDIT].NewValue = CASE WHEN [AUDIT].Operation IN ('I', 'U') THEN CONCAT([AUDIT].TableName, ': ', @AnonymizedAuditOldValueSuffixe) ELSE NULL END + +FROM + [Audit].[AUDIT] + +INNER JOIN + dbo.[ADDRESS] + ON [ADDRESS].Id = [AUDIT].[Entity_Id] + +INNER JOIN + dbo.RELATIONSHIP + ON RELATIONSHIP.Child_Id = [ADDRESS].Address_Id + +INNER JOIN + dbo.ENTITY parentEntity + ON parentEntity.Entity_Id = RELATIONSHIP.ParentEntity_Id + +INNER JOIN + dbo.ENTITY childEntity + ON childEntity.Entity_Id = RELATIONSHIP.ChildEntity_Id + +INNER JOIN + ##CustomerProfileToAnonymize CustomerProfileToAnonymize + ON CustomerProfileToAnonymize.Customer_Id = RELATIONSHIP.Parent_Id + +WHERE + parentEntity.EntityName = @CustomerEntityName + AND childEntity.EntityName = @AddressEntityName + AND [AUDIT].TableName = @AddressEntityName + AND [AUDIT].ColumnName IN ('FirstName', 'LastName', 'PhoneNumber') +OPTION (RECOMPILE) + + +SET @NumberOfRowChanged = @@ROWCOUNT; +SET @CurrentMessageToDisplay = CONCAT('Number of sanitanized address audit rows: ', @NumberOfRowChanged) +RAISERROR (@CurrentMessageToDisplay, 0, 1) WITH NOWAIT + + + + +--*********************************************************** +-- *** RE-Enabling triggers on Customer and Address entities +-- ********************************************************** +IF (@DisableProfileChanges = 1) +BEGIN + SET @QueryToExecute = CONCAT('ENABLE TRIGGER ALL ON dbo.[', @AddressEntityName, ']') + EXEC sp_executeSQL @QueryToExecute + + SET @QueryToExecute = CONCAT('ENABLE TRIGGER ALL ON dbo.', @CustomerEntityName) + EXEC sp_executeSQL @QueryToExecute +END + +GO diff --git a/Sample Project/README.md b/Sample Project/README.md index b22e54c..aa397f7 100644 --- a/Sample Project/README.md +++ b/Sample Project/README.md @@ -1,2 +1,19 @@ -# Sample Project -This is a folder for a sample project. To be removed when the repo is public +Anonymization scripts + +The purpose of the 3 following scripts is to anonymize sensible data in the different tables +for the Order, Profile and Foundation databases. + + + +The Profile_Anonymized script must be run in the Profile database. + +The Order_Anonymized script must be run in the Order database.Before running this script, +Profile_Anonymized has to be run. + +The Fondation_Anonymized script must be run in the Foundation database. + +Be attentive to the Configuration Section in the Profile_Anonymized script. +This is the place when you can adapt different variables like if the script will be run for one or all customers. + + + diff --git a/Sample Project/SecurityFixAfterRestoringDatabasesFromAnExternalServer.sql b/Sample Project/SecurityFixAfterRestoringDatabasesFromAnExternalServer.sql new file mode 100644 index 0000000..bb429db --- /dev/null +++ b/Sample Project/SecurityFixAfterRestoringDatabasesFromAnExternalServer.sql @@ -0,0 +1,113 @@ +SET NOCOUNT ON + +-- Rebind security, logins & databases users if already deployed by the platform for the former +-- The most probable scenario: from prod to staging + +-- This script *does not rebuild the security* + + + +DECLARE @LoginList TABLE ( + LoginName SYSNAME NOT NULL +) + +INSERT INTO @LoginList + SELECT + sql_logins.[name] + + FROM + sys.sql_logins + + WHERE + sql_logins.type_desc = 'SQL_LOGIN' + AND sql_logins.[name] LIKE 'Overture%' + + + +DECLARE @CurrentDatabaseName AS SYSNAME +DECLARE @CurrentLoginName AS SYSNAME +DECLARE @CurrentMessageToDisplay AS NVARCHAR(MAX) +DECLARE @QueryToExecute AS NVARCHAR(MAX) + + +DECLARE CursorIterateOverDatabases CURSOR LOCAL FAST_FORWARD FOR + SELECT + databases.[name] + + FROM + sys.databases + + WHERE + databases.[name] LIKE '%_DataWarehouse' + OR databases.[name] LIKE '%_Archive' + OR databases.[name] LIKE '%_foundation' + OR databases.[name] LIKE '%_marketing' + OR databases.[name] LIKE '%_membership' + OR databases.[name] LIKE '%_messaging' + OR databases.[name] LIKE '%_order' + OR databases.[name] LIKE '%_product' + OR databases.[name] LIKE '%_profile' + + ORDER BY + databases.[name] + + +OPEN CursorIterateOverDatabases + +FETCH NEXT FROM CursorIterateOverDatabases +INTO @CurrentDatabaseName + + +WHILE @@FETCH_STATUS = 0 +BEGIN + + SET @CurrentMessageToDisplay = CONCAT('Start rebind login on: ', @CurrentDatabaseName) + RAISERROR (@CurrentMessageToDisplay, 0, 1) WITH NOWAIT + + + + + DECLARE CursorIterateOverLogins CURSOR LOCAL FAST_FORWARD FOR + SELECT LoginList.LoginName FROM @LoginList LoginList + + OPEN CursorIterateOverLogins + + FETCH NEXT FROM CursorIterateOverLogins + INTO @CurrentLoginName + + + WHILE @@FETCH_STATUS = 0 + BEGIN + + SET @CurrentMessageToDisplay = CONCAT(' Start rebind login: ', @CurrentLoginName) + RAISERROR (@CurrentMessageToDisplay, 0, 1) WITH NOWAIT + + + SET @QueryToExecute = CONCAT('EXEC ', QUOTENAME(@CurrentDatabaseName), '..sp_change_users_login ''Auto_Fix'', ''', @CurrentLoginName, '''') + EXEC sp_executeSQL @QueryToExecute + --print @QueryToExecute + + SET @CurrentMessageToDisplay = CONCAT(' End rebind login: ', @CurrentLoginName) + CHAR(13) + RAISERROR (@CurrentMessageToDisplay, 0, 1) WITH NOWAIT + + FETCH NEXT FROM CursorIterateOverLogins + INTO @CurrentLoginName + + END + + CLOSE CursorIterateOverLogins; + DEALLOCATE CursorIterateOverLogins; + + + + + SET @CurrentMessageToDisplay = CONCAT('End rebind login on: ', @CurrentDatabaseName) + CHAR(13) + CHAR(13) + CHAR(13) + RAISERROR (@CurrentMessageToDisplay, 0, 1) WITH NOWAIT + + FETCH NEXT FROM CursorIterateOverDatabases + INTO @CurrentDatabaseName + +END + +CLOSE CursorIterateOverDatabases; +DEALLOCATE CursorIterateOverDatabases; diff --git a/Sample Project/Update Reserved Quantities.sql b/Sample Project/Update Reserved Quantities.sql new file mode 100644 index 0000000..2b1b870 --- /dev/null +++ b/Sample Project/Update Reserved Quantities.sql @@ -0,0 +1,14 @@ +SET XACT_ABORT ON + + +DECLARE @SkuToChange AS NVARCHAR(64) = 'SkuValue' +DECLARE @QuantityToReserve AS INT = IntegerValue + + +BEGIN TRANSACTION + +SELECT 'Before', INVENTORY_QUANTITIES.SKU, INVENTORY_QUANTITIES.ReservedQuantity FROM dbo.INVENTORY_QUANTITIES WHERE INVENTORY_QUANTITIES.SKU = @SkuToChange +UPDATE dbo.INVENTORY_QUANTITIES SET INVENTORY_QUANTITIES.ReservedQuantity = ISNULL(INVENTORY_QUANTITIES.ReservedQuantity, 0) + @QuantityToReserve WHERE INVENTORY_QUANTITIES.SKU = @SkuToChange +SELECT 'After', INVENTORY_QUANTITIES.SKU, INVENTORY_QUANTITIES.ReservedQuantity FROM dbo.INVENTORY_QUANTITIES WHERE INVENTORY_QUANTITIES.SKU = @SkuToChange + +COMMIT diff --git a/SecurityFixAfterRestoringDatabasesFromAnExternalServer.sql b/SecurityFixAfterRestoringDatabasesFromAnExternalServer.sql new file mode 100644 index 0000000..bb429db --- /dev/null +++ b/SecurityFixAfterRestoringDatabasesFromAnExternalServer.sql @@ -0,0 +1,113 @@ +SET NOCOUNT ON + +-- Rebind security, logins & databases users if already deployed by the platform for the former +-- The most probable scenario: from prod to staging + +-- This script *does not rebuild the security* + + + +DECLARE @LoginList TABLE ( + LoginName SYSNAME NOT NULL +) + +INSERT INTO @LoginList + SELECT + sql_logins.[name] + + FROM + sys.sql_logins + + WHERE + sql_logins.type_desc = 'SQL_LOGIN' + AND sql_logins.[name] LIKE 'Overture%' + + + +DECLARE @CurrentDatabaseName AS SYSNAME +DECLARE @CurrentLoginName AS SYSNAME +DECLARE @CurrentMessageToDisplay AS NVARCHAR(MAX) +DECLARE @QueryToExecute AS NVARCHAR(MAX) + + +DECLARE CursorIterateOverDatabases CURSOR LOCAL FAST_FORWARD FOR + SELECT + databases.[name] + + FROM + sys.databases + + WHERE + databases.[name] LIKE '%_DataWarehouse' + OR databases.[name] LIKE '%_Archive' + OR databases.[name] LIKE '%_foundation' + OR databases.[name] LIKE '%_marketing' + OR databases.[name] LIKE '%_membership' + OR databases.[name] LIKE '%_messaging' + OR databases.[name] LIKE '%_order' + OR databases.[name] LIKE '%_product' + OR databases.[name] LIKE '%_profile' + + ORDER BY + databases.[name] + + +OPEN CursorIterateOverDatabases + +FETCH NEXT FROM CursorIterateOverDatabases +INTO @CurrentDatabaseName + + +WHILE @@FETCH_STATUS = 0 +BEGIN + + SET @CurrentMessageToDisplay = CONCAT('Start rebind login on: ', @CurrentDatabaseName) + RAISERROR (@CurrentMessageToDisplay, 0, 1) WITH NOWAIT + + + + + DECLARE CursorIterateOverLogins CURSOR LOCAL FAST_FORWARD FOR + SELECT LoginList.LoginName FROM @LoginList LoginList + + OPEN CursorIterateOverLogins + + FETCH NEXT FROM CursorIterateOverLogins + INTO @CurrentLoginName + + + WHILE @@FETCH_STATUS = 0 + BEGIN + + SET @CurrentMessageToDisplay = CONCAT(' Start rebind login: ', @CurrentLoginName) + RAISERROR (@CurrentMessageToDisplay, 0, 1) WITH NOWAIT + + + SET @QueryToExecute = CONCAT('EXEC ', QUOTENAME(@CurrentDatabaseName), '..sp_change_users_login ''Auto_Fix'', ''', @CurrentLoginName, '''') + EXEC sp_executeSQL @QueryToExecute + --print @QueryToExecute + + SET @CurrentMessageToDisplay = CONCAT(' End rebind login: ', @CurrentLoginName) + CHAR(13) + RAISERROR (@CurrentMessageToDisplay, 0, 1) WITH NOWAIT + + FETCH NEXT FROM CursorIterateOverLogins + INTO @CurrentLoginName + + END + + CLOSE CursorIterateOverLogins; + DEALLOCATE CursorIterateOverLogins; + + + + + SET @CurrentMessageToDisplay = CONCAT('End rebind login on: ', @CurrentDatabaseName) + CHAR(13) + CHAR(13) + CHAR(13) + RAISERROR (@CurrentMessageToDisplay, 0, 1) WITH NOWAIT + + FETCH NEXT FROM CursorIterateOverDatabases + INTO @CurrentDatabaseName + +END + +CLOSE CursorIterateOverDatabases; +DEALLOCATE CursorIterateOverDatabases; diff --git a/Update Reserved Quantities.sql b/Update Reserved Quantities.sql new file mode 100644 index 0000000..2b1b870 --- /dev/null +++ b/Update Reserved Quantities.sql @@ -0,0 +1,14 @@ +SET XACT_ABORT ON + + +DECLARE @SkuToChange AS NVARCHAR(64) = 'SkuValue' +DECLARE @QuantityToReserve AS INT = IntegerValue + + +BEGIN TRANSACTION + +SELECT 'Before', INVENTORY_QUANTITIES.SKU, INVENTORY_QUANTITIES.ReservedQuantity FROM dbo.INVENTORY_QUANTITIES WHERE INVENTORY_QUANTITIES.SKU = @SkuToChange +UPDATE dbo.INVENTORY_QUANTITIES SET INVENTORY_QUANTITIES.ReservedQuantity = ISNULL(INVENTORY_QUANTITIES.ReservedQuantity, 0) + @QuantityToReserve WHERE INVENTORY_QUANTITIES.SKU = @SkuToChange +SELECT 'After', INVENTORY_QUANTITIES.SKU, INVENTORY_QUANTITIES.ReservedQuantity FROM dbo.INVENTORY_QUANTITIES WHERE INVENTORY_QUANTITIES.SKU = @SkuToChange + +COMMIT