├── DataGuard ├── Security │ ├── log.sql │ ├── mon.sql │ ├── conf.sql │ ├── def.sql │ └── sec.sql ├── Scripts │ ├── Pre-Deploy │ │ ├── MaintainDBSettings.sql │ │ └── Script.PreDeployment.sql │ └── Post-Deploy │ │ ├── conf │ │ └── SetInitialSetting.sql │ │ ├── def │ │ └── SetTypeLogin.sql │ │ └── Script.PostDeployment.sql ├── def │ └── Tables │ │ └── def.tTypeLogin.sql ├── mon │ └── Tables │ │ ├── mon.tUserState.sql │ │ └── mon.tPermissionState.sql ├── local.publish.xml ├── dbo │ └── Procedures │ │ ├── dbo.pThrowErrorIfDatabaseNotExists.sql │ │ ├── dbo.pGetListOfInstancePrincipals.sql │ │ ├── dbo.pGetListOfInstancePermissions.sql │ │ ├── dbo.pGetListOfInstanceRoles.sql │ │ ├── dbo.pIsDatabaseExists.sql │ │ ├── dbo.pIsSchemaExists.sql │ │ ├── dbo.pGetListOfDatabaseRoles.sql │ │ ├── dbo.pGetListOfDatabaseUsers.sql │ │ ├── dbo.pGetLoginDiff.sql │ │ ├── dbo.pGetListOfDatabasePermissions.sql │ │ ├── dbo.pObjectInSystem.sql │ │ ├── dbo.pGetUserDiff.sql │ │ ├── dbo.pPermissionInSystemAsXml.sql │ │ ├── dbo.pGetListOfDatabaseObject.sql │ │ └── dbo.pPermissionInInstance.sql ├── sec │ └── Procedures │ │ ├── sec.pCreateUser.sql │ │ └── sec.pCreateLogin.sql ├── DataGuard.refactorlog ├── conf │ └── Tables │ │ ├── conf.tSetting.sql │ │ ├── conf.tUser.sql │ │ ├── conf.tLogin.sql │ │ ├── conf.tDatabase.sql │ │ └── conf.tPermission.sql └── DataGuard.sqlproj ├── LICENSE.md ├── data-guard-logo.jpg ├── External └── tSQLt.2019.dacpac ├── DataGuard.dbtests ├── Security │ └── test.sql ├── Scripts │ ├── Pre-Deploy │ │ ├── tSQLtTest │ │ │ └── CreateSchemaTest.sql │ │ ├── master │ │ │ └── EnableCLR.sql │ │ └── Script.PreDeployment.sql │ └── Post-Deploy │ │ ├── tSQLt │ │ ├── tSQLt.Private_InstallationInfo.sql │ │ └── tSQLt.SetExecutionBitOnExtenstionPropertyForSchemaTests.sql │ │ ├── conf │ │ └── SetTableDatabase.sql │ │ └── Script.PostDeployment.sql ├── Test │ └── Procedures │ │ ├── test database DataGuard existing.sql │ │ ├── test database TestDataTest not existing.sql │ │ ├── test conf.tDatabase try change CreatedOn.sql │ │ ├── test conf.tDatabase try change CreatedBy.sql │ │ └── test conf.tDatabase if record change update LastModifiedOn.sql ├── local.publish.xml └── DataGuard.dbtests.sqlproj ├── PermissionMatrix.txt ├── DataGuard.sln ├── README.md └── .gitignore /DataGuard/Security/log.sql: -------------------------------------------------------------------------------- 1 | CREATE SCHEMA [log] 2 | AUTHORIZATION [dbo]; -------------------------------------------------------------------------------- /DataGuard/Security/mon.sql: -------------------------------------------------------------------------------- 1 | CREATE SCHEMA [mon] 2 | AUTHORIZATION [dbo]; -------------------------------------------------------------------------------- /DataGuard/Security/conf.sql: -------------------------------------------------------------------------------- 1 | CREATE SCHEMA [conf] 2 | AUTHORIZATION [dbo]; 3 | -------------------------------------------------------------------------------- /DataGuard/Security/def.sql: -------------------------------------------------------------------------------- 1 | CREATE SCHEMA [def] 2 | AUTHORIZATION [dbo]; 3 | -------------------------------------------------------------------------------- /DataGuard/Security/sec.sql: -------------------------------------------------------------------------------- 1 | CREATE SCHEMA [sec] 2 | AUTHORIZATION [dbo]; 3 | -------------------------------------------------------------------------------- /LICENSE.md: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/dalionsystem/dataGuard/HEAD/LICENSE.md -------------------------------------------------------------------------------- /data-guard-logo.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/dalionsystem/dataGuard/HEAD/data-guard-logo.jpg -------------------------------------------------------------------------------- /External/tSQLt.2019.dacpac: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/dalionsystem/dataGuard/HEAD/External/tSQLt.2019.dacpac -------------------------------------------------------------------------------- /DataGuard/Scripts/Pre-Deploy/MaintainDBSettings.sql: -------------------------------------------------------------------------------- 1 | ALTER AUTHORIZATION ON Database::[$(DatabaseName)] TO sa; 2 | 3 | GO -------------------------------------------------------------------------------- /DataGuard.dbtests/Security/test.sql: -------------------------------------------------------------------------------- 1 | CREATE SCHEMA [test] 2 | AUTHORIZATION [dbo]; 3 | 4 | 5 | --EXEC tSQLt.NewTestClass 'test'; -------------------------------------------------------------------------------- /DataGuard.dbtests/Scripts/Pre-Deploy/tSQLtTest/CreateSchemaTest.sql: -------------------------------------------------------------------------------- 1 | IF SCHEMA_ID('test') IS NULL 2 | EXEC tSQLt.NewTestClass 'test'; 3 | GO -------------------------------------------------------------------------------- /DataGuard.dbtests/Scripts/Pre-Deploy/master/EnableCLR.sql: -------------------------------------------------------------------------------- 1 | USE [master] 2 | GO 3 | 4 | EXEC master.sys.sp_configure @configname='clr enabled', @configvalue = 1; 5 | RECONFIGURE; 6 | 7 | USE [$(DatabaseName)] 8 | GO 9 | -------------------------------------------------------------------------------- /DataGuard/def/Tables/def.tTypeLogin.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE [def].[tTypeLogin] 2 | ( 3 | [TypeLoginId] CHAR(1) NOT NULL, 4 | [TypeDescription] VARCHAR(30) NOT NULL 5 | CONSTRAINT [def_pkTypeLogin] PRIMARY KEY CLUSTERED ([TypeLoginId] ASC), 6 | ) 7 | -------------------------------------------------------------------------------- /DataGuard/mon/Tables/mon.tUserState.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE [mon].[tUserState] 2 | ( 3 | [UserStateId] INT NOT NULL PRIMARY KEY, 4 | [DatabaseName] SYSNAME NULL, 5 | [User] SYSNAME NULL, 6 | [PermissionType] varchar(100) NULL 7 | 8 | ) 9 | -------------------------------------------------------------------------------- /DataGuard.dbtests/Test/Procedures/test database DataGuard existing.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [test].[test database DataGuard existing] 2 | AS 3 | BEGIN 4 | 5 | EXEC [dbo].[pThrowErrorIfDatabaseNotExists] @DatabaseName = [DataGuard], @IsDebug =1 6 | 7 | END; 8 | GO -------------------------------------------------------------------------------- /DataGuard.dbtests/Scripts/Post-Deploy/tSQLt/tSQLt.Private_InstallationInfo.sql: -------------------------------------------------------------------------------- 1 | --Fix tSQLt version for SQL Server 2022 2 | CREATE OR ALTER FUNCTION [tSQLt].[Private_InstallationInfo]() 3 | RETURNS TABLE 4 | AS 5 | RETURN SELECT CAST(16.00 AS NUMERIC(10,2)) AS SqlVersion; -------------------------------------------------------------------------------- /DataGuard/Scripts/Post-Deploy/conf/SetInitialSetting.sql: -------------------------------------------------------------------------------- 1 | 2 | MERGE conf.tSetting d 3 | USING ( 4 | VALUES ('IsDemo', '1') 5 | ) s (SettingName, Value) 6 | ON d.[SettingName] =s.[SettingName] 7 | WHEN NOT MATCHED BY TARGET THEN 8 | INSERT ([SettingName],[Value]) 9 | VALUES (s.[SettingName],s.[Value]) 10 | ; -------------------------------------------------------------------------------- /DataGuard/mon/Tables/mon.tPermissionState.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE [mon].[tPermissionState] 2 | ( 3 | [PermissionStateId] INT NOT NULL PRIMARY KEY, 4 | [Database] SYSNAME NULL, 5 | [User] SYSNAME NULL, 6 | [Role] SYSNAME NULL, 7 | [ObjectType] SYSNAME NULL, 8 | [Schema] SYSNAME NULL, 9 | [ObjectName] SYSNAME NULL, 10 | [Permission] SYSNAME NULL 11 | 12 | ) 13 | -------------------------------------------------------------------------------- /DataGuard.dbtests/Scripts/Post-Deploy/tSQLt/tSQLt.SetExecutionBitOnExtenstionPropertyForSchemaTests.sql: -------------------------------------------------------------------------------- 1 | 2 | IF NOT EXISTS (SELECT * FROM SYS.EXTENDED_PROPERTIES WHERE class_desc = 'SCHEMA' AND NAME = 'tSQLt.TestClass' AND value = 1) 3 | BEGIN 4 | EXEC sp_addextendedproperty @name = N'tSQLt.TestClass', 5 | @value = 1, 6 | @level0type = 'SCHEMA', 7 | @level0name = 'test'; 8 | END -------------------------------------------------------------------------------- /DataGuard.dbtests/Test/Procedures/test database TestDataTest not existing.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [test].[test database TestDataTest not existing] 2 | AS 3 | BEGIN 4 | 5 | EXEC tSQLt.ExpectException @ExpectedMessagePattern = 'The database TestDataTest does not exists!', @ExpectedSeverity = 16, @ExpectedState = 1; 6 | -- EXEC tSQLt.ExpectException @Message = 'The database TestDataTest23 not exists!', @ExpectedSeverity = 16, @ExpectedState = 1; 7 | EXEC [dbo].[pThrowErrorIfDatabaseNotExists] @DatabaseName = [TestDataTest], @IsDebug =1 8 | 9 | END; 10 | GO -------------------------------------------------------------------------------- /DataGuard/Scripts/Post-Deploy/def/SetTypeLogin.sql: -------------------------------------------------------------------------------- 1 | 2 | 3 | MERGE def.tTypeLogin d 4 | USING ( 5 | VALUES ('S', 'SQL_LOGIN') 6 | ,('R', 'SERVER_ROLE') 7 | ,('C', 'CERTIFICATE_MAPPED_LOGIN') 8 | ,('U', 'WINDOWS_LOGIN') 9 | ) s ([TypeLoginId],[TypeDescription]) ON d.[TypeLoginId] =s.[TypeLoginId] 10 | WHEN MATCHED AND s.[TypeDescription] <> d.[TypeDescription] THEN 11 | UPDATE SET [TypeDescription] = s.[TypeDescription] 12 | WHEN NOT MATCHED BY TARGET THEN 13 | INSERT ([TypeLoginId],[TypeDescription]) 14 | VALUES (s.[TypeLoginId],s.[TypeDescription]) 15 | WHEN NOT MATCHED BY SOURCE THEN 16 | DELETE; -------------------------------------------------------------------------------- /DataGuard/local.publish.xml: -------------------------------------------------------------------------------- 1 | 2 | 3 | 4 | True 5 | DataGuard 6 | DataGuard.sql 7 | Data Source=(local)\SQL2022DEV;Integrated Security=True;Persist Security Info=False;Pooling=False;Multiple Active Result Sets=False;Connect Timeout=60;Encrypt=True;Trust Server Certificate=True;Command Timeout=0 8 | 1 9 | 10 | -------------------------------------------------------------------------------- /PermissionMatrix.txt: -------------------------------------------------------------------------------- 1 | 2 | ObjectType Table View Procedure InlineFunction ScalarFunction Schema VirtualPermission 3 | =================================================================================================== 4 | Alter x x x x x x Owner 5 | Control x x x x x x Owner 6 | Execute x x x Execute 7 | References x x x x x 8 | Take ownership x x x x x x 9 | View definition x x x x x x ViewDefinition 10 | Delete x x x x Write 11 | Insert x x x x Write 12 | Select x x x x Read 13 | Update x x x x Write 14 | View change tracking x x x Owner 15 | Create sequence x -------------------------------------------------------------------------------- /DataGuard/Scripts/Pre-Deploy/Script.PreDeployment.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Pre-Deployment Script Template 3 | -------------------------------------------------------------------------------------- 4 | This file contains SQL statements that will be executed before the build script. 5 | Use SQLCMD syntax to include a file in the pre-deployment script. 6 | Example: :r .\myfile.sql 7 | Use SQLCMD syntax to reference a variable in the pre-deployment script. 8 | Example: :setvar TableName MyTable 9 | SELECT * FROM [$(TableName)] 10 | -------------------------------------------------------------------------------------- 11 | */ 12 | 13 | 14 | PRINT N'Executing MaintainDbSettings.sql...'; 15 | GO 16 | :r .\MaintainDbSettings.sql 17 | GO 18 | -------------------------------------------------------------------------------- /DataGuard.dbtests/Scripts/Post-Deploy/conf/SetTableDatabase.sql: -------------------------------------------------------------------------------- 1 | 2 | ;WITH sysDatabases AS ( 3 | select 4 | d.name COLLATE SQL_Latin1_General_CP1_CI_AS AS [DatabaseName] 5 | ,case 6 | when d.name not in ('tempdb', 'model') THEN 1 7 | ELSE 0 8 | END AS [IsPermissionActive] 9 | from sys.databases (nolock) d 10 | ) 11 | 12 | 13 | MERGE conf.tDatabase d 14 | USING sysDatabases s 15 | ON d.[DatabaseName] =s.[DatabaseName] 16 | WHEN MATCHED AND s.[IsPermissionActive] <> d.[IsPermissionActive] THEN 17 | UPDATE SET [IsPermissionActive] = s.[IsPermissionActive] 18 | WHEN NOT MATCHED BY TARGET THEN 19 | INSERT ([DatabaseName],[IsPermissionActive]) 20 | VALUES (s.[DatabaseName],s.[IsPermissionActive]) 21 | -- WHEN NOT MATCHED BY SOURCE THEN 22 | -- DELETE 23 | ; -------------------------------------------------------------------------------- /DataGuard.dbtests/local.publish.xml: -------------------------------------------------------------------------------- 1 | 2 | 3 | 4 | True 5 | DataGuard 6 | DataGuard.dbtests.sql 7 | Data Source=(local)\SQL2022DEV;Integrated Security=True;Persist Security Info=False;Pooling=False;Multiple Active Result Sets=False;Connect Timeout=60;Encrypt=True;Trust Server Certificate=True;Command Timeout=0 8 | 1 9 | 10 | 11 | 12 | DataGuard 13 | 14 | 15 | -------------------------------------------------------------------------------- /DataGuard/Scripts/Post-Deploy/Script.PostDeployment.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Post-Deployment Script Template 3 | -------------------------------------------------------------------------------------- 4 | This file contains SQL statements that will be appended to the build script. 5 | Use SQLCMD syntax to include a file in the post-deployment script. 6 | Example: :r .\myfile.sql 7 | Use SQLCMD syntax to reference a variable in the post-deployment script. 8 | Example: :setvar TableName MyTable 9 | SELECT * FROM [$(TableName)] 10 | -------------------------------------------------------------------------------------- 11 | */ 12 | 13 | PRINT N'Executing def\SetTypeLogin.sql...'; 14 | GO 15 | :r .\def\SetTypeLogin.sql 16 | GO 17 | 18 | 19 | PRINT N'Executing conf\SetTableSetting.sql...'; 20 | GO 21 | :r .\conf\SetInitialSetting.sql 22 | GO 23 | 24 | -------------------------------------------------------------------------------- /DataGuard.dbtests/Scripts/Pre-Deploy/Script.PreDeployment.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Pre-Deployment Script Template 3 | -------------------------------------------------------------------------------------- 4 | This file contains SQL statements that will be executed before the build script. 5 | Use SQLCMD syntax to include a file in the pre-deployment script. 6 | Example: :r .\myfile.sql 7 | Use SQLCMD syntax to reference a variable in the pre-deployment script. 8 | Example: :setvar TableName MyTable 9 | SELECT * FROM [$(TableName)] 10 | -------------------------------------------------------------------------------------- 11 | */ 12 | 13 | 14 | PRINT N'Executing master\EnableCLR.sql...'; 15 | GO 16 | :r .\master\EnableCLR.sql 17 | GO 18 | 19 | PRINT N'Executing tSQLtTest\CreateSchemaTest.sql...'; 20 | GO 21 | :r .\tSQLtTest\CreateSchemaTest.sql 22 | GO -------------------------------------------------------------------------------- /DataGuard/dbo/Procedures/dbo.pThrowErrorIfDatabaseNotExists.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [dbo].[pThrowErrorIfDatabaseNotExists] 2 | @DatabaseName sysname, 3 | @IsDebug BIT = 0 4 | AS 5 | DECLARE @Sql nvarchar(3000) 6 | ,@ErrorMessage nvarchar(2000) 7 | ,@ExecQuery nvarchar(4000) 8 | ,@CRLF CHAR(2) = CHAR(13)+CHAR(10) 9 | ,@Tab nvarchar(10) = CHAR(9) 10 | 11 | IF @IsDebug = 1 12 | BEGIN 13 | SET @ExecQuery = CONCAT( 'EXEC ', QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)), '.', QUOTENAME(OBJECT_NAME(@@PROCID)), @CRLF, 14 | @Tab, ' @DatabaseName = ', @DatabaseName, @CRLF, 15 | @Tab, ',@IsDebug = ', @IsDebug ) 16 | 17 | PRINT @ExecQuery 18 | 19 | END 20 | 21 | 22 | IF DB_ID(@DatabaseName) IS NULL OR HAS_DBACCESS(@DatabaseName) = 0 23 | BEGIN 24 | SET @ErrorMessage = CONCAT('The database ',@DatabaseName,' does not exists!') 25 | ;THROW 50001, @ErrorMessage ,1; 26 | END 27 | 28 | -------------------------------------------------------------------------------- /DataGuard/dbo/Procedures/dbo.pGetListOfInstancePrincipals.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [dbo].[pGetListOfInstancePrincipals] 2 | @Type CHAR(1) = '%' 3 | ,@IsDebug BIT = 0 4 | AS 5 | DECLARE @Sql nvarchar(3000) 6 | ,@ErrorMessage nvarchar(2000) 7 | ,@ExecQuery nvarchar(4000) 8 | ,@CRLF CHAR(2) = CHAR(13)+CHAR(10) 9 | ,@Tab nvarchar(10) = CHAR(9) 10 | 11 | IF @IsDebug = 1 12 | BEGIN 13 | SET @ExecQuery = CONCAT( 'EXEC ', QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)), '.', QUOTENAME(OBJECT_NAME(@@PROCID)), @CRLF, 14 | @Tab, ',@IsDebug = ', @IsDebug ) 15 | PRINT @ExecQuery 16 | END 17 | 18 | 19 | 20 | SELECT 'SERVER' AS [ClassDesc] 21 | ,s.[type] AS [Type] 22 | ,s.[name] AS [LoginName] 23 | ,~s.is_disabled AS [IsActive] 24 | ,s.[modify_date] AS [LastModifiedOn] 25 | FROM sys.server_principals (nolock) s 26 | WHERE s.type LIKE @Type 27 | 28 | 29 | 30 | EXEC sp_executesql @sql -------------------------------------------------------------------------------- /DataGuard/dbo/Procedures/dbo.pGetListOfInstancePermissions.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [dbo].[pGetListOfInstancePermissions] 2 | @IsDebug BIT = 0 3 | AS 4 | DECLARE 5 | @ErrorMessage nvarchar(2000) 6 | ,@ExecQuery nvarchar(4000) 7 | ,@CRLF CHAR(2) = CHAR(13)+CHAR(10) 8 | ,@Tab nvarchar(10) = CHAR(9) 9 | 10 | IF @IsDebug = 1 11 | BEGIN 12 | SET @ExecQuery = CONCAT( 'EXEC ', QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)), '.', QUOTENAME(OBJECT_NAME(@@PROCID)), @CRLF, 13 | @Tab, '@IsDebug = ', @IsDebug ) 14 | 15 | PRINT @ExecQuery 16 | 17 | END 18 | 19 | 20 | SELECT DISTINCT 21 | c.[type] AS [Type] 22 | ,c.[name] AS [UserName] --RoleName 23 | ,m.[class_desc] AS [ClassDesc] 24 | ,m.[permission_name] AS [PermmisionType] 25 | ,m.[state_desc] AS [PermmisionState] 26 | 27 | FROM sys.server_principals (nolock) c 28 | INNER JOIN sys.server_permissions (nolock) m ON m.[grantee_principal_id] = c.[principal_id] 29 | 30 | 31 | 32 | 33 | -------------------------------------------------------------------------------- /DataGuard/dbo/Procedures/dbo.pGetListOfInstanceRoles.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [dbo].[pGetListOfInstanceRoles] 2 | @IsDebug BIT = 0 3 | AS 4 | DECLARE @Sql nvarchar(3000) 5 | ,@ErrorMessage nvarchar(2000) 6 | ,@ExecQuery nvarchar(4000) 7 | ,@CRLF CHAR(2) = CHAR(13)+CHAR(10) 8 | ,@Tab nvarchar(10) = CHAR(9) 9 | 10 | IF @IsDebug = 1 11 | BEGIN 12 | SET @ExecQuery = CONCAT( 'EXEC ', QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)), '.', QUOTENAME(OBJECT_NAME(@@PROCID)), @CRLF, 13 | @Tab, '@IsDebug = ', @IsDebug ) 14 | 15 | PRINT @ExecQuery 16 | END 17 | 18 | 19 | SELECT 'SERVER' AS [ClassDesc] 20 | ,s.[type] AS [Type] 21 | ,s.[name] AS [LoginName] 22 | ,pc.[name] AS [RoleName] 23 | 24 | 25 | FROM sys.server_principals (nolock) s 26 | INNER JOIN sys.server_role_members (nolock) rm ON rm.[member_principal_id] = s.[principal_id] 27 | INNER JOIN sys.server_principals (nolock) pc ON rm.[role_principal_id] = pc.[principal_id] 28 | 29 | 30 | 31 | 32 | -------------------------------------------------------------------------------- /DataGuard.dbtests/Scripts/Post-Deploy/Script.PostDeployment.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Post-Deployment Script Template 3 | -------------------------------------------------------------------------------------- 4 | This file contains SQL statements that will be appended to the build script. 5 | Use SQLCMD syntax to include a file in the post-deployment script. 6 | Example: :r .\myfile.sql 7 | Use SQLCMD syntax to reference a variable in the post-deployment script. 8 | Example: :setvar TableName MyTable 9 | SELECT * FROM [$(TableName)] 10 | -------------------------------------------------------------------------------------- 11 | */ 12 | 13 | 14 | PRINT N'Executing conf\SetTableDatabase.sql...'; 15 | GO 16 | :r .\conf\SetTableDatabase.sql 17 | GO 18 | 19 | 20 | PRINT N'Executing tSQLt\tSQLt.Private_InstallationInfo.sql...'; 21 | GO 22 | :r .\tSQLt\tSQLt.Private_InstallationInfo.sql 23 | GO 24 | 25 | PRINT N'Executing tSQLt\tSQLt.SetExecutionBitOnExtenstionPropertyForSchemaTests.sql...'; 26 | GO 27 | :r .\tSQLt\tSQLt.SetExecutionBitOnExtenstionPropertyForSchemaTests.sql 28 | GO -------------------------------------------------------------------------------- /DataGuard.dbtests/Test/Procedures/test conf.tDatabase try change CreatedOn.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [test].[test conf.tDatabase try change CreatedOn] 2 | AS 3 | BEGIN 4 | 5 | DECLARE @DatabaseName SYSNAME = 'TestDB' 6 | 7 | ,@DatabaseId INT 8 | ,@CreatedOn DATETIME2(3) 9 | 10 | 11 | SELECT TOP (1) 12 | @DatabaseId = [DatabaseId] 13 | ,@CreatedOn = [CreatedOn] 14 | FROM [conf].[tDatabase] 15 | WHERE [DatabaseName] = @DatabaseName 16 | 17 | 18 | IF @DatabaseId IS NOT NULL 19 | BEGIN 20 | 21 | 22 | EXEC tSQLt.ExpectException @ExpectedMessagePattern = 'Updating columns CreatedBy, CreatedOn is not allowed!', @ExpectedSeverity = NULL, @ExpectedState = NULL; 23 | 24 | UPDATE [DataGuard].[conf].[tDatabase] 25 | SET [CreatedOn] = '2000-01-01 00:00:00' 26 | WHERE DatabaseId = @DatabaseId 27 | 28 | END 29 | ELSE 30 | BEGIN 31 | DECLARE @ErrorMessage nvarchar(200) = CONCAT('The database record ', @DatabaseName, ' does not Exists in conf.tDatabase table') 32 | EXEC tSQLt.Fail @ErrorMessage 33 | END 34 | END; 35 | GO -------------------------------------------------------------------------------- /DataGuard.dbtests/Test/Procedures/test conf.tDatabase try change CreatedBy.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [test].[test conf.tDatabase try change CreatedBy] 2 | AS 3 | BEGIN 4 | 5 | DECLARE @DatabaseName SYSNAME = 'TestDB' 6 | 7 | ,@DatabaseId INT 8 | ,@CreatedBy NVARCHAR(128) 9 | 10 | 11 | SELECT TOP (1) 12 | @DatabaseId = [DatabaseId] 13 | ,@CreatedBy = [CreatedBy] 14 | FROM [conf].[tDatabase] 15 | WHERE [DatabaseName] = @DatabaseName 16 | 17 | 18 | IF @DatabaseId IS NOT NULL 19 | BEGIN 20 | 21 | 22 | EXEC tSQLt.ExpectException @ExpectedMessagePattern = 'Updating columns CreatedBy, CreatedOn is not allowed!', @ExpectedSeverity = NULL, @ExpectedState = NULL; 23 | 24 | UPDATE [DataGuard].[conf].[tDatabase] 25 | SET [CreatedBy] = CONCAT('WrongTestUser-ManualChenged', CONVERT(nvarchar(30),GETDATE(), 121)) 26 | WHERE DatabaseId = @DatabaseId 27 | 28 | END 29 | ELSE 30 | BEGIN 31 | DECLARE @ErrorMessage nvarchar(200) = CONCAT('The database record ', @DatabaseName, ' does not Exists in conf.tDatabase table') 32 | EXEC tSQLt.Fail @ErrorMessage 33 | END 34 | END; 35 | GO -------------------------------------------------------------------------------- /DataGuard/dbo/Procedures/dbo.pIsDatabaseExists.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [dbo].[pIsDatabaseExists] 2 | @DatabaseName sysname, 3 | @IsDebug BIT = 0 4 | AS 5 | DECLARE @Sql nvarchar(3000) 6 | ,@ErrorMessage nvarchar(2000) 7 | ,@Result BIT = 0 8 | ,@ExecQuery nvarchar(4000) 9 | ,@CRLF CHAR(2) = CHAR(13)+CHAR(10) 10 | ,@Tab nvarchar(10) = CHAR(9) 11 | 12 | IF @IsDebug = 1 13 | BEGIN 14 | SET @ExecQuery = CONCAT( 'EXEC ', QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)), '.', QUOTENAME(OBJECT_NAME(@@PROCID)), @CRLF, 15 | @Tab, ' @DatabaseName = ', @DatabaseName, @CRLF, 16 | @Tab, ',@IsDebug = ', @IsDebug ) 17 | 18 | PRINT @ExecQuery 19 | 20 | END 21 | 22 | 23 | IF DB_ID(@DatabaseName) IS NULL OR HAS_DBACCESS(@DatabaseName) = 0 24 | BEGIN 25 | SET @ErrorMessage = CONCAT('The database ',@DatabaseName,' not exists!') 26 | ;THROW 50001, @ErrorMessage ,1; 27 | END 28 | 29 | SET @sql = 'SELECT @Result = 1 FROM [sys].[databases] (nolock) where [name] = @DatabaseName' 30 | IF @IsDebug = 1 PRINT @sql 31 | 32 | EXEC sp_executesql @sql, N'@Result bit OUTPUT, @DatabaseName sysname', @Result=@Result OUTPUT, @DatabaseName =@DatabaseName 33 | 34 | IF @IsDebug = 1 PRINT @Result 35 | 36 | 37 | 38 | RETURN @Result 39 | -------------------------------------------------------------------------------- /DataGuard/dbo/Procedures/dbo.pIsSchemaExists.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [dbo].[pIsSchemaExists] 2 | @SchemaName sysname, 3 | @DatabaseName sysname, 4 | @IsDebug BIT = 0 5 | AS 6 | DECLARE @Sql nvarchar(3000) 7 | ,@ErrorMessage nvarchar(2000) 8 | ,@Result BIT = 0 9 | ,@ExecQuery nvarchar(4000) 10 | ,@CRLF CHAR(2) = CHAR(13)+CHAR(10) 11 | ,@Tab nvarchar(10) = CHAR(9) 12 | 13 | IF @IsDebug = 1 14 | BEGIN 15 | SET @ExecQuery = CONCAT( 'EXEC ', QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)), '.', QUOTENAME(OBJECT_NAME(@@PROCID)), @CRLF, 16 | @Tab, ' @SchemaName = ', @SchemaName, @CRLF, 17 | @Tab, ',@DatabaseName = ', @DatabaseName, @CRLF, 18 | @Tab, ',@IsDebug = ', @IsDebug ) 19 | 20 | PRINT @ExecQuery 21 | 22 | END 23 | 24 | 25 | IF DB_ID(@DatabaseName) IS NULL OR HAS_DBACCESS(@DatabaseName) = 0 26 | BEGIN 27 | SET @ErrorMessage = CONCAT('The database ',@DatabaseName,' not exists!') 28 | ;THROW 50001, @ErrorMessage ,1; 29 | END 30 | 31 | 32 | --TODO 33 | SET @sql = CONCAT('SELECT @Result = 1 FROM ',QUOTENAME(@DatabaseName),'.[sys].[schemas] (nolock) where [name] = @SchemaName') 34 | PRINT @sql 35 | 36 | EXEC sp_executesql @sql, N'@Result bit OUTPUT, @SchemaName sysname', @Result=@Result OUTPUT, @SchemaName =@SchemaName 37 | 38 | PRINT @Result 39 | 40 | -- 41 | 42 | RETURN @Result 43 | -------------------------------------------------------------------------------- /DataGuard/dbo/Procedures/dbo.pGetListOfDatabaseRoles.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [dbo].[pGetListOfDatabaseRoles] 2 | @DatabaseName sysname, 3 | @IsDebug BIT = 0 4 | AS 5 | DECLARE @Sql nvarchar(3000) 6 | ,@ErrorMessage nvarchar(2000) 7 | ,@ExecQuery nvarchar(4000) 8 | ,@CRLF CHAR(2) = CHAR(13)+CHAR(10) 9 | ,@Tab nvarchar(10) = CHAR(9) 10 | 11 | IF @IsDebug = 1 12 | BEGIN 13 | SET @ExecQuery = CONCAT( 'EXEC ', QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)), '.', QUOTENAME(OBJECT_NAME(@@PROCID)), @CRLF, 14 | @Tab, ' @DatabaseName = ', @DatabaseName, @CRLF, 15 | @Tab, ',@IsDebug = ', @IsDebug ) 16 | PRINT @ExecQuery 17 | END 18 | 19 | EXEC [dbo].[pThrowErrorIfDatabaseNotExists] @DatabaseName = @DatabaseName, @IsDebug = @IsDebug 20 | 21 | SET @sql = CONCAT(' 22 | SELECT ',QUOTENAME(@DatabaseName,''''),' AS [DatabaseName] 23 | ,mc.[type] AS [Type] 24 | ,mc.[name] AS [UserName] 25 | ,rc.[name] AS [RoleName] 26 | 27 | FROM ', QUOTENAME(@DatabaseName),'.sys.database_role_members (nolock) m 28 | JOIN ', QUOTENAME(@DatabaseName),'.sys.database_principals (nolock) rc ON rc.[principal_id] = m.[role_principal_id] 29 | JOIN ', QUOTENAME(@DatabaseName),'.sys.database_principals (nolock) mc ON mc.[principal_id] = m.[member_principal_id] 30 | ' 31 | ) 32 | IF @IsDebug = 1 PRINT @sql 33 | 34 | 35 | EXEC sp_executesql @sql 36 | 37 | 38 | 39 | 40 | 41 | -------------------------------------------------------------------------------- /DataGuard.dbtests/Test/Procedures/test conf.tDatabase if record change update LastModifiedOn.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [test].[test conf.tDatabase if record change update LastModifiedOn] 2 | AS 3 | BEGIN 4 | 5 | DECLARE @DatabaseName SYSNAME = 'TestDB' 6 | 7 | ,@DatabaseId INT 8 | ,@LastModifiedOn DATETIME2(3) 9 | ,@NewLastModifiedOn DATETIME2(3) 10 | 11 | 12 | SELECT TOP (1) 13 | @DatabaseId = [DatabaseId] 14 | -- ,[LastModifiedBy] 15 | ,@LastModifiedOn = [LastModifiedOn] 16 | FROM [conf].[tDatabase] 17 | WHERE [DatabaseName] = @DatabaseName 18 | 19 | 20 | IF @DatabaseId IS NOT NULL 21 | BEGIN 22 | 23 | UPDATE [DataGuard].[conf].[tDatabase] 24 | SET [IsPermissionActive] = ~[IsPermissionActive] 25 | WHERE DatabaseId = @DatabaseId 26 | 27 | 28 | SELECT TOP 1 @NewLastModifiedOn = [LastModifiedOn] FROM [conf].[tDatabase] WHERE [DatabaseId] = @DatabaseId 29 | 30 | PRINT CONCAT('@LastModifiedOn=<',@LastModifiedOn,'>, @NewLastModifiedOn=<', @NewLastModifiedOn,'>') 31 | EXEC tSQLt.AssertNotEquals @NewLastModifiedOn, @LastModifiedOn; 32 | 33 | 34 | END 35 | ELSE 36 | BEGIN 37 | DECLARE @ErrorMessage nvarchar(200) = CONCAT('The database record ', @DatabaseName, ' does not Exists in conf.tDatabase table') 38 | EXEC tSQLt.Fail @ErrorMessage 39 | END 40 | END; 41 | GO -------------------------------------------------------------------------------- /DataGuard/dbo/Procedures/dbo.pGetListOfDatabaseUsers.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [dbo].[pGetListOfDatabaseUsers] 2 | @DatabaseName sysname, 3 | @IsDebug BIT = 0 4 | AS 5 | DECLARE @Sql nvarchar(3000) 6 | ,@ErrorMessage nvarchar(2000) 7 | ,@ExecQuery nvarchar(4000) 8 | ,@CRLF CHAR(2) = CHAR(13)+CHAR(10) 9 | ,@Tab nvarchar(10) = CHAR(9) 10 | 11 | IF @IsDebug = 1 12 | BEGIN 13 | SET @ExecQuery = CONCAT( 'EXEC ', QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)), '.', QUOTENAME(OBJECT_NAME(@@PROCID)), @CRLF, 14 | @Tab, ' @DatabaseName = ', @DatabaseName, @CRLF, 15 | @Tab, ',@IsDebug = ', @IsDebug ) 16 | PRINT @ExecQuery 17 | END 18 | 19 | EXEC [dbo].[pThrowErrorIfDatabaseNotExists] @DatabaseName = @DatabaseName, @IsDebug = @IsDebug 20 | 21 | 22 | SET @sql = CONCAT(' 23 | SELECT ',QUOTENAME(@DatabaseName,''''),' AS DatabaseName 24 | ,c.[name] AS [UserName] 25 | ,c.[type] AS [Type] 26 | ,c.[authentication_type] AS [AuthenticationType] 27 | ,CASE WHEN m.[permission_name] = N''CONNECT'' THEN 1 ELSE 0 END AS [IsEnable] 28 | 29 | FROM ', QUOTENAME(@DatabaseName),'.sys.database_principals (nolock) c 30 | LEFT JOIN ', QUOTENAME(@DatabaseName),'.sys.database_permissions (nolock) m ON m.[grantee_principal_id] = c.[principal_id] AND m.[permission_name] = N''CONNECT'' 31 | WHERE c.type IN (''S'',''G'',''U'') 32 | -- AND c.sid IS NOT NULL 33 | -- AND c.name <> N''guest'' 34 | ' 35 | ) 36 | PRINT @sql 37 | 38 | 39 | EXEC sp_executesql @sql 40 | -------------------------------------------------------------------------------- /DataGuard/sec/Procedures/sec.pCreateUser.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [sec].[pCreateUser] 2 | @DatabaseName sysname 3 | ,@UserName VARCHAR(128) 4 | ,@LoginName VARCHAR(128) 5 | ,@DefaultSchema VARCHAR(128) --= 'dbo' 6 | ,@IsDebug BIT = 0 7 | AS 8 | DECLARE @Sql nvarchar(3000) 9 | ,@Messsage nvarchar(4000) 10 | ,@ErrorMessage nvarchar(2000) 11 | ,@ExecQuery nvarchar(4000) 12 | ,@CRLF CHAR(2) = CHAR(13)+CHAR(10) 13 | ,@Tab nvarchar(10) = CHAR(9) 14 | 15 | IF @IsDebug = 1 16 | BEGIN 17 | SET @ExecQuery = CONCAT( 'EXEC ', QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)), '.', QUOTENAME(OBJECT_NAME(@@PROCID)), @CRLF, 18 | @Tab, ' @DatabaseName = ', @DatabaseName, @CRLF, 19 | @Tab, ' @UserName = ', @UserName, @CRLF, 20 | @Tab, ' @LoginName = ', @LoginName, @CRLF, 21 | @Tab, ' @DefaultSchema = ', @DefaultSchema , @CRLF, 22 | @Tab, ',@IsDebug = ', @IsDebug ) 23 | PRINT @ExecQuery 24 | END 25 | 26 | 27 | 28 | 29 | SET @Messsage = CONCAT('On Database ', @DatabaseName, ' User ', @UserName, ' will be created for login ', @LoginName) 30 | IF @IsDebug=1 PRINT @Messsage 31 | 32 | SET @Sql = CONCAT('USE ', QUOTENAME(@DatabaseName), @CRLF, 33 | ' CREATE USER ', QUOTENAME(@UserName), ' FOR LOGIN ' , QUOTENAME(@UserName) , ' WITH DEFAULT_SCHEMA = ''' + @DefaultSchema + '''' ) 34 | 35 | 36 | 37 | SET @Messsage = CONCAT('Create User ', QUOTENAME(@UserName)) 38 | IF @IsDebug=1 PRINT @Messsage 39 | 40 | BEGIN TRAN 41 | EXEC sp_executesql @sql 42 | 43 | ROLLBACK 44 | 45 | 46 | SET @Messsage = CONCAT('User ', QUOTENAME(@UserName) , ' was created.') 47 | IF @IsDebug=1 PRINT @Messsage 48 | 49 | -------------------------------------------------------------------------------- /DataGuard/dbo/Procedures/dbo.pGetLoginDiff.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [dbo].[pGetLoginDiff] 2 | @IsDebug BIT = 0 3 | AS 4 | DECLARE @Sql nvarchar(3000) 5 | ,@ErrorMessage nvarchar(2000) 6 | ,@ExecQuery nvarchar(4000) 7 | ,@CRLF CHAR(2) = CHAR(13)+CHAR(10) 8 | ,@Tab nvarchar(10) = CHAR(9) 9 | 10 | IF @IsDebug = 1 11 | BEGIN 12 | SET @ExecQuery = CONCAT( 'EXEC ', QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)), '.', QUOTENAME(OBJECT_NAME(@@PROCID)), @CRLF, 13 | @Tab, ',@IsDebug = ', @IsDebug ) 14 | PRINT @ExecQuery 15 | END 16 | 17 | 18 | 19 | CREATE TABLE #InstanceLogin 20 | ( 21 | [ClassDesc] VARCHAR(10) COLLATE SQL_Latin1_General_CP1_CI_AS 22 | ,[Type] CHAR(1) 23 | ,[LoginName] VARCHAR(128) COLLATE SQL_Latin1_General_CP1_CI_AS 24 | ,[IsActive] BIT 25 | ,[LastModifiedOn] DATETIME2(3) 26 | ) 27 | 28 | 29 | INSERT INTO #InstanceLogin 30 | EXEC [dbo].[pGetListOfInstancePrincipals] @IsDebug =@IsDebug 31 | 32 | 33 | SELECT DISTINCT 34 | COALESCE(c.LoginName , i.[LoginName] ) AS LoginName 35 | ,c.IsActive 36 | ,i.IsActive AS SysIsActive 37 | ,COALESCE(i.[LastModifiedOn] ,c.[LastModifiedOn] ) AS LastModifiedOn 38 | ,NULLIF(c.LoginName, i.LoginName) AS CreateLogin 39 | ,NULLIF(i.LoginName, c.LoginName) AS Droplogin 40 | ,CASE 41 | WHEN NULLIF(c.LoginName, i.LoginName) IS NULL AND NULLIF(i.LoginName, c.LoginName) IS NULL 42 | THEN NULLIF(c.IsActive, i.IsActive) 43 | END AS SwitchLogin 44 | 45 | FROM [conf].[tLogin] c (nolock) 46 | FULL OUTER JOIN #InstanceLogin i (nolock) ON c.LoginName = i.LoginName 47 | WHERE i.[Type] IN ('S', 'U', 'K') --C, R, S, U 48 | OR c.[TypeLoginId] IN ('S', 'U', 'K') 49 | 50 | -------------------------------------------------------------------------------- /DataGuard/sec/Procedures/sec.pCreateLogin.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [sec].[pCreateLogin] 2 | @LoginName VARCHAR(128) 3 | ,@IsDebug BIT = 0 4 | AS 5 | DECLARE @Sql nvarchar(3000) 6 | ,@Messsage nvarchar(4000) 7 | ,@ErrorMessage nvarchar(2000) 8 | ,@ExecQuery nvarchar(4000) 9 | ,@CRLF CHAR(2) = CHAR(13)+CHAR(10) 10 | ,@Tab nvarchar(10) = CHAR(9) 11 | 12 | IF @IsDebug = 1 13 | BEGIN 14 | SET @ExecQuery = CONCAT( 'EXEC ', QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)), '.', QUOTENAME(OBJECT_NAME(@@PROCID)), @CRLF, 15 | @Tab, ' @LoginName = ', @LoginName, @CRLF, 16 | @Tab, ',@IsDebug = ', @IsDebug ) 17 | PRINT @ExecQuery 18 | END 19 | 20 | 21 | IF @LoginName LIKE '%\%' 22 | BEGIN 23 | 24 | IF SUSER_SID(@LoginName) IS NULL 25 | BEGIN 26 | 27 | SET @ErrorMessage = CONCAT('The LoginName ''', @LoginName ,''' not exists in AD or you don''t have permissions') 28 | 29 | ;THROW 50000, @ErrorMessage, 1 30 | 31 | END 32 | 33 | SET @Messsage = CONCAT('Windows login ', @LoginName, ' will be created') 34 | IF @IsDebug=1 PRINT @Messsage 35 | 36 | SET @Sql = CONCAT('CREATE LOGIN ', QUOTENAME(@LoginName), ' FROM WINDOWS') 37 | 38 | END 39 | ELSE 40 | BEGIN 41 | 42 | SET @Messsage = CONCAT('SQL login ', @LoginName, ' will be created. You must change password') 43 | IF @IsDebug=1 PRINT @Messsage 44 | 45 | SET @Sql = CONCAT('CREATE LOGIN ', QUOTENAME(@LoginName), ' WITH PASSWORD=N''', NEWID() ,''' MUST_CHANGE, CHECK_EXPIRATION=ON') 46 | 47 | END 48 | 49 | 50 | SET @Messsage = CONCAT('Create login ', QUOTENAME(@LoginName)) 51 | IF @IsDebug=1 PRINT @Messsage 52 | 53 | BEGIN TRAN 54 | EXEC sp_executesql @sql 55 | 56 | ROLLBACK 57 | 58 | 59 | SET @Messsage = CONCAT('Login ', QUOTENAME(@LoginName) , ' was created.') 60 | IF @IsDebug=1 PRINT @Messsage 61 | 62 | -------------------------------------------------------------------------------- /DataGuard/dbo/Procedures/dbo.pGetListOfDatabasePermissions.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [dbo].[pGetListOfDatabasePermissions] 2 | @DatabaseName sysname, 3 | @IsDebug BIT = 0 4 | AS 5 | DECLARE @Sql nvarchar(3000) 6 | ,@ErrorMessage nvarchar(2000) 7 | ,@ExecQuery nvarchar(4000) 8 | ,@CRLF CHAR(2) = CHAR(13)+CHAR(10) 9 | ,@Tab nvarchar(10) = CHAR(9) 10 | 11 | IF @IsDebug = 1 12 | BEGIN 13 | SET @ExecQuery = CONCAT( 'EXEC ', QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)), '.', QUOTENAME(OBJECT_NAME(@@PROCID)), @CRLF, 14 | @Tab, ' @DatabaseName = ', @DatabaseName, @CRLF, 15 | @Tab, ',@IsDebug = ', @IsDebug ) 16 | 17 | PRINT @ExecQuery 18 | END 19 | 20 | EXEC [dbo].[pThrowErrorIfDatabaseNotExists] @DatabaseName = @DatabaseName, @IsDebug = @IsDebug 21 | 22 | 23 | SET @sql = CONCAT(' 24 | SELECT DISTINCT 25 | ',QUOTENAME(@DatabaseName,''''),' AS [DatabaseName] 26 | ,c.[type] AS [Type] 27 | ,c.[name] AS [UserName] 28 | ,m.[class_desc] AS [ClassDesc] 29 | ,m.[permission_name] AS [PermisssionType] 30 | ,m.[state_desc] AS [PermisssionState] 31 | ,COALESCE(sm.[name], so.[name]) AS [SchemaName] 32 | ,o.[type_desc] AS [ObjectType] 33 | ,o.[name] AS [ObjectName] 34 | FROM ', QUOTENAME(@DatabaseName),'.sys.database_principals (nolock) c 35 | LEFT JOIN ', QUOTENAME(@DatabaseName),'.sys.database_permissions (nolock) m ON m.[grantee_principal_id] = c.[principal_id] 36 | LEFT JOIN ', QUOTENAME(@DatabaseName),'.sys.all_objects (nolock) o ON m.[major_id] = o.[object_id] 37 | LEFT JOIN ', QUOTENAME(@DatabaseName),'.sys.schemas (nolock) so ON o.[schema_id] = so.[schema_id] 38 | LEFT JOIN ', QUOTENAME(@DatabaseName),'.sys.schemas (nolock) sm ON m.[major_id] = sm.[schema_id] 39 | WHERE c.[Type] IN (''U'',''G'')' 40 | ) 41 | PRINT @sql 42 | 43 | 44 | EXEC sp_executesql @sql 45 | 46 | 47 | 48 | 49 | 50 | -------------------------------------------------------------------------------- /DataGuard/DataGuard.refactorlog: -------------------------------------------------------------------------------- 1 | 2 | 3 | 4 | 5 | 6 | 7 | 8 | 9 | 10 | 11 | 12 | 13 | 14 | 15 | 16 | 17 | 18 | 19 | 20 | 21 | 22 | 23 | 24 | 25 | 26 | 27 | 28 | 29 | 30 | 31 | -------------------------------------------------------------------------------- /DataGuard/dbo/Procedures/dbo.pObjectInSystem.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [dbo].[pObjectInSystem] 2 | @DatabaseName sysname, 3 | @IsDebug BIT = 0 4 | AS 5 | 6 | DECLARE @Sql nvarchar(3000) 7 | ,@ErrorMessage nvarchar(2000) 8 | ,@ExecQuery nvarchar(4000) 9 | ,@CRLF CHAR(2) = CHAR(13)+CHAR(10) 10 | ,@Tab nvarchar(10) = CHAR(9) 11 | 12 | IF @IsDebug = 1 13 | BEGIN 14 | SET @ExecQuery = CONCAT( 'EXEC ', QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)), '.', QUOTENAME(OBJECT_NAME(@@PROCID)), @CRLF, 15 | @Tab, ' @DatabaseName = ', IIF(@DatabaseName LIKE '%', QUOTENAME(@DatabaseName,''''), @DatabaseName ) , @CRLF, 16 | @Tab, ',@IsDebug = ', @IsDebug ) 17 | 18 | PRINT @ExecQuery 19 | 20 | END 21 | 22 | 23 | IF OBJECT_ID('tempdb..#ObjectInSystem') IS NOT NULL DROP TABLE #ObjectInSystem 24 | 25 | 26 | CREATE TABLE #ObjectInSystem 27 | ( 28 | [DatabaseName] sysname NULL 29 | ,[Type] varchar(100) 30 | ,[SchemaName] sysname NULL 31 | ,[ObjectName] varchar(100) 32 | ) 33 | 34 | 35 | 36 | IF @DatabaseName <> '%' 37 | BEGIN 38 | INSERT INTO #ObjectInSystem ([DatabaseName], [Type], [SchemaName], [ObjectName]) 39 | EXEC [dbo].[pGetListOfDatabaseObject] @DatabaseName=@DatabaseName, @IsDebug= @IsDebug 40 | END 41 | 42 | 43 | 44 | 45 | IF @DatabaseName = '%' 46 | BEGIN 47 | 48 | DECLARE @DatabaseNameLoop sysname 49 | 50 | DECLARE databaseNameCursor CURSOR READ_ONLY FOR 51 | SELECT DatabaseName 52 | FROM [conf].[tDatabase] (nolock) 53 | WHERE IsPermissionActive = 1 54 | AND DatabaseName IS NOT NULL 55 | 56 | OPEN databaseNameCursor 57 | FETCH NEXT FROM databaseNameCursor INTO @DatabaseNameLoop 58 | 59 | WHILE @@FETCH_STATUS =0 60 | BEGIN 61 | 62 | BEGIN TRY 63 | INSERT INTO #ObjectInSystem ([DatabaseName], [Type], [SchemaName], [ObjectName]) 64 | EXEC [dbo].[pGetListOfDatabaseObject] @DatabaseName=@DatabaseNameLoop, @IsDebug= @IsDebug 65 | END TRY 66 | BEGIN CATCH 67 | SET @ErrorMessage = CONCAT('Error when get data from dbo.pGetListOfDatabaseObject on DatabaseName ', @DatabaseNameLoop) 68 | PRINT @ErrorMessage 69 | END CATCH 70 | 71 | 72 | FETCH NEXT FROM databaseNameCursor INTO @DatabaseNameLoop 73 | END 74 | 75 | CLOSE databaseNameCursor 76 | DEALLOCATE databaseNameCursor 77 | 78 | END 79 | 80 | 81 | 82 | SELECT * 83 | FROM #ObjectInSystem 84 | -------------------------------------------------------------------------------- /DataGuard/dbo/Procedures/dbo.pGetUserDiff.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [dbo].[pGetUserDiff] 2 | @DatabaseName sysname, 3 | @IsDebug BIT = 0 4 | AS 5 | DECLARE @Sql nvarchar(3000) 6 | ,@ErrorMessage nvarchar(2000) 7 | ,@ExecQuery nvarchar(4000) 8 | ,@CRLF CHAR(2) = CHAR(13)+CHAR(10) 9 | ,@Tab nvarchar(10) = CHAR(9) 10 | 11 | IF @IsDebug = 1 12 | BEGIN 13 | SET @ExecQuery = CONCAT( 'EXEC ', QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)), '.', QUOTENAME(OBJECT_NAME(@@PROCID)), @CRLF, 14 | @Tab, ' @DatabaseName = ', @DatabaseName, @CRLF, 15 | @Tab, ',@IsDebug = ', @IsDebug ) 16 | PRINT @ExecQuery 17 | END 18 | 19 | 20 | 21 | 22 | CREATE TABLE #DatabaseUser 23 | ( 24 | [DatabaseName] SYSNAME COLLATE SQL_Latin1_General_CP1_CI_AS 25 | ,[UserName] VARCHAR(128) COLLATE SQL_Latin1_General_CP1_CI_AS 26 | ,[Type] CHAR(1) 27 | ,[AuthenticationType] VARCHAR(20) COLLATE SQL_Latin1_General_CP1_CI_AS 28 | ,[IsEnable] BIT 29 | ) 30 | 31 | 32 | IF @DatabaseName <> '%' 33 | BEGIN 34 | INSERT INTO #DatabaseUser 35 | EXEC [dbo].[pGetListOfDatabaseUsers] @DatabaseName =@DatabaseName, @IsDebug =@IsDebug 36 | END 37 | 38 | 39 | IF @DatabaseName = '%' 40 | BEGIN 41 | 42 | DECLARE @DatabaseNameLoop sysname 43 | 44 | DECLARE databaseNameCursor CURSOR READ_ONLY FOR 45 | SELECT DatabaseName 46 | FROM [conf].[tDatabase] (nolock) 47 | WHERE IsPermissionActive = 1 48 | AND DatabaseName IS NOT NULL 49 | 50 | OPEN databaseNameCursor 51 | FETCH NEXT FROM databaseNameCursor INTO @DatabaseNameLoop 52 | 53 | WHILE @@FETCH_STATUS =0 54 | BEGIN 55 | 56 | BEGIN TRY 57 | INSERT INTO #DatabaseUser 58 | EXEC [dbo].[pGetListOfDatabaseUsers] @DatabaseName=@DatabaseNameLoop, @IsDebug= @IsDebug 59 | END TRY 60 | BEGIN CATCH 61 | SET @ErrorMessage = CONCAT('Error when get users from dbo.pGetListOfDatabaseUsers on DatabaseName ', @DatabaseNameLoop) 62 | PRINT @ErrorMessage 63 | END CATCH 64 | 65 | FETCH NEXT FROM databaseNameCursor INTO @DatabaseNameLoop 66 | END 67 | 68 | CLOSE databaseNameCursor 69 | DEALLOCATE databaseNameCursor 70 | END 71 | 72 | 73 | -- select * from #DatabaseUser 74 | 75 | SELECT DISTINCT 76 | COALESCE(cd.DatabaseName, d.[DatabaseName] ) AS DatabaseName 77 | ,COALESCE(c.UserName, d.[UserName] ) AS UserName 78 | ,c.IsActive AS IsEnable 79 | ,d.IsEnable AS SysIsEnable 80 | ,NULLIF(c.UserName, d.UserName) AS CreateUser 81 | ,NULLIF(d.UserName, c.UserName) AS DropUser 82 | ,CASE 83 | WHEN NULLIF(c.UserName, d.UserName) IS NULL AND NULLIF(d.UserName, c.UserName) IS NULL 84 | THEN NULLIF(c.IsActive, d.IsEnable) 85 | END AS SwitchUser 86 | 87 | FROM [conf].[tUser] c (nolock) 88 | INNER JOIN [conf].[tPermission] p (nolock) ON c.UserId = p.UserId 89 | INNER JOIN [conf].[tDatabase] cd (nolock) ON c.DatabaseId =cd.DatabaseId 90 | FULL OUTER JOIN #DatabaseUser d (nolock) ON cd.[DatabaseName] = d.[DatabaseName] AND c.[UserName] = d.[UserName] 91 | 92 | 93 | -------------------------------------------------------------------------------- /DataGuard.sln: -------------------------------------------------------------------------------- 1 | 2 | Microsoft Visual Studio Solution File, Format Version 12.00 3 | # Visual Studio Version 17 4 | VisualStudioVersion = 17.8.34511.84 5 | MinimumVisualStudioVersion = 10.0.40219.1 6 | Project("{00D1A9C2-B5F0-4AF3-8072-F6C62B433612}") = "DataGuard", "DataGuard\DataGuard.sqlproj", "{03BA78EB-EE24-45A2-86F8-35BFEF5BE1A6}" 7 | EndProject 8 | Project("{2150E333-8FDC-42A3-9474-1A3956D46DE8}") = "Solution Items", "Solution Items", "{50D0878D-C512-4C88-AB6C-4F54759807BB}" 9 | ProjectSection(SolutionItems) = preProject 10 | .gitignore = .gitignore 11 | data-guard-logo.jpg = data-guard-logo.jpg 12 | LICENSE.md = LICENSE.md 13 | README.md = README.md 14 | EndProjectSection 15 | EndProject 16 | Project("{2150E333-8FDC-42A3-9474-1A3956D46DE8}") = "src", "src", "{7E1645A1-DBD3-4407-9E42-5DCBD05F1925}" 17 | EndProject 18 | Project("{2150E333-8FDC-42A3-9474-1A3956D46DE8}") = "doc", "doc", "{D5C2FB82-F627-4A49-AB39-13F679EB9BB1}" 19 | ProjectSection(SolutionItems) = preProject 20 | PermissionMatrix.txt = PermissionMatrix.txt 21 | EndProjectSection 22 | EndProject 23 | Project("{00D1A9C2-B5F0-4AF3-8072-F6C62B433612}") = "DataGuard.dbtests", "DataGuard.dbtests\DataGuard.dbtests.sqlproj", "{A5298359-A4B2-47B0-9D0B-7200B32D0B7D}" 24 | EndProject 25 | Project("{2150E333-8FDC-42A3-9474-1A3956D46DE8}") = "External", "External", "{D650D96E-5CA0-4324-B078-84901AF5E272}" 26 | ProjectSection(SolutionItems) = preProject 27 | External\tSQLt.2019.dacpac = External\tSQLt.2019.dacpac 28 | EndProjectSection 29 | EndProject 30 | Global 31 | GlobalSection(SolutionConfigurationPlatforms) = preSolution 32 | Debug|Any CPU = Debug|Any CPU 33 | Release|Any CPU = Release|Any CPU 34 | EndGlobalSection 35 | GlobalSection(ProjectConfigurationPlatforms) = postSolution 36 | {03BA78EB-EE24-45A2-86F8-35BFEF5BE1A6}.Debug|Any CPU.ActiveCfg = Debug|Any CPU 37 | {03BA78EB-EE24-45A2-86F8-35BFEF5BE1A6}.Debug|Any CPU.Build.0 = Debug|Any CPU 38 | {03BA78EB-EE24-45A2-86F8-35BFEF5BE1A6}.Debug|Any CPU.Deploy.0 = Debug|Any CPU 39 | {03BA78EB-EE24-45A2-86F8-35BFEF5BE1A6}.Release|Any CPU.ActiveCfg = Release|Any CPU 40 | {03BA78EB-EE24-45A2-86F8-35BFEF5BE1A6}.Release|Any CPU.Build.0 = Release|Any CPU 41 | {03BA78EB-EE24-45A2-86F8-35BFEF5BE1A6}.Release|Any CPU.Deploy.0 = Release|Any CPU 42 | {A5298359-A4B2-47B0-9D0B-7200B32D0B7D}.Debug|Any CPU.ActiveCfg = Debug|Any CPU 43 | {A5298359-A4B2-47B0-9D0B-7200B32D0B7D}.Debug|Any CPU.Build.0 = Debug|Any CPU 44 | {A5298359-A4B2-47B0-9D0B-7200B32D0B7D}.Debug|Any CPU.Deploy.0 = Debug|Any CPU 45 | {A5298359-A4B2-47B0-9D0B-7200B32D0B7D}.Release|Any CPU.ActiveCfg = Release|Any CPU 46 | {A5298359-A4B2-47B0-9D0B-7200B32D0B7D}.Release|Any CPU.Build.0 = Release|Any CPU 47 | {A5298359-A4B2-47B0-9D0B-7200B32D0B7D}.Release|Any CPU.Deploy.0 = Release|Any CPU 48 | EndGlobalSection 49 | GlobalSection(SolutionProperties) = preSolution 50 | HideSolutionNode = FALSE 51 | EndGlobalSection 52 | GlobalSection(NestedProjects) = preSolution 53 | {03BA78EB-EE24-45A2-86F8-35BFEF5BE1A6} = {7E1645A1-DBD3-4407-9E42-5DCBD05F1925} 54 | {A5298359-A4B2-47B0-9D0B-7200B32D0B7D} = {7E1645A1-DBD3-4407-9E42-5DCBD05F1925} 55 | {D650D96E-5CA0-4324-B078-84901AF5E272} = {7E1645A1-DBD3-4407-9E42-5DCBD05F1925} 56 | EndGlobalSection 57 | GlobalSection(ExtensibilityGlobals) = postSolution 58 | SolutionGuid = {1F663CF2-4A53-41AA-886E-18FB9DFD5F42} 59 | EndGlobalSection 60 | EndGlobal 61 | -------------------------------------------------------------------------------- /DataGuard/conf/Tables/conf.tSetting.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE [conf].[tSetting] 2 | ( 3 | [SettingId] INT IDENTITY (1, 1) NOT NULL, 4 | [SettingName] VARCHAR(50) NOT NULL, 5 | [Value] VARCHAR(50) NOT NULL, 6 | [CreatedBy] NVARCHAR (128) CONSTRAINT [conf_dfSetting_CreatedBy] DEFAULT (SYSTEM_USER) NOT NULL, 7 | [CreatedOn] DATETIME2(3) CONSTRAINT [conf_dfSetting_CreatedOn] DEFAULT (GETDATE()) NOT NULL, 8 | [LastModifiedBy] NVARCHAR (128) CONSTRAINT [conf_dfSetting_LastModifiedBy] DEFAULT (SYSTEM_USER) NOT NULL, 9 | [LastModifiedOn] DATETIME2(3) CONSTRAINT [conf_dfSetting_LastModifiedOn] DEFAULT (GETDATE()) NOT NULL, 10 | CONSTRAINT [conf_pkSetting] PRIMARY KEY NONCLUSTERED ([SettingName] ASC), 11 | ) 12 | 13 | GO 14 | 15 | CREATE CLUSTERED INDEX [uix_conf_Setting_SettingId] ON [conf].[tSetting]([SettingId]) 16 | 17 | GO 18 | 19 | 20 | CREATE TRIGGER [conf].[trg_tSetting_ModyficationMeta] 21 | ON [conf].[tSetting] 22 | WITH EXECUTE AS OWNER 23 | AFTER INSERT, UPDATE 24 | AS 25 | BEGIN 26 | 27 | IF (ROWCOUNT_BIG() =0) 28 | RETURN; 29 | 30 | SET NOCOUNT ON; 31 | IF EXISTS ( 32 | SELECT CreatedBy, CreatedOn FROM deleted 33 | EXCEPT 34 | SELECT CreatedBy, CreatedOn FROM inserted 35 | ) 36 | BEGIN 37 | ;THROW 51000, N'Updating columns CreatedBy, CreatedOn is not allowed!', 1; 38 | END 39 | 40 | DECLARE @SuserSname nvarchar(128) 41 | ,@Datetime DATETIME2(3) = SYSDATETIME() 42 | 43 | EXECUTE AS CALLER 44 | SET @SuserSname = SUSER_SNAME() 45 | REVERT; 46 | 47 | --CreateRecord 48 | UPDATE u 49 | SET CreatedBy = @SuserSname 50 | ,CreatedOn = @Datetime 51 | ,LastModifiedBy = @SuserSname 52 | ,LastModifiedOn = @Datetime 53 | FROM inserted i 54 | INNER JOIN [conf].[tSetting] u ON i.SettingId = u.SettingId 55 | LEFT JOIN deleted d ON i.SettingId = d.SettingId 56 | WHERE d.SettingId IS NULL 57 | 58 | 59 | 60 | IF EXISTS ( 61 | SELECT LastModifiedBy, LastModifiedOn FROM deleted 62 | EXCEPT 63 | SELECT LastModifiedBy, LastModifiedOn FROM inserted 64 | ) 65 | AND NOT EXISTS ( 66 | SELECT SettingName, Value FROM deleted 67 | EXCEPT 68 | SELECT SettingName, Value FROM inserted 69 | ) 70 | BEGIN 71 | UPDATE u 72 | SET LastModifiedBy = @SuserSname 73 | FROM inserted i 74 | INNER JOIN [conf].[tSetting] u ON i.SettingId = u.SettingId 75 | LEFT JOIN deleted d ON i.SettingId = d.SettingId 76 | WHERE i.LastModifiedBy <> @SuserSname 77 | 78 | UPDATE u 79 | SET LastModifiedOn = d.LastModifiedOn 80 | FROM inserted i 81 | INNER JOIN [conf].[tSetting] u ON i.SettingId = u.SettingId 82 | LEFT JOIN deleted d ON i.SettingId = d.SettingId 83 | WHERE i.LastModifiedBy = @SuserSname 84 | AND i.LastModifiedOn <> @Datetime 85 | END 86 | 87 | IF EXISTS ( 88 | SELECT * FROM deleted 89 | EXCEPT 90 | SELECT * FROM inserted 91 | ) 92 | BEGIN 93 | --UpdateRecord 94 | UPDATE u 95 | SET LastModifiedBy = @SuserSname 96 | ,LastModifiedOn = @Datetime 97 | FROM inserted i 98 | INNER JOIN [conf].[tSetting] u ON i.SettingId = u.SettingId 99 | LEFT JOIN deleted d ON i.SettingId = d.SettingId 100 | WHERE i.LastModifiedBy <> @SuserSname 101 | OR i.LastModifiedOn <> @Datetime 102 | -- OR i.[LoginId] <> d.[LoginId] 103 | -- OR i.[DefaultSchema] <> d.[DefaultSchema] 104 | -- OR i.[IsActive] <> d.[IsActive] 105 | 106 | END 107 | 108 | END -------------------------------------------------------------------------------- /DataGuard/conf/Tables/conf.tUser.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE [conf].[tUser] 2 | ( 3 | [UserId] INT IDENTITY (1, 1) NOT NULL, 4 | [UserName] NVARCHAR(256) NOT NULL, 5 | [DatabaseId] INT NULL, 6 | [LoginId] INT NULL, 7 | [DefaultSchema] NVARCHAR(128) NULL, 8 | [IsActive] BIT DEFAULT(1) NOT NULL, 9 | 10 | [CreatedBy] NVARCHAR (128) CONSTRAINT [conf_dfUser_CreatedBy] DEFAULT (SUSER_SNAME()) NOT NULL, 11 | [CreatedOn] DATETIME2(3) CONSTRAINT [conf_dfUser_CreatedOn] DEFAULT (SYSDATETIME()) NOT NULL, 12 | [LastModifiedBy] NVARCHAR (128) CONSTRAINT [conf_dfUser_LastModifiedBy] DEFAULT (SUSER_SNAME()) NOT NULL, 13 | [LastModifiedOn] DATETIME2(3) CONSTRAINT [conf_dfUser_LastModifiedOn] DEFAULT (SYSDATETIME()) NOT NULL, 14 | CONSTRAINT [conf_pkUser] PRIMARY KEY CLUSTERED ([UserId] ASC), 15 | CONSTRAINT [conf_fkUser_ToLogin] FOREIGN KEY ([LoginId]) REFERENCES [conf].[tLogin] ([LoginId]), 16 | ) 17 | 18 | GO 19 | 20 | 21 | CREATE UNIQUE NONCLUSTERED INDEX [uxUser_UserName_LoginId] 22 | ON [conf].[tUser]([UserName] ASC, [LoginId]); 23 | GO 24 | 25 | 26 | CREATE TRIGGER [conf].[trg_tUser_ModyficationMeta] 27 | ON [conf].[tUser] 28 | WITH EXECUTE AS OWNER 29 | AFTER INSERT, UPDATE 30 | AS 31 | BEGIN 32 | 33 | IF (ROWCOUNT_BIG() =0) 34 | RETURN; 35 | 36 | SET NOCOUNT ON; 37 | IF EXISTS ( 38 | SELECT CreatedBy, CreatedOn FROM deleted 39 | EXCEPT 40 | SELECT CreatedBy, CreatedOn FROM inserted 41 | ) 42 | BEGIN 43 | ;THROW 51000, N'Updating columns CreatedBy, CreatedOn is not allowed!', 1; 44 | END 45 | 46 | DECLARE @SuserSname nvarchar(128) 47 | ,@Datetime DATETIME2(3) = SYSDATETIME() 48 | 49 | EXECUTE AS CALLER 50 | SET @SuserSname = SUSER_SNAME() 51 | REVERT; 52 | 53 | --CreateRecord 54 | UPDATE u 55 | SET CreatedBy = @SuserSname 56 | ,CreatedOn = @Datetime 57 | ,LastModifiedBy = @SuserSname 58 | ,LastModifiedOn = @Datetime 59 | FROM inserted i 60 | INNER JOIN [conf].[tUser] u ON i.UserId = u.UserId 61 | LEFT JOIN deleted d ON i.UserId = d.UserId 62 | WHERE d.UserId IS NULL 63 | 64 | 65 | 66 | IF EXISTS ( 67 | SELECT LastModifiedBy, LastModifiedOn FROM deleted 68 | EXCEPT 69 | SELECT LastModifiedBy, LastModifiedOn FROM inserted 70 | ) 71 | AND NOT EXISTS ( 72 | SELECT UserName, LoginId, DefaultSchema, IsActive FROM deleted 73 | EXCEPT 74 | SELECT UserName, LoginId, DefaultSchema, IsActive FROM inserted 75 | ) 76 | BEGIN 77 | UPDATE u 78 | SET LastModifiedBy = @SuserSname 79 | FROM inserted i 80 | INNER JOIN [conf].[tUser] u ON i.UserId = u.UserId 81 | LEFT JOIN deleted d ON i.UserId = d.UserId 82 | WHERE i.LastModifiedBy <> @SuserSname 83 | 84 | UPDATE u 85 | SET LastModifiedOn = d.LastModifiedOn 86 | FROM inserted i 87 | INNER JOIN [conf].[tUser] u ON i.UserId = u.UserId 88 | LEFT JOIN deleted d ON i.UserId = d.UserId 89 | WHERE i.LastModifiedBy = @SuserSname 90 | AND i.LastModifiedOn <> @Datetime 91 | END 92 | 93 | IF EXISTS ( 94 | SELECT * FROM deleted 95 | EXCEPT 96 | SELECT * FROM inserted 97 | ) 98 | BEGIN 99 | --UpdateRecord 100 | UPDATE u 101 | SET LastModifiedBy = @SuserSname 102 | ,LastModifiedOn = @Datetime 103 | FROM inserted i 104 | INNER JOIN [conf].[tUser] u ON i.UserId = u.UserId 105 | LEFT JOIN deleted d ON i.UserId = d.UserId 106 | WHERE i.LastModifiedBy <> @SuserSname 107 | OR i.LastModifiedOn <> @Datetime 108 | -- OR i.[LoginId] <> d.[LoginId] 109 | -- OR i.[DefaultSchema] <> d.[DefaultSchema] 110 | -- OR i.[IsActive] <> d.[IsActive] 111 | 112 | END 113 | 114 | END -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | 2 | 3 | # dataGuard 4 | 5 | db permission management & audit system 6 | 7 | [![100 - commitow](https://img.shields.io/badge/100%20-commitow-lightgreen.svg)](https://100commitow.pl) 8 | 9 | > \[!NOTE] 10 | > 11 | > This project is part of the ["100 Commits"](https://100commitow.pl/) competition, which challenges participants to commit to their projects by making at least one commit every day for 100 consecutive days. 12 | > 13 | 14 | 15 | ## About DataGuard 16 | 17 |
18 | 19 | 20 | 21 | 22 | 23 |
24 | 25 | Do you know what permissions are currently set on your databases? 26 | Do you know when which permission was granted? 27 | Has someone accidentally granted too many permissions? 28 | 29 | 30 | ## Idea 31 | 32 | All authorization configuration should be saved in the authorization management system. 33 | Based on this configuration, the system automatically grants and revokes permissions. Even if the administrator grants permission directly in the database, the system will automatically receive it and send a notification about this fact. 34 | If the permission is added in the configuration, the system will automatically transfer it to the database. 35 | 36 | 37 | ## Benefits 38 | A full audit with real-time permissions, not a post-factum analysis 39 | Granting permissions faster than those broadcast by Active Directory groups 40 | 41 | The system is to be a central repository for various databases and will provide a unified system for granting permissions. 42 | Facilitates the transfer of permissions between different environments (DEV, TEST, PROD) 43 | 44 | 45 | ## Progress 46 | - This is PoC only for SQL Server 47 | - Project is written as DacPack project 48 | 49 | ## How to deploy/run 50 | ### Requirements 51 | - SQL Server 2022 ( https://www.microsoft.com/pl-pl/sql-server/sql-server-downloads https://info.microsoft.com/ww-landing-sql-server-2022.html?culture=en-us&country=us) 52 | - DataTools (https://learn.microsoft.com/en-us/sql/ssdt/download-sql-server-data-tools-ssdt?view=sql-server-ver16) 53 | - Visual Studion (unfortunately scripts for running without VS are not yet prepared) 54 | 55 | ### Deployment 56 | - Deploy Project DataGuard (local.publish.xml) 57 | - Deploy Project DataGuard.dbtest (local.publish.xml) 58 | 59 | ### Test 60 | Unit test are writtent in T-SQLt framework (https://tsqlt.org/) 61 | Quickest way to execute all test is 62 | > __EXEC [tSQLt].[RunAll]__ 63 | 64 | #### Example result 65 | 66 | ```` 67 | +----------------------+ 68 | |Test Execution Summary| 69 | +----------------------+ 70 | 71 | |No|Test Case Name |Dur(ms)|Result | 72 | +--+-------------------------------------------------------------------+-------+-------+ 73 | |1 |[test].[test conf.tDatabase if record change update LastModifiedOn]| 10|Success| 74 | |2 |[test].[test conf.tDatabase try change CreatedBy] | 8|Success| 75 | |3 |[test].[test conf.tDatabase try change CreatedOn] | 8|Success| 76 | |4 |[test].[test database DataGuard existing] | 8|Success| 77 | |5 |[test].[test database TestDataTest not existing] | 3|Success| 78 | ---------------------------------------------------------------------------------------- 79 | Test Case Summary: 5 test case(s) executed, 5 succeeded, 0 skipped, 0 failed, 0 errored. 80 | ---------------------------------------------------------------------------------------- 81 | ```` 82 | 83 | 84 | ### Execute 85 | On current state of project, you can get some middle information 86 | 87 | ````sql 88 | USE [DataGuard] 89 | GO 90 | 91 | EXEC [dbo].[pGetLoginDiff] 92 | EXEC [dbo].[pGetUserDiff] @DatabaseName = DataGuard 93 | 94 | 95 | ```` -------------------------------------------------------------------------------- /DataGuard/conf/Tables/conf.tLogin.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE [conf].[tLogin] 2 | ( 3 | [LoginId] INT IDENTITY (1, 1) NOT NULL, 4 | [LoginName] NVARCHAR(256) NOT NULL, 5 | [TypeLoginId] CHAR(1) DEFAULT('S') NOT NULL, 6 | [DefaultDatabaseName] NVARCHAR(128) NULL, 7 | [IsActive] BIT DEFAULT(1) NOT NULL, 8 | [CreatedBy] NVARCHAR (128) CONSTRAINT [conf_dfLogin_CreatedBy] DEFAULT (SUSER_SNAME()) NOT NULL, 9 | [CreatedOn] DATETIME2(3) CONSTRAINT [conf_dfLogin_CreatedOn] DEFAULT (SYSDATETIME()) NOT NULL, 10 | [LastModifiedBy] NVARCHAR (128) CONSTRAINT [conf_dfLogin_LastModifiedBy] DEFAULT (SUSER_SNAME()) NOT NULL, 11 | [LastModifiedOn] DATETIME2(3) CONSTRAINT [conf_dfLogin_LastModifiedOn] DEFAULT (SYSDATETIME()) NOT NULL, 12 | 13 | CONSTRAINT [conf_pkLogin] PRIMARY KEY CLUSTERED ([LoginId] ASC), 14 | CONSTRAINT [conf_fkLogin_ToTypeLogin] FOREIGN KEY ([TypeLoginId]) REFERENCES [def].[tTypeLogin] ([TypeLoginId]), 15 | ) 16 | 17 | GO 18 | 19 | 20 | 21 | CREATE UNIQUE NONCLUSTERED INDEX [uxLogin_LoginName] 22 | ON [conf].[tLogin]([LoginName] ASC); 23 | GO 24 | 25 | 26 | 27 | 28 | CREATE TRIGGER [conf].[trg_tLogin_ModyficationMeta] 29 | ON [conf].[tLogin] 30 | WITH EXECUTE AS OWNER 31 | AFTER INSERT, UPDATE 32 | AS 33 | BEGIN 34 | 35 | IF (ROWCOUNT_BIG() =0) 36 | RETURN; 37 | 38 | SET NOCOUNT ON; 39 | IF EXISTS ( 40 | SELECT CreatedBy, CreatedOn FROM deleted 41 | EXCEPT 42 | SELECT CreatedBy, CreatedOn FROM inserted 43 | ) 44 | BEGIN 45 | ;THROW 51000, N'Updating columns CreatedBy, CreatedOn is not allowed!', 1; 46 | END 47 | 48 | DECLARE @SuserSname nvarchar(128) 49 | ,@Datetime DATETIME2(3) = SYSDATETIME() 50 | 51 | EXECUTE AS CALLER 52 | SET @SuserSname = SUSER_SNAME() 53 | REVERT; 54 | 55 | --CreateRecord 56 | UPDATE u 57 | SET CreatedBy = @SuserSname 58 | ,CreatedOn = @Datetime 59 | ,LastModifiedBy = @SuserSname 60 | ,LastModifiedOn = @Datetime 61 | FROM inserted i 62 | INNER JOIN [conf].[tLogin] u ON i.LoginId = u.LoginId 63 | LEFT JOIN deleted d ON i.LoginId = d.LoginId 64 | WHERE d.LoginId IS NULL 65 | 66 | 67 | 68 | IF EXISTS ( 69 | SELECT LastModifiedBy, LastModifiedOn FROM deleted 70 | EXCEPT 71 | SELECT LastModifiedBy, LastModifiedOn FROM inserted 72 | ) 73 | AND NOT EXISTS ( 74 | SELECT LoginName, TypeLoginId, DefaultDatabaseName, IsActive FROM deleted 75 | EXCEPT 76 | SELECT LoginName, TypeLoginId, DefaultDatabaseName, IsActive FROM inserted 77 | ) 78 | BEGIN 79 | UPDATE u 80 | SET LastModifiedBy = @SuserSname 81 | FROM inserted i 82 | INNER JOIN [conf].[tLogin] u ON i.LoginId = u.LoginId 83 | LEFT JOIN deleted d ON i.LoginId = d.LoginId 84 | WHERE i.LastModifiedBy <> @SuserSname 85 | 86 | UPDATE u 87 | SET LastModifiedOn = d.LastModifiedOn 88 | FROM inserted i 89 | INNER JOIN [conf].[tLogin] u ON i.LoginId = u.LoginId 90 | LEFT JOIN deleted d ON i.LoginId = d.LoginId 91 | WHERE i.LastModifiedBy = @SuserSname 92 | AND i.LastModifiedOn <> @Datetime 93 | END 94 | 95 | IF EXISTS ( 96 | SELECT * FROM deleted 97 | EXCEPT 98 | SELECT * FROM inserted 99 | ) 100 | BEGIN 101 | --UpdateRecord 102 | UPDATE u 103 | SET LastModifiedBy = @SuserSname 104 | ,LastModifiedOn = @Datetime 105 | FROM inserted i 106 | INNER JOIN [conf].[tLogin] u ON i.LoginId = u.LoginId 107 | LEFT JOIN deleted d ON i.LoginId = d.LoginId 108 | WHERE i.LastModifiedBy <> @SuserSname 109 | OR i.LastModifiedOn <> @Datetime 110 | -- OR i.[TypeLoginId] <> d.[TypeLoginId] 111 | -- OR i.[DefaultDatabaseName] <> d.[DefaultDatabaseName] 112 | -- OR i.[IsActive] <> d.[IsActive] 113 | 114 | END 115 | 116 | END -------------------------------------------------------------------------------- /DataGuard/conf/Tables/conf.tDatabase.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE [conf].[tDatabase] 2 | ( 3 | [DatabaseId] INT IDENTITY (1, 1) NOT NULL, 4 | [DatabaseName] NVARCHAR(256) NOT NULL, 5 | [IsPermissionActive] BIT DEFAULT(1) NOT NULL, 6 | [CreatedBy] NVARCHAR (128) CONSTRAINT [conf_dfDatabase_CreatedBy] DEFAULT (SUSER_SNAME()) NOT NULL, 7 | [CreatedOn] DATETIME2(3) CONSTRAINT [conf_dfDatabase_CreatedOn] DEFAULT (SYSDATETIME()) NOT NULL, 8 | [LastModifiedBy] NVARCHAR (128) CONSTRAINT [conf_dfDatabase_LastModifiedBy] DEFAULT (SUSER_SNAME()) NOT NULL, 9 | [LastModifiedOn] DATETIME2(3) CONSTRAINT [conf_dfDatabase_LastModifiedOn] DEFAULT (SYSDATETIME()) NOT NULL, 10 | CONSTRAINT [conf_pkDatabase] PRIMARY KEY CLUSTERED ([DatabaseId] ASC) 11 | ); 12 | 13 | GO 14 | 15 | CREATE UNIQUE NONCLUSTERED INDEX [uxDatabase_DatabaseName] 16 | ON [conf].[tDatabase]([DatabaseName] ASC); 17 | GO 18 | 19 | 20 | 21 | CREATE TRIGGER [conf].[trg_Database_ModyficationMeta] 22 | ON [conf].[tDatabase] 23 | WITH EXECUTE AS OWNER 24 | AFTER INSERT, UPDATE 25 | AS 26 | BEGIN 27 | 28 | IF (ROWCOUNT_BIG() =0) 29 | RETURN; 30 | 31 | SET NOCOUNT ON; 32 | IF EXISTS ( 33 | SELECT CreatedBy, CreatedOn FROM deleted 34 | EXCEPT 35 | SELECT CreatedBy, CreatedOn FROM inserted 36 | ) 37 | BEGIN 38 | ;THROW 51000, N'Updating columns CreatedBy, CreatedOn is not allowed!', 1; 39 | END 40 | 41 | DECLARE @SuserSname nvarchar(128) 42 | ,@Datetime DATETIME2(3) = SYSDATETIME() 43 | 44 | EXECUTE AS CALLER 45 | SET @SuserSname = SUSER_SNAME() 46 | REVERT; 47 | 48 | --CreateRecord 49 | UPDATE u 50 | SET CreatedBy = @SuserSname 51 | ,CreatedOn = @Datetime 52 | ,LastModifiedBy = @SuserSname 53 | ,LastModifiedOn = @Datetime 54 | FROM inserted i 55 | INNER JOIN [conf].[tDatabase] u ON i.DatabaseId = u.DatabaseId 56 | LEFT JOIN deleted d ON i.DatabaseId = d.DatabaseId 57 | WHERE d.DatabaseId IS NULL 58 | /* 59 | ( u.CreatedBy <> IIF(d.DatabaseId IS NULL, @SuserSname, u.CreatedBy) 60 | OR u.CreatedOn <> IIF(d.DatabaseId IS NULL, @Datetime, u.CreatedOn) 61 | OR u.LastModifiedBy <> IIF( i.[DatabaseName] <> d.[DatabaseName] 62 | OR i.[IsPermissionActive] <> d.[IsPermissionActive] 63 | OR i.[LastModifiedOn] <> d.[LastModifiedOn] 64 | OR i.[LastModifiedBy] <> d.[LastModifiedBy] , @SuserSname, u.LastModifiedBy) 65 | OR u.LastModifiedOn <> IIF( i.[DatabaseName] <> d.[DatabaseName] 66 | OR i.[IsPermissionActive] <> d.[IsPermissionActive] 67 | OR i.[LastModifiedOn] <> d.[LastModifiedOn] 68 | OR i.[LastModifiedBy] <> d.[LastModifiedBy] , @Datetime, u.LastModifiedOn) 69 | ) 70 | */ 71 | 72 | IF EXISTS ( 73 | SELECT LastModifiedBy, LastModifiedOn FROM deleted 74 | EXCEPT 75 | SELECT LastModifiedBy, LastModifiedOn FROM inserted 76 | ) 77 | AND NOT EXISTS ( 78 | SELECT DatabaseName, IsPermissionActive FROM deleted 79 | EXCEPT 80 | SELECT DatabaseName, IsPermissionActive FROM inserted 81 | ) 82 | BEGIN 83 | UPDATE u 84 | SET LastModifiedBy = @SuserSname 85 | FROM inserted i 86 | INNER JOIN [conf].[tDatabase] u ON i.DatabaseId = u.DatabaseId 87 | LEFT JOIN deleted d ON i.DatabaseId = d.DatabaseId 88 | WHERE i.LastModifiedBy <> @SuserSname 89 | 90 | UPDATE u 91 | SET LastModifiedOn = d.LastModifiedOn 92 | FROM inserted i 93 | INNER JOIN [conf].[tDatabase] u ON i.DatabaseId = u.DatabaseId 94 | LEFT JOIN deleted d ON i.DatabaseId = d.DatabaseId 95 | WHERE i.LastModifiedBy = @SuserSname 96 | AND i.LastModifiedOn <> @Datetime 97 | END 98 | 99 | IF EXISTS ( 100 | SELECT * FROM deleted 101 | EXCEPT 102 | SELECT * FROM inserted 103 | ) 104 | BEGIN 105 | --UpdateRecord 106 | UPDATE u 107 | SET LastModifiedBy = @SuserSname 108 | ,LastModifiedOn = @Datetime 109 | FROM inserted i 110 | INNER JOIN [conf].[tDatabase] u ON i.DatabaseId = u.DatabaseId 111 | LEFT JOIN deleted d ON i.DatabaseId = d.DatabaseId 112 | WHERE i.LastModifiedBy <> @SuserSname 113 | OR i.LastModifiedOn <> @Datetime 114 | -- OR i.[DatabaseName] <> d.[DatabaseName] 115 | -- OR i.[IsPermissionActive] <> d.[IsPermissionActive] 116 | END 117 | 118 | END -------------------------------------------------------------------------------- /DataGuard/conf/Tables/conf.tPermission.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE [conf].[tPermission] 2 | ( 3 | [PermissionId] INT IDENTITY (1, 1) NOT NULL, 4 | [EnvironmentId] TINYINT NOT NULL, --TODO 5 | -- [DatabaseId] INT NOT NULL, 6 | [UserId] INT NOT NULL, 7 | [ObjectType] VARCHAR(128) DEFAULT ('%') NOT NULL, 8 | [SchemaName] SYSNAME DEFAULT ('%') NOT NULL, 9 | [ObjectName] SYSNAME DEFAULT ('%') NOT NULL, 10 | [CreatedBy] NVARCHAR (128) CONSTRAINT [conf_dfPermission_CreatedBy] DEFAULT (SYSTEM_USER) NOT NULL, 11 | [CreatedOn] DATETIME2(3) CONSTRAINT [conf_dfPermission_CreatedOn] DEFAULT (GETDATE()) NOT NULL, 12 | [LastModifiedBy] NVARCHAR (128) CONSTRAINT [conf_dfPermission_LastModifiedBy] DEFAULT (SYSTEM_USER) NOT NULL, 13 | [LastModifiedOn] DATETIME2(3) CONSTRAINT [conf_dfPermission_LastModifiedOn] DEFAULT (GETDATE()) NOT NULL, 14 | CONSTRAINT [conf_pkPermission] PRIMARY KEY CLUSTERED ([PermissionId] ASC), 15 | --CONSTRAINT [conf_fkPermission_ToDatabase] FOREIGN KEY ([DatabaseId]) REFERENCES [conf].[tDatabase] ([DatabaseId]), 16 | CONSTRAINT [conf_fkPermission_ToUser] FOREIGN KEY ([UserId]) REFERENCES [conf].[tUser] ([UserId]), 17 | ) 18 | 19 | GO 20 | 21 | ALTER TABLE [conf].[tPermission] ADD CONSTRAINT conf_chkPermission_ObjectType CHECK ( [ObjectType] IN ('%', 22 | 'Inlinefunction', 23 | 'ScalarFunction', 24 | 'Procedure', 25 | 'Role', 26 | 'Schema', 27 | 'Table', 28 | 'View') 29 | ) 30 | --'User', 31 | --'Login', 32 | --'Securable', 33 | GO 34 | 35 | 36 | 37 | CREATE TRIGGER [conf].[trg_tPermission_ModyficationMeta] 38 | ON [conf].[tPermission] 39 | WITH EXECUTE AS OWNER 40 | AFTER INSERT, UPDATE 41 | AS 42 | BEGIN 43 | 44 | IF (ROWCOUNT_BIG() =0) 45 | RETURN; 46 | 47 | SET NOCOUNT ON; 48 | IF EXISTS ( 49 | SELECT CreatedBy, CreatedOn FROM deleted 50 | EXCEPT 51 | SELECT CreatedBy, CreatedOn FROM inserted 52 | ) 53 | BEGIN 54 | ;THROW 51000, N'Updating columns CreatedBy, CreatedOn is not allowed!', 1; 55 | END 56 | 57 | DECLARE @SuserSname nvarchar(128) 58 | ,@Datetime DATETIME2(3) = SYSDATETIME() 59 | 60 | EXECUTE AS CALLER 61 | SET @SuserSname = SUSER_SNAME() 62 | REVERT; 63 | 64 | --CreateRecord 65 | UPDATE u 66 | SET CreatedBy = @SuserSname 67 | ,CreatedOn = @Datetime 68 | ,LastModifiedBy = @SuserSname 69 | ,LastModifiedOn = @Datetime 70 | FROM inserted i 71 | INNER JOIN [conf].[tPermission] u ON i.PermissionId = u.PermissionId 72 | LEFT JOIN deleted d ON i.PermissionId = d.PermissionId 73 | WHERE d.PermissionId IS NULL 74 | 75 | 76 | 77 | IF EXISTS ( 78 | SELECT LastModifiedBy, LastModifiedOn FROM deleted 79 | EXCEPT 80 | SELECT LastModifiedBy, LastModifiedOn FROM inserted 81 | ) 82 | AND NOT EXISTS ( 83 | SELECT EnvironmentId, --DatabaseId, 84 | UserId, ObjectType, SchemaName, ObjectName FROM deleted 85 | EXCEPT 86 | SELECT EnvironmentId, --DatabaseId, 87 | UserId, ObjectType, SchemaName, ObjectName FROM inserted 88 | ) 89 | BEGIN 90 | UPDATE u 91 | SET LastModifiedBy = @SuserSname 92 | FROM inserted i 93 | INNER JOIN [conf].[tPermission] u ON i.PermissionId = u.PermissionId 94 | LEFT JOIN deleted d ON i.PermissionId = d.PermissionId 95 | WHERE i.LastModifiedBy <> @SuserSname 96 | 97 | UPDATE u 98 | SET LastModifiedOn = d.LastModifiedOn 99 | FROM inserted i 100 | INNER JOIN [conf].[tPermission] u ON i.PermissionId = u.PermissionId 101 | LEFT JOIN deleted d ON i.PermissionId = d.PermissionId 102 | WHERE i.LastModifiedBy = @SuserSname 103 | AND i.LastModifiedOn <> @Datetime 104 | END 105 | 106 | IF EXISTS ( 107 | SELECT * FROM deleted 108 | EXCEPT 109 | SELECT * FROM inserted 110 | ) 111 | BEGIN 112 | --UpdateRecord 113 | UPDATE u 114 | SET LastModifiedBy = @SuserSname 115 | ,LastModifiedOn = @Datetime 116 | FROM inserted i 117 | INNER JOIN [conf].[tPermission] u ON i.PermissionId = u.PermissionId 118 | LEFT JOIN deleted d ON i.PermissionId = d.PermissionId 119 | WHERE i.LastModifiedBy <> @SuserSname 120 | OR i.LastModifiedOn <> @Datetime 121 | -- OR i.[LoginId] <> d.[LoginId] 122 | -- OR i.[DefaultSchema] <> d.[DefaultSchema] 123 | -- OR i.[IsActive] <> d.[IsActive] 124 | 125 | END 126 | 127 | END -------------------------------------------------------------------------------- /DataGuard/dbo/Procedures/dbo.pPermissionInSystemAsXml.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [dbo].[pPermissionInSystemAsXml] 2 | @DatabaseName sysname, 3 | @UserName sysname, 4 | @IsDebug BIT = 0 5 | AS 6 | 7 | DECLARE @Sql nvarchar(3000) 8 | ,@ErrorMessage nvarchar(2000) 9 | ,@ExecQuery nvarchar(4000) 10 | ,@CRLF CHAR(2) = CHAR(13)+CHAR(10) 11 | ,@Tab nvarchar(10) = CHAR(9) 12 | 13 | ,@XmlResult XML 14 | 15 | IF @IsDebug = 1 16 | BEGIN 17 | SET @ExecQuery = CONCAT( 'EXEC ', QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)), '.', QUOTENAME(OBJECT_NAME(@@PROCID)), @CRLF, 18 | @Tab, ' @DatabaseName = ', IIF(@DatabaseName LIKE '%', QUOTENAME(@DatabaseName,''''), @DatabaseName ) , @CRLF, 19 | @Tab, ' @UserName = ', IIF(@UserName LIKE '%', QUOTENAME(@UserName,''''), @UserName ) , @CRLF, 20 | @Tab, ',@IsDebug = ', @IsDebug ) 21 | 22 | PRINT @ExecQuery 23 | 24 | END 25 | 26 | 27 | IF OBJECT_ID('tempdb..#PermissionInSystem') IS NOT NULL DROP TABLE #PermissionInSystem 28 | 29 | 30 | CREATE TABLE #PermissionInSystem 31 | ( 32 | [DatabaseName] sysname NULL 33 | ,[Type] varchar(100) 34 | ,[UserName] sysname NULL 35 | ,[RoleName] sysname NULL 36 | ,[ClassDesc] varchar(100) 37 | ,[PermissionType] varchar(100) 38 | ,[PermissionState] varchar(100) 39 | ,[SchemaName] sysname NULL 40 | ,[SqlObjectType] varchar(100) 41 | ,[ObjectName] varchar(100) 42 | ,[ObjectType] varchar(100) 43 | 44 | 45 | ) 46 | 47 | 48 | -- INSERT INTO @PermissionInSystem ([DatabaseName], [Type], [UserName], [RoleName], [ClassDesc], [PermissionType], [PermissionState], [SchemaName], [SqlObjectType], [ObjectName], [ObjectType]) 49 | EXEC [dbo].[pPermissionInInstance] @DatabaseName=@DatabaseName, @IsDebug= @IsDebug 50 | 51 | -- SELECT * FROM #PermissionInSystem 52 | 53 | 54 | SET @XmlResult = ( 55 | SELECT un.[UserName] as [@UserName], 56 | un.[LoginName] as [@LoginName], 57 | un.[State] as [@State] 58 | ,( 59 | SELECT db.[DatabaseName] AS [Database/@Name], 60 | ( 61 | SELECT rn.[RoleName] as [Role] 62 | FROM ( SELECT DISTINCT r.[RoleName] 63 | FROM #PermissionInSystem r 64 | WHERE db.[UserName] = r.[UserName] 65 | AND (db.[DatabaseName] = r.[DatabaseName] OR (db.[DatabaseName] IS NULL AND r.[DatabaseName] IS NULL)) 66 | AND r.RoleName IS NOT NULL 67 | ) rn 68 | FOR XML PATH(''), TYPE 69 | ) AS [Database], 70 | ( 71 | SELECT ps.ObjectType AS [Object/@ObjectType], 72 | ps.SchemaName AS [Object/@SchemaName], 73 | ps.ObjectName AS [Object/@ObjectName], 74 | ps.PermissionType AS [Object/@PermissionType], 75 | ps.PermissionState AS [Object/@PermissionState] 76 | FROM ( SELECT DISTINCT p.[PermissionState], p.[ObjectType], p.[PermissionType], p.[SchemaName], p.[ObjectName] 77 | FROM #PermissionInSystem p 78 | WHERE p.PermissionState IS NULL 79 | AND db.[UserName] = p.[UserName] 80 | AND (db.[DatabaseName] = p.[DatabaseName] OR (db.[DatabaseName] IS NULL AND p.[DatabaseName] IS NULL)) 81 | AND p.RoleName IS NOT NULL 82 | ) ps 83 | ORDER BY ps.ObjectType, ps.SchemaName, ps.ObjectName 84 | FOR XML PATH(''), TYPE 85 | 86 | ) as [Database] 87 | FROM ( 88 | SELECT DISTINCT d.[DatabaseName], d.[UserName] 89 | FROM #PermissionInSystem d 90 | WHERE COALESCE(un.[UserName], un.[LoginName]) = d.[UserName] 91 | ) db 92 | FOR XML PATH(''), TYPE 93 | ) 94 | FROM ( 95 | SELECT u2.[UserName] 96 | ,u2.[LoginName] 97 | ,CASE 98 | WHEN su.[UserName] IS NOT NULL THEN 'Enabled' 99 | WHEN sl.[UserName] IS NOT NULL THEN 'Enabled' 100 | ELSE 'Disbled' 101 | END AS [State] 102 | FROM ( 103 | SELECT DISTINCT IIF(u.[DatabaseName] IS NOT NULL, u.[UserName], NULL) AS [UserName], 104 | IIF(u.[DatabaseName] IS NULL, u.[UserName], NULL) AS [LoginName] 105 | FROM #PermissionInSystem u 106 | WHERE u.[UserName] = @UserName OR @UserName = '%' 107 | ) u2 108 | LEFT JOIN #PermissionInSystem su ON u2.[UserName] = su.[UserName] 109 | AND su.PermissionType = 'CONNECT' 110 | AND su.PermissionState = 'GRANT' 111 | LEFT JOIN #PermissionInSystem sl ON u2.[LoginName] = sl.[UserName] 112 | AND sl.PermissionType = 'CONNECT SQL' 113 | AND sl.PermissionState = 'GRANT' 114 | ) un 115 | FOR XML PATH('Permission'), ROOT('Permissions') 116 | 117 | ) 118 | 119 | SELECT @XmlResult 120 | -------------------------------------------------------------------------------- /DataGuard/dbo/Procedures/dbo.pGetListOfDatabaseObject.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [dbo].[pGetListOfDatabaseObject] 2 | 3 | @DatabaseName sysname, 4 | @Type varchar(30) ='%', 5 | @Schema sysname = '%', 6 | @IsDebug BIT = 0 7 | AS 8 | DECLARE @Sql nvarchar(3000) 9 | ,@ErrorMessage nvarchar(2000) 10 | ,@ExecQuery nvarchar(max) 11 | ,@CRLF CHAR(2) = CHAR(13)+CHAR(10) 12 | ,@Tab nvarchar(10) = CHAR(9) 13 | 14 | IF @IsDebug = 1 15 | BEGIN 16 | SET @ExecQuery = CONCAT( 'EXEC ', QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)), '.', QUOTENAME(OBJECT_NAME(@@PROCID)), @CRLF, 17 | @Tab, ' @DatabaseName = ', IIF(@DatabaseName LIKE '%', QUOTENAME(@DatabaseName,''''), @DatabaseName ), @CRLF, 18 | @Tab, ',@Type = ', @Type, @CRLF, 19 | @Tab, ',@Schema = ', @Schema, @CRLF, 20 | @Tab, ',@IsDebug = ', @IsDebug ) 21 | 22 | PRINT @ExecQuery 23 | END 24 | 25 | EXEC [dbo].[pThrowErrorIfDatabaseNotExists] @DatabaseName = @DatabaseName , @IsDebug = @IsDebug 26 | 27 | 28 | /* DECLARE @ObjectTable TABLE 29 | ( 30 | [DatabaseName] sysname 31 | [Type] varchar(20) 32 | ,[Schema] sysname 33 | ,[ObjectName] sysname 34 | ) 35 | */ 36 | 37 | 38 | IF @Type = 'Table' 39 | BEGIN 40 | SET @Sql = CONCAT(' 41 | SELECT @DatabaseName AS [DatabaseName] 42 | ,''Table'' AS [Type] 43 | ,[Table_SCHEMA] AS [Schema] 44 | ,[TABLE_NAME] AS [TableName] 45 | FROM ', QUOTENAME(@DatabaseName),'.[INFORMATION_SCHEMA].[TABLES] (nolock) 46 | WHERE [TABLE_TYPE] = ''BASE TABLE'' 47 | ', 48 | IIF(@Schema = '%', NULL, ' AND [TABLE_SCHEMA] = @Schema ') 49 | ) 50 | END 51 | 52 | 53 | 54 | IF @Type = 'View' 55 | BEGIN 56 | SET @Sql = CONCAT(' 57 | SELECT @DatabaseName AS [DatabaseName] 58 | ,''View'' AS [Type] 59 | ,[Table_SCHEMA] AS [Schema] 60 | ,[TABLE_NAME] AS [TableName] 61 | FROM ', QUOTENAME(@DatabaseName),'.[INFORMATION_SCHEMA].[TABLES] (nolock) 62 | WHERE [TABLE_TYPE] = ''View'' 63 | ', 64 | IIF(@Schema = '%', NULL, ' AND [TABLE_SCHEMA] = @Schema ') 65 | ) 66 | END 67 | 68 | 69 | IF @Type = 'Procedure' 70 | BEGIN 71 | SET @Sql = CONCAT(' 72 | SELECT @DatabaseName AS [DatabaseName] 73 | ,''Procedure'' AS [Type] 74 | ,[SPECIFIC_SCHEMA] AS [Schema] 75 | ,[SPECIFIC_NAME] AS [TableName] 76 | FROM ', QUOTENAME(@DatabaseName),'.[INFORMATION_SCHEMA].[ROUTINES] (nolock) 77 | WHERE [ROUTINE_TYPE] = ''PROCEDURE'' 78 | ', 79 | IIF(@Schema = '%', NULL, ' AND [SPECIFIC_SCHEMA] = @Schema ') 80 | ) 81 | END 82 | 83 | 84 | IF @Type = 'InlineFunction' 85 | BEGIN 86 | SET @Sql = CONCAT(' 87 | SELECT @DatabaseName AS [DatabaseName] 88 | ,''InlineFunction'' AS [Type] 89 | ,[SPECIFIC_SCHEMA] AS [Schema] 90 | ,[SPECIFIC_NAME] AS [TableName] 91 | FROM ', QUOTENAME(@DatabaseName),'.[INFORMATION_SCHEMA].[ROUTINES] (nolock) 92 | WHERE [ROUTINE_TYPE] = ''FUNCTION'' 93 | AND DATA_TYPE = ''TABLE'' 94 | ', 95 | IIF(@Schema = '%', NULL, ' AND [SPECIFIC_SCHEMA] = @Schema ') 96 | ) 97 | END 98 | 99 | 100 | IF @Type = 'ScalarFunction' 101 | BEGIN 102 | 103 | SET @Sql = CONCAT(' 104 | SELECT @DatabaseName AS [DatabaseName] 105 | ,''ScalarFunction'' AS [Type] 106 | ,[SPECIFIC_SCHEMA] AS [Schema] 107 | ,[SPECIFIC_NAME] AS [TableName] 108 | FROM ', QUOTENAME(@DatabaseName),'.[INFORMATION_SCHEMA].[ROUTINES] (nolock) 109 | WHERE [ROUTINE_TYPE] = ''FUNCTION'' 110 | AND DATA_TYPE != ''TABLE'' 111 | ', 112 | IIF(@Schema = '%', NULL, ' AND [SPECIFIC_SCHEMA] = @Schema ') 113 | ) 114 | END 115 | 116 | 117 | IF @Type = '%' 118 | BEGIN 119 | 120 | SET @Sql = CONCAT(' 121 | SELECT @DatabaseName AS [DatabaseName] 122 | ,CASE 123 | WHEN [TABLE_TYPE] = ''View'' THEN ''View'' 124 | WHEN [TABLE_TYPE] = ''BASE TABLE'' THEN ''Table'' 125 | ELSE [TABLE_TYPE] 126 | END AS [Type] 127 | ,[Table_SCHEMA] AS [Schema] 128 | ,[TABLE_NAME] AS [TableName] 129 | FROM ', QUOTENAME(@DatabaseName),'.[INFORMATION_SCHEMA].[TABLES] (nolock) 130 | ', 131 | IIF(@Schema = '%', NULL, ' WHERE [TABLE_SCHEMA] = @Schema ') 132 | ,' 133 | UNION ALL 134 | SELECT @DatabaseName AS [DatabaseName] 135 | ,CASE 136 | WHEN [ROUTINE_TYPE] = ''PROCEDURE'' THEN ''Procedure'' 137 | WHEN [ROUTINE_TYPE] = ''FUNCTION'' AND DATA_TYPE != ''TABLE'' THEN ''ScalarFunction'' 138 | WHEN [ROUTINE_TYPE] = ''FUNCTION'' AND DATA_TYPE = ''TABLE'' THEN ''InlineFunction'' 139 | ELSE [ROUTINE_TYPE] 140 | END AS [Type] 141 | ,[SPECIFIC_SCHEMA] AS [Schema] 142 | ,[SPECIFIC_NAME] AS [TableName] 143 | FROM ', QUOTENAME(@DatabaseName),'.[INFORMATION_SCHEMA].[ROUTINES] (nolock) 144 | ', 145 | IIF(@Schema = '%', NULL, ' WHERE [SPECIFIC_SCHEMA] = @Schema ') 146 | ) 147 | END 148 | 149 | 150 | IF @IsDebug =1 PRINT @sql 151 | 152 | 153 | EXEC sp_executesql @sql , N'@DatabaseName nvarchar(255) ,@Schema SYSNAME' , @DatabaseName = @DatabaseName, @Schema = @Schema 154 | -------------------------------------------------------------------------------- /DataGuard.dbtests/DataGuard.dbtests.sqlproj: -------------------------------------------------------------------------------- 1 | 2 | 3 | 4 | Debug 5 | AnyCPU 6 | DataGuard.dbtests 7 | 2.0 8 | 4.1 9 | {a5298359-a4b2-47b0-9d0b-7200b32d0b7d} 10 | Microsoft.Data.Tools.Schema.Sql.Sql160DatabaseSchemaProvider 11 | Database 12 | 13 | 14 | DataGuard.dbtests 15 | DataGuard.dbtests 16 | 1033, CI 17 | BySchemaAndSchemaType 18 | True 19 | v4.7.2 20 | CS 21 | Properties 22 | False 23 | True 24 | True 25 | True 26 | 27 | 28 | bin\Release\ 29 | $(MSBuildProjectName).sql 30 | False 31 | pdbonly 32 | true 33 | false 34 | true 35 | prompt 36 | 4 37 | 38 | 39 | bin\Debug\ 40 | $(MSBuildProjectName).sql 41 | false 42 | true 43 | full 44 | false 45 | true 46 | true 47 | prompt 48 | 4 49 | 50 | 51 | 11.0 52 | 53 | True 54 | 11.0 55 | 56 | 57 | 58 | 59 | 60 | 61 | 62 | 63 | 64 | 65 | 66 | 67 | 68 | 69 | 70 | 71 | 72 | 73 | DataGuard 74 | $(SqlCmdVar__4) 75 | 76 | 77 | 78 | 79 | DataGuard 80 | {03ba78eb-ee24-45a2-86f8-35bfef5be1a6} 81 | True 82 | False 83 | DataGuard_db 84 | 85 | 86 | 87 | 88 | ..\External\tSQLt.2019.dacpac 89 | False 90 | 91 | 92 | $(DacPacRootPath)\Extensions\Microsoft\SQLDB\Extensions\SqlServer\160\SqlSchemas\master.dacpac 93 | False 94 | master 95 | 96 | 97 | 98 | 99 | 100 | 101 | 102 | 103 | 104 | 105 | 106 | 107 | 108 | 109 | 110 | 111 | 112 | 113 | 114 | 115 | 116 | 117 | 118 | 119 | -------------------------------------------------------------------------------- /DataGuard/dbo/Procedures/dbo.pPermissionInInstance.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE [dbo].[pPermissionInInstance] 2 | @DatabaseName sysname, 3 | @IsDebug BIT = 0 4 | AS 5 | 6 | DECLARE @Sql nvarchar(3000) 7 | ,@ErrorMessage nvarchar(2000) 8 | ,@ExecQuery nvarchar(4000) 9 | ,@CRLF CHAR(2) = CHAR(13)+CHAR(10) 10 | ,@Tab nvarchar(10) = CHAR(9) 11 | 12 | IF @IsDebug = 1 13 | BEGIN 14 | SET @ExecQuery = CONCAT( 'EXEC ', QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)), '.', QUOTENAME(OBJECT_NAME(@@PROCID)), @CRLF, 15 | @Tab, ' @DatabaseName = ', IIF(@DatabaseName LIKE '%', QUOTENAME(@DatabaseName,''''), @DatabaseName ) , @CRLF, 16 | @Tab, ',@IsDebug = ', @IsDebug ) 17 | 18 | PRINT @ExecQuery 19 | 20 | END 21 | 22 | 23 | IF OBJECT_ID('tempdb..#PermissionInSystemInternal') IS NOT NULL DROP TABLE #PermissionInSystemInternal 24 | 25 | 26 | CREATE TABLE #PermissionInSystemInternal 27 | ( 28 | [DatabaseName] sysname NULL 29 | ,[Type] varchar(100) 30 | ,[UserName] sysname NULL 31 | ,[RoleName] sysname NULL 32 | ,[ClassDesc] varchar(100) 33 | ,[PermissionType] varchar(100) 34 | ,[PermissionState] varchar(100) 35 | ,[SchemaName] sysname NULL 36 | ,[ObjectType] varchar(100) 37 | ,[ObjectName] varchar(100) 38 | ) 39 | 40 | 41 | 42 | IF @DatabaseName <> '%' 43 | BEGIN 44 | INSERT INTO #PermissionInSystemInternal ([DatabaseName], [Type], [UserName], [ClassDesc], [PermissionType], [PermissionState], [SchemaName], [ObjectType], [ObjectName]) 45 | EXEC [dbo].[pGetListOfDatabasePermissions] @DatabaseName=@DatabaseName, @IsDebug= @IsDebug 46 | 47 | INSERT INTO #PermissionInSystemInternal ([DatabaseName], [Type], [UserName], [RoleName]) 48 | EXEC [dbo].[pGetListOfDatabaseRoles] @DatabaseName=@DatabaseName, @IsDebug= @IsDebug 49 | END 50 | 51 | 52 | IF @DatabaseName IS NULL 53 | BEGIN 54 | INSERT INTO #PermissionInSystemInternal ([Type], [UserName], [ClassDesc], [PermissionType], [PermissionState]) 55 | EXEC [dbo].[pGetListOfInstancePermissions] @IsDebug= @IsDebug 56 | 57 | INSERT INTO #PermissionInSystemInternal ( [ClassDesc], [Type], [UserName], [RoleName]) 58 | EXEC [dbo].[pGetListOfInstanceRoles] @IsDebug= @IsDebug 59 | END 60 | 61 | IF @DatabaseName = '%' 62 | BEGIN 63 | 64 | DECLARE @DatabaseNameLoop sysname 65 | 66 | DECLARE databaseNameCursor CURSOR READ_ONLY FOR 67 | SELECT DatabaseName 68 | FROM [conf].[tDatabase] (nolock) 69 | WHERE IsPermissionActive = 1 70 | AND DatabaseName IS NOT NULL 71 | 72 | OPEN databaseNameCursor 73 | FETCH NEXT FROM databaseNameCursor INTO @DatabaseNameLoop 74 | 75 | WHILE @@FETCH_STATUS =0 76 | BEGIN 77 | 78 | BEGIN TRY 79 | INSERT INTO #PermissionInSystemInternal ([DatabaseName], [Type], [UserName], [ClassDesc], [PermissionType], [PermissionState], [SchemaName], [ObjectType], [ObjectName]) 80 | EXEC [dbo].[pGetListOfDatabasePermissions] @DatabaseName=@DatabaseNameLoop, @IsDebug= @IsDebug 81 | END TRY 82 | BEGIN CATCH 83 | SET @ErrorMessage = CONCAT('Error when get data from dbo.pGetListOfDatabasePermissions on DatabaseName ', @DatabaseNameLoop) 84 | PRINT @ErrorMessage 85 | END CATCH 86 | 87 | 88 | BEGIN TRY 89 | INSERT INTO #PermissionInSystemInternal ([DatabaseName], [Type], [UserName], [RoleName]) 90 | EXEC [dbo].[pGetListOfDatabaseRoles] @DatabaseName=@DatabaseNameLoop, @IsDebug= @IsDebug 91 | END TRY 92 | BEGIN CATCH 93 | SET @ErrorMessage = CONCAT('Error when get data from dbo.pGetListOfDatabaseRoles on DatabaseName ', @DatabaseNameLoop) 94 | PRINT @ErrorMessage 95 | END CATCH 96 | 97 | 98 | 99 | FETCH NEXT FROM databaseNameCursor INTO @DatabaseNameLoop 100 | END 101 | 102 | CLOSE databaseNameCursor 103 | DEALLOCATE databaseNameCursor 104 | 105 | 106 | 107 | INSERT INTO #PermissionInSystemInternal ([Type], [UserName], [ClassDesc], [PermissionType], [PermissionState]) 108 | EXEC [dbo].[pGetListOfInstancePermissions] @IsDebug= @IsDebug 109 | 110 | INSERT INTO #PermissionInSystemInternal ( [ClassDesc], [Type], [UserName], [RoleName]) 111 | EXEC [dbo].[pGetListOfInstanceRoles] @IsDebug= @IsDebug 112 | 113 | 114 | END 115 | 116 | 117 | IF OBJECT_ID('tempdb..#PermissionInSystem') IS NOT NULL 118 | BEGIN 119 | INSERT INTO #PermissionInSystem 120 | SELECT 121 | [DatabaseName] 122 | ,[Type] 123 | ,[UserName] 124 | ,[RoleName] 125 | ,[ClassDesc] 126 | ,[PermissionType] 127 | ,[PermissionState] 128 | ,[SchemaName] 129 | ,[ObjectType] AS [SqlObjectType] 130 | ,IIF([RoleName] IS NOT NULL, [RoleName], [ObjectName]) AS [ObjectName] 131 | ,CASE 132 | WHEN [RoleName] IS NOT NULL THEN 'Role' 133 | WHEN [ClassDesc] = 'SERVER' THEN 'Instance' 134 | WHEN [ClassDesc] = 'DATABASE_PRINCIPAL' THEN 'Database' 135 | WHEN [ClassDesc] = 'OBJECT_OR_COLUMN' AND [ObjectType] = 'USER_TABLE' THEN 'Table' 136 | WHEN [ClassDesc] = 'OBJECT_OR_COLUMN' AND [ObjectType] = 'VIEW' THEN 'View' 137 | WHEN [ClassDesc] = 'OBJECT_OR_COLUMN' AND [ObjectType] = 'SQL_STORED_PROCEDURE' THEN 'SqlProcedure' 138 | WHEN [ClassDesc] = 'OBJECT_OR_COLUMN' AND [ObjectType] = 'EXTENDED_STORED_PROCEDURE' THEN 'ExtendedProcedure' 139 | WHEN [ClassDesc] = 'OBJECT_OR_COLUMN' AND [ObjectType] = 'CLR_STORED_PROCEDURE' THEN 'ClrProcedure' 140 | WHEN [ClassDesc] = 'OBJECT_OR_COLUMN' AND [ObjectType] = 'SQL_SCALAR_FUNCTION' THEN 'ScalarFunction' 141 | WHEN [ClassDesc] = 'OBJECT_OR_COLUMN' AND [ObjectType] = 'SQL_INLINE_TABLE_VALUED_FUNCTION' THEN 'InlineFunction' 142 | WHEN [ClassDesc] = 'OBJECT_OR_COLUMN' AND [ObjectType] = 'SQL_TABLE_VALUED_FUNCTION' THEN 'InlineFunction' 143 | WHEN [ClassDesc] = 'OBJECT_OR_COLUMN' THEN [ClassDesc] 144 | END AS [ObjectType] 145 | FROM #PermissionInSystemInternal 146 | 147 | END 148 | ELSE 149 | BEGIN 150 | SELECT 151 | [DatabaseName] 152 | ,[Type] 153 | ,[UserName] 154 | ,[RoleName] 155 | ,[ClassDesc] 156 | ,[PermissionType] 157 | ,[PermissionState] 158 | ,[SchemaName] 159 | ,[ObjectType] AS [SqlObjectType] 160 | ,IIF([RoleName] IS NOT NULL, [RoleName], [ObjectName]) AS [ObjectName] 161 | ,CASE 162 | WHEN [RoleName] IS NOT NULL THEN 'Role' 163 | WHEN [ClassDesc] = 'SERVER' THEN 'Instance' 164 | WHEN [ClassDesc] = 'DATABASE_PRINCIPAL' THEN 'Database' 165 | WHEN [ClassDesc] = 'OBJECT_OR_COLUMN' AND [ObjectType] = 'USER_TABLE' THEN 'Table' 166 | WHEN [ClassDesc] = 'OBJECT_OR_COLUMN' AND [ObjectType] = 'VIEW' THEN 'View' 167 | WHEN [ClassDesc] = 'OBJECT_OR_COLUMN' AND [ObjectType] = 'SQL_STORED_PROCEDURE' THEN 'SqlProcedure' 168 | WHEN [ClassDesc] = 'OBJECT_OR_COLUMN' AND [ObjectType] = 'EXTENDED_STORED_PROCEDURE' THEN 'ExtendedProcedure' 169 | WHEN [ClassDesc] = 'OBJECT_OR_COLUMN' AND [ObjectType] = 'CLR_STORED_PROCEDURE' THEN 'ClrProcedure' 170 | WHEN [ClassDesc] = 'OBJECT_OR_COLUMN' AND [ObjectType] = 'SQL_SCALAR_FUNCTION' THEN 'ScalarFunction' 171 | WHEN [ClassDesc] = 'OBJECT_OR_COLUMN' AND [ObjectType] = 'SQL_INLINE_TABLE_VALUED_FUNCTION' THEN 'InlineFunction' 172 | WHEN [ClassDesc] = 'OBJECT_OR_COLUMN' AND [ObjectType] = 'SQL_TABLE_VALUED_FUNCTION' THEN 'InlineFunction' 173 | WHEN [ClassDesc] = 'OBJECT_OR_COLUMN' THEN [ClassDesc] 174 | END AS [ObjectType] 175 | FROM #PermissionInSystemInternal 176 | END 177 | -------------------------------------------------------------------------------- /DataGuard/DataGuard.sqlproj: -------------------------------------------------------------------------------- 1 | 2 | 3 | 4 | Debug 5 | AnyCPU 6 | DataGuard 7 | 2.0 8 | 4.1 9 | {03ba78eb-ee24-45a2-86f8-35bfef5be1a6} 10 | Microsoft.Data.Tools.Schema.Sql.Sql160DatabaseSchemaProvider 11 | Database 12 | 13 | 14 | DataGuard 15 | DataGuard 16 | 1033, CI 17 | BySchemaAndSchemaType 18 | True 19 | v4.7.2 20 | CS 21 | Properties 22 | False 23 | True 24 | True 25 | True 26 | False 27 | True 28 | 29 | 30 | bin\Release\ 31 | $(MSBuildProjectName).sql 32 | False 33 | pdbonly 34 | true 35 | false 36 | true 37 | prompt 38 | 4 39 | 40 | 41 | bin\Debug\ 42 | $(MSBuildProjectName).sql 43 | false 44 | true 45 | full 46 | false 47 | true 48 | true 49 | prompt 50 | 4 51 | 52 | 53 | 11.0 54 | 55 | True 56 | 11.0 57 | 58 | 59 | 60 | 61 | 62 | 63 | 64 | 65 | 66 | 67 | 68 | 69 | 70 | 71 | 72 | 73 | 74 | 75 | 76 | 77 | 78 | 79 | 80 | 81 | 82 | 83 | 84 | 85 | 86 | 87 | 88 | 89 | 90 | 91 | 92 | 93 | 94 | 95 | 96 | 97 | 98 | 99 | 100 | 101 | 102 | 103 | 104 | 105 | 106 | 107 | 108 | 109 | 110 | 111 | 112 | 113 | 114 | 115 | 116 | 117 | 118 | 119 | 120 | $(DacPacRootPath)\Extensions\Microsoft\SQLDB\Extensions\SqlServer\160\SqlSchemas\master.dacpac 121 | False 122 | master 123 | 124 | 125 | $(DacPacRootPath)\Extensions\Microsoft\SQLDB\Extensions\SqlServer\160\SqlSchemas\msdb.dacpac 126 | False 127 | msdb 128 | 129 | 130 | 131 | 132 | 133 | 134 | 135 | 136 | 137 | 138 | 139 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | ## Ignore Visual Studio temporary files, build results, and 2 | ## files generated by popular Visual Studio add-ons. 3 | ## 4 | ## Get latest from https://github.com/github/gitignore/blob/main/VisualStudio.gitignore 5 | 6 | # User-specific files 7 | *.rsuser 8 | *.suo 9 | *.user 10 | *.userosscache 11 | *.sln.docstates 12 | 13 | # User-specific files (MonoDevelop/Xamarin Studio) 14 | *.userprefs 15 | 16 | # Mono auto generated files 17 | mono_crash.* 18 | 19 | # Build results 20 | [Dd]ebug/ 21 | [Dd]ebugPublic/ 22 | [Rr]elease/ 23 | [Rr]eleases/ 24 | x64/ 25 | x86/ 26 | [Ww][Ii][Nn]32/ 27 | [Aa][Rr][Mm]/ 28 | [Aa][Rr][Mm]64/ 29 | bld/ 30 | [Bb]in/ 31 | [Oo]bj/ 32 | [Ll]og/ 33 | [Ll]ogs/ 34 | 35 | # Visual Studio 2015/2017 cache/options directory 36 | .vs/ 37 | # Uncomment if you have tasks that create the project's static files in wwwroot 38 | #wwwroot/ 39 | 40 | # Visual Studio 2017 auto generated files 41 | Generated\ Files/ 42 | 43 | # MSTest test Results 44 | [Tt]est[Rr]esult*/ 45 | [Bb]uild[Ll]og.* 46 | 47 | # NUnit 48 | *.VisualState.xml 49 | TestResult.xml 50 | nunit-*.xml 51 | 52 | # Build Results of an ATL Project 53 | [Dd]ebugPS/ 54 | [Rr]eleasePS/ 55 | dlldata.c 56 | 57 | # Benchmark Results 58 | BenchmarkDotNet.Artifacts/ 59 | 60 | # .NET Core 61 | project.lock.json 62 | project.fragment.lock.json 63 | artifacts/ 64 | 65 | # ASP.NET Scaffolding 66 | ScaffoldingReadMe.txt 67 | 68 | # StyleCop 69 | StyleCopReport.xml 70 | 71 | # Files built by Visual Studio 72 | *_i.c 73 | *_p.c 74 | *_h.h 75 | *.ilk 76 | *.meta 77 | *.obj 78 | *.iobj 79 | *.pch 80 | *.pdb 81 | *.ipdb 82 | *.pgc 83 | *.pgd 84 | *.rsp 85 | *.sbr 86 | *.tlb 87 | *.tli 88 | *.tlh 89 | *.tmp 90 | *.tmp_proj 91 | *_wpftmp.csproj 92 | *.log 93 | *.tlog 94 | *.vspscc 95 | *.vssscc 96 | .builds 97 | *.pidb 98 | *.svclog 99 | *.scc 100 | 101 | # Chutzpah Test files 102 | _Chutzpah* 103 | 104 | # Visual C++ cache files 105 | ipch/ 106 | *.aps 107 | *.ncb 108 | *.opendb 109 | *.opensdf 110 | *.sdf 111 | *.cachefile 112 | *.VC.db 113 | *.VC.VC.opendb 114 | 115 | # Visual Studio profiler 116 | *.psess 117 | *.vsp 118 | *.vspx 119 | *.sap 120 | 121 | # Visual Studio Trace Files 122 | *.e2e 123 | 124 | # TFS 2012 Local Workspace 125 | $tf/ 126 | 127 | # Guidance Automation Toolkit 128 | *.gpState 129 | 130 | # ReSharper is a .NET coding add-in 131 | _ReSharper*/ 132 | *.[Rr]e[Ss]harper 133 | *.DotSettings.user 134 | 135 | # TeamCity is a build add-in 136 | _TeamCity* 137 | 138 | # DotCover is a Code Coverage Tool 139 | *.dotCover 140 | 141 | # AxoCover is a Code Coverage Tool 142 | .axoCover/* 143 | !.axoCover/settings.json 144 | 145 | # Coverlet is a free, cross platform Code Coverage Tool 146 | coverage*.json 147 | coverage*.xml 148 | coverage*.info 149 | 150 | # Visual Studio code coverage results 151 | *.coverage 152 | *.coveragexml 153 | 154 | # NCrunch 155 | _NCrunch_* 156 | .*crunch*.local.xml 157 | nCrunchTemp_* 158 | 159 | # MightyMoose 160 | *.mm.* 161 | AutoTest.Net/ 162 | 163 | # Web workbench (sass) 164 | .sass-cache/ 165 | 166 | # Installshield output folder 167 | [Ee]xpress/ 168 | 169 | # DocProject is a documentation generator add-in 170 | DocProject/buildhelp/ 171 | DocProject/Help/*.HxT 172 | DocProject/Help/*.HxC 173 | DocProject/Help/*.hhc 174 | DocProject/Help/*.hhk 175 | DocProject/Help/*.hhp 176 | DocProject/Help/Html2 177 | DocProject/Help/html 178 | 179 | # Click-Once directory 180 | publish/ 181 | 182 | # Publish Web Output 183 | #*.[Pp]ublish.xml 184 | *.azurePubxml 185 | # Note: Comment the next line if you want to checkin your web deploy settings, 186 | # but database connection strings (with potential passwords) will be unencrypted 187 | *.pubxml 188 | *.publishproj 189 | 190 | # Microsoft Azure Web App publish settings. Comment the next line if you want to 191 | # checkin your Azure Web App publish settings, but sensitive information contained 192 | # in these scripts will be unencrypted 193 | PublishScripts/ 194 | 195 | # NuGet Packages 196 | *.nupkg 197 | # NuGet Symbol Packages 198 | *.snupkg 199 | # The packages folder can be ignored because of Package Restore 200 | **/[Pp]ackages/* 201 | # except build/, which is used as an MSBuild target. 202 | !**/[Pp]ackages/build/ 203 | # Uncomment if necessary however generally it will be regenerated when needed 204 | #!**/[Pp]ackages/repositories.config 205 | # NuGet v3's project.json files produces more ignorable files 206 | *.nuget.props 207 | *.nuget.targets 208 | 209 | # Microsoft Azure Build Output 210 | csx/ 211 | *.build.csdef 212 | 213 | # Microsoft Azure Emulator 214 | ecf/ 215 | rcf/ 216 | 217 | # Windows Store app package directories and files 218 | AppPackages/ 219 | BundleArtifacts/ 220 | Package.StoreAssociation.xml 221 | _pkginfo.txt 222 | *.appx 223 | *.appxbundle 224 | *.appxupload 225 | 226 | # Visual Studio cache files 227 | # files ending in .cache can be ignored 228 | *.[Cc]ache 229 | # but keep track of directories ending in .cache 230 | !?*.[Cc]ache/ 231 | 232 | # Others 233 | ClientBin/ 234 | ~$* 235 | *~ 236 | *.dbmdl 237 | *.dbproj.schemaview 238 | *.jfm 239 | *.pfx 240 | *.publishsettings 241 | orleans.codegen.cs 242 | 243 | # Including strong name files can present a security risk 244 | # (https://github.com/github/gitignore/pull/2483#issue-259490424) 245 | #*.snk 246 | 247 | # Since there are multiple workflows, uncomment next line to ignore bower_components 248 | # (https://github.com/github/gitignore/pull/1529#issuecomment-104372622) 249 | #bower_components/ 250 | 251 | # RIA/Silverlight projects 252 | Generated_Code/ 253 | 254 | # Backup & report files from converting an old project file 255 | # to a newer Visual Studio version. Backup files are not needed, 256 | # because we have git ;-) 257 | _UpgradeReport_Files/ 258 | Backup*/ 259 | UpgradeLog*.XML 260 | UpgradeLog*.htm 261 | ServiceFabricBackup/ 262 | *.rptproj.bak 263 | 264 | # SQL Server files 265 | *.mdf 266 | *.ldf 267 | *.ndf 268 | 269 | # Business Intelligence projects 270 | *.rdl.data 271 | *.bim.layout 272 | *.bim_*.settings 273 | *.rptproj.rsuser 274 | *- [Bb]ackup.rdl 275 | *- [Bb]ackup ([0-9]).rdl 276 | *- [Bb]ackup ([0-9][0-9]).rdl 277 | 278 | # Microsoft Fakes 279 | FakesAssemblies/ 280 | 281 | # GhostDoc plugin setting file 282 | *.GhostDoc.xml 283 | 284 | # Node.js Tools for Visual Studio 285 | .ntvs_analysis.dat 286 | node_modules/ 287 | 288 | # Visual Studio 6 build log 289 | *.plg 290 | 291 | # Visual Studio 6 workspace options file 292 | *.opt 293 | 294 | # Visual Studio 6 auto-generated workspace file (contains which files were open etc.) 295 | *.vbw 296 | 297 | # Visual Studio 6 auto-generated project file (contains which files were open etc.) 298 | *.vbp 299 | 300 | # Visual Studio 6 workspace and project file (working project files containing files to include in project) 301 | *.dsw 302 | *.dsp 303 | 304 | # Visual Studio 6 technical files 305 | *.ncb 306 | *.aps 307 | 308 | # Visual Studio LightSwitch build output 309 | **/*.HTMLClient/GeneratedArtifacts 310 | **/*.DesktopClient/GeneratedArtifacts 311 | **/*.DesktopClient/ModelManifest.xml 312 | **/*.Server/GeneratedArtifacts 313 | **/*.Server/ModelManifest.xml 314 | _Pvt_Extensions 315 | 316 | # Paket dependency manager 317 | .paket/paket.exe 318 | paket-files/ 319 | 320 | # FAKE - F# Make 321 | .fake/ 322 | 323 | # CodeRush personal settings 324 | .cr/personal 325 | 326 | # Python Tools for Visual Studio (PTVS) 327 | __pycache__/ 328 | *.pyc 329 | 330 | # Cake - Uncomment if you are using it 331 | # tools/** 332 | # !tools/packages.config 333 | 334 | # Tabs Studio 335 | *.tss 336 | 337 | # Telerik's JustMock configuration file 338 | *.jmconfig 339 | 340 | # BizTalk build output 341 | *.btp.cs 342 | *.btm.cs 343 | *.odx.cs 344 | *.xsd.cs 345 | 346 | # OpenCover UI analysis results 347 | OpenCover/ 348 | 349 | # Azure Stream Analytics local run output 350 | ASALocalRun/ 351 | 352 | # MSBuild Binary and Structured Log 353 | *.binlog 354 | 355 | # NVidia Nsight GPU debugger configuration file 356 | *.nvuser 357 | 358 | # MFractors (Xamarin productivity tool) working folder 359 | .mfractor/ 360 | 361 | # Local History for Visual Studio 362 | .localhistory/ 363 | 364 | # Visual Studio History (VSHistory) files 365 | .vshistory/ 366 | 367 | # BeatPulse healthcheck temp database 368 | healthchecksdb 369 | 370 | # Backup folder for Package Reference Convert tool in Visual Studio 2017 371 | MigrationBackup/ 372 | 373 | # Ionide (cross platform F# VS Code tools) working folder 374 | .ionide/ 375 | 376 | # Fody - auto-generated XML schema 377 | FodyWeavers.xsd 378 | 379 | # VS Code files for those working on multiple tools 380 | .vscode/* 381 | !.vscode/settings.json 382 | !.vscode/tasks.json 383 | !.vscode/launch.json 384 | !.vscode/extensions.json 385 | *.code-workspace 386 | 387 | # Local History for Visual Studio Code 388 | .history/ 389 | 390 | # Windows Installer files from build outputs 391 | *.cab 392 | *.msi 393 | *.msix 394 | *.msm 395 | *.msp 396 | 397 | # JetBrains Rider 398 | *.sln.iml 399 | 400 | --------------------------------------------------------------------------------