├── AWS RDS
├── sp_add_cdc.sql
└── sp_auto_cdc.sql
├── DBA
└── dba-config.sql
├── LICENSE
├── README.md
├── SQLCompare
├── TsqlTools-SQLcompare-IndexCompare.sql
├── TsqlTools-SQLcompare-ObjectsCompare.sql
└── TsqlTools-SQLcompare-RowsCompare.sql
├── Security Audit
└── tsqltools_AllInOneSecurityAudit.sql
└── _config.yml
/AWS RDS/sp_add_cdc.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************
2 | -------------------------------------
3 | tsqltools - RDS Add CDC
4 | -------------------------------------
5 | Description: This stored procedure will help you to enable CDC on
6 | all the exsiting tables. You have to run this store procedure on the
7 | database where you need to add the tables. It won't support Cross
8 | database's tables.
9 |
10 | How to Run: If you want to enable CDC on the tables which
11 | all are in DBAdmin database,
12 |
13 | USE DBAdmin
14 | GO
15 | EXEC sp_add_cdc 'DBAdmin'
16 |
17 | -------------------------------------------------------------------
18 |
19 | Version: v1.0
20 | Release Date: 2018-02-09
21 | Author: Bhuvanesh(@SQLadmin)
22 | Feedback: mailto:r.bhuvanesh@outlook.com
23 | Updates: https://github.com/SqlAdmin/tsqltools/
24 | Blog: http://www.sqlgossip.com/automatically-enable-cdc-in-rds-sql-server/
25 | License: GPL-3.0
26 | tsqltools is free to download.It contains Tsql stored procedures
27 | and scripts to help the DBAs and Developers to make job easier
28 | (C) 2017
29 | *******************************************************************/
30 |
31 | -- READ THE DESCRIPTION BEFORE EXECUTE THIS ***
32 | IF OBJECT_ID('dbo.sp_add_cdc') IS NULL
33 | EXEC ('CREATE PROCEDURE dbo.sp_add_cdc AS RETURN 0;');
34 | GO
35 |
36 | ALTER PROCEDURE [dbo].[sp_add_cdc]
37 | @cdcdbname NVARCHAR(100)
38 | as begin
39 | exec msdb.dbo.rds_cdc_enable_db @cdcdbname
40 | DECLARE @name VARCHAR(50)
41 | -- For PrimaryKey Tables
42 | DECLARE primary_tbl_cursor CURSOR FOR
43 | SELECT t1.table_name
44 | FROM INFORMATION_SCHEMA.TABLES t1
45 | Join INFORMATION_SCHEMA.TABLE_CONSTRAINTS t2 on t1.TABLE_NAME=t2.TABLE_NAME
46 | Join sys.tables t3 on t1.table_name = t3.name
47 | WHERE t1.TABLE_TYPE='BASE TABLE' and t2.CONSTRAINT_TYPE='PRIMARY KEY' and t1.table_schema !='cdc' and t3.is_tracked_by_cdc=0;
48 | OPEN primary_tbl_cursor
49 | FETCH NEXT FROM primary_tbl_cursor INTO @name
50 | WHILE @@FETCH_STATUS = 0
51 | BEGIN
52 | declare @primary int = 1
53 | declare @p_schema nvarchar(100)=(select table_schema
54 | FROM INFORMATION_SCHEMA.TABLES
55 | where TABLE_NAME=@name)
56 | declare @p_tbl nvarchar(100)=(select table_name
57 | FROM INFORMATION_SCHEMA.TABLES
58 | where TABLE_NAME=@name)
59 | exec sys.sp_cdc_enable_table
60 | @source_schema = @p_schema,
61 | @source_name = @p_tbl,
62 | @role_name = NULL,
63 | @supports_net_changes = @primary
64 |
65 | FETCH NEXT FROM primary_tbl_cursor INTO @name
66 | END
67 | CLOSE primary_tbl_cursor
68 | DEALLOCATE primary_tbl_cursor
69 |
70 | -- For Non-PrimaryKey Tables
71 |
72 | DECLARE nonprimary_cursor CURSOR FOR
73 | SELECT table_name
74 | FROM INFORMATION_SCHEMA.TABLES Join sys.tables t3 on table_name = t3.name
75 | where TABLE_NAME not in (select table_name
76 | from INFORMATION_SCHEMA.TABLE_CONSTRAINTS) and table_schema !='cdc' and TABLE_NAME !='systranschemas' and t3.is_tracked_by_cdc=0;
77 |
78 | OPEN nonprimary_cursor
79 | FETCH NEXT FROM nonprimary_cursor INTO @name
80 | WHILE @@FETCH_STATUS = 0
81 | BEGIN
82 | declare @n_primary int = 0
83 | declare @n_schema nvarchar(100)=(select table_schema
84 | FROM INFORMATION_SCHEMA.TABLES
85 | where TABLE_NAME=@name)
86 | declare @n_tbl nvarchar(100)=(select table_name
87 | FROM INFORMATION_SCHEMA.TABLES
88 | where TABLE_NAME=@name)
89 | exec sys.sp_cdc_enable_table
90 | @source_schema = @n_schema,
91 | @source_name = @n_tbl,
92 | @role_name = NULL,
93 | @supports_net_changes = @n_primary
94 |
95 | FETCH NEXT FROM nonprimary_cursor INTO @name
96 | END
97 | CLOSE nonprimary_cursor
98 | DEALLOCATE nonprimary_cursor
99 | END
100 |
--------------------------------------------------------------------------------
/AWS RDS/sp_auto_cdc.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************
2 | -------------------------------------
3 | tsqltools - RDS - Auto CDC
4 | -------------------------------------
5 | Description: This stored procedure will help you to enable CDC
6 | automatically when a tables is created. This is basically a database
7 | Trigger and it'll ecxecute enable CDC procedure when we creat a
8 | new table. This is a database level trigger, so it won't replicate
9 | the new tables which are in another database.
10 |
11 | How to Run: If you to enable this on DBAdmin database,
12 | USE DBAdmin
13 | GO
14 | -- Execute the below Query.
15 |
16 | -------------------------------------------------------------------
17 |
18 | Version: v1.0
19 | Release Date: 2018-02-10
20 | Author: Bhuvanesh(@SQLadmin)
21 | Feedback: mailto:r.bhuvanesh@outlook.com
22 | Updates: https://github.com/SqlAdmin/tsqltools/
23 | Blog: http://www.sqlgossip.com/automatically-enable-cdc-in-rds-sql-server/
24 | License: GPL-3.0
25 | tsqltools is free to download.It contains Tsql stored procedures
26 | and scripts to help the DBAs and Developers to make job easier
27 | (C) 2018
28 |
29 | *******************************************************************/
30 |
31 | -- READ THE DESCRIPTION BEFORE EXECUTE THIS ***
32 |
33 | CREATE TABLE [dbo].[DBSchema_Change_Log]
34 | (
35 | [RecordId] [int] IDENTITY(1,1) NOT NULL,
36 | [EventTime] [datetime] NULL,
37 | [LoginName] [varchar](50) NULL,
38 | [UserName] [varchar](50) NULL,
39 | [DatabaseName] [varchar](50) NULL,
40 | [SchemaName] [varchar](50) NULL,
41 | [ObjectName] [varchar](50) NULL,
42 | [ObjectType] [varchar](50) NULL,
43 | [DDLCommand] [varchar](max) NULL
44 |
45 | ) ON [PRIMARY]
46 | GO
47 |
48 | CREATE TRIGGER [auto_cdc] ON Database
49 | FOR CREATE_TABLE
50 | AS
51 | DECLARE @eventInfo XML
52 | SET @eventInfo = EVENTDATA()
53 | INSERT INTO DBSchema_Change_Log
54 | VALUES
55 | (
56 | REPLACE(CONVERT(VARCHAR(50),@eventInfo.query('data(/EVENT_INSTANCE/PostTime)')),'T', ' '),
57 | CONVERT(VARCHAR(50),@eventInfo.query('data(/EVENT_INSTANCE/LoginName)')),
58 | CONVERT(VARCHAR(50),@eventInfo.query('data(/EVENT_INSTANCE/UserName)')),
59 | CONVERT(VARCHAR(50),@eventInfo.query('data(/EVENT_INSTANCE/DatabaseName)')),
60 | CONVERT(VARCHAR(50),@eventInfo.query('data(/EVENT_INSTANCE/SchemaName)')),
61 | CONVERT(VARCHAR(50),@eventInfo.query('data(/EVENT_INSTANCE/ObjectName)')),
62 | CONVERT(VARCHAR(50),@eventInfo.query('data(/EVENT_INSTANCE/ObjectType)')),
63 | CONVERT(VARCHAR(MAX),@eventInfo.query('data(/EVENT_INSTANCE/TSQLCommand/CommandText)'))
64 | )
65 |
66 | declare @tbl varchar(100) =(select top(1)
67 | OBJECTname
68 | from DBSchema_Change_Log
69 | order by recordid desc)
70 | DECLARE @schemaname varchar(100) =(select top(1)
71 | schemaname
72 | from DBSchema_Change_Log
73 | order by recordid desc)
74 | DECLARE @primarykey int =( select case CONSTRAINT_TYPE when 'PRIMARY KEY' THen 1 else 0 end as PRIMARYkey
75 | from INFORMATION_SCHEMA.TABLE_CONSTRAINTS
76 | where TABLE_NAME=@tbl and TABLE_SCHEMA=@schemaname)
77 |
78 | exec sys.sp_cdc_enable_table
79 | @source_schema = @schemaname,
80 | @source_name = @tbl,
81 | @role_name = NULL,
82 | @supports_net_changes = @primarykey
83 | GO
84 | --Enable the Trigger
85 | ENABLE TRIGGER [auto_cdc] ON database
86 | GO
87 |
88 |
--------------------------------------------------------------------------------
/DBA/dba-config.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************
2 | -----------------------
3 | T-SQLtools - DBA-Config
4 | -----------------------
5 |
6 | DESCRIPTION: This is a simple T-SQL query to configure your SQL
7 | Server with Best Practices. After install SQL Server/Any exsiting
8 | SQL Server you can Run this.
9 |
10 | Parameters:
11 |
12 | MinMem => Assign Minimum Memory [Default 0]
13 | MaxMem => Assign Maximum Memory [Default 90%]
14 | P_MAXDOP => Set Max Degree of Parallelism [ Default - Based on CPU Cores]
15 | CostThresHold => Cost value to use Parallelism [Default - 50]
16 | DBfile => Default Data files [Default - Current Data file location]
17 | Logfile => Default Log files [Default- Current Log file location]
18 | Backup => Default path for Backup files [Default - Current Data backup location ]
19 | TempfilePath => Path for adding tempDB files [Default - Current Temp mdf file path]
20 | TempfileSize => Size for new temp DB files [Default - 100MB]
21 |
22 |
23 | Other Parameters will Reset to Default:
24 | 1. index create memory = 0
25 | 2. min memory per query = 1024
26 | 3. priority boost = 0
27 | 4. max worker threads = 0
28 | 5. lightweight pooling = 0
29 | 6. fill factor = 0
30 | 7. backup compression default = 1
31 |
32 |
33 |
34 | Credits: This Max_DOP value query written by Kin
35 | https://dba.stackexchange.com/users/8783/kin
36 |
37 |
38 | Version: v1.0
39 | Release Date: 2018-02-12
40 | Author: Bhuvanesh(@SQLadmin)
41 | Feedback: mailto:r.bhuvanesh@outlook.com
42 | Blog: www.sqlgossip.com
43 | License: GPL-3.0
44 | (C) 2018
45 |
46 | *************************
47 | Here is how I executed?
48 | *************************
49 |
50 | DECLARE @MinMem int -- Let the query calculate this
51 | DECLARE @MaxMem int -- Let the query calculate this
52 | DECLARE @P_MAXDOP INT -- Let the query calculate this
53 | DECLARE @CostThresHold INT -- Let the query calculate this
54 | DECLARE @DBfile nvarchar(500) = 'C:\Data'
55 | DECLARE @Logfile nvarchar(500) = 'C:\Log'
56 | DECLARE @Backup NVARCHAR(500) = 'C:\backups\'
57 | DECLARE @TempfilePath nvarchar(500) = 'C:\temp\'
58 | DECLARE @TempfileSize nvarchar(100) = '100MB'
59 |
60 | ******************************************************************/
61 |
62 | -- Global Declarations
63 | DECLARE @MinMem int
64 | DECLARE @MaxMem int
65 | DECLARE @P_MAXDOP INT
66 | DECLARE @CostThresHold INT
67 | DECLARE @DBfile nvarchar(500)
68 | DECLARE @Logfile nvarchar(500)
69 | DECLARE @Backup NVARCHAR(500)
70 | DECLARE @TempfilePath nvarchar(500) -- its mandatory
71 | DECLARE @TempfileSize nvarchar(100)
72 |
73 |
74 | EXEC sp_configure 'show advanced options', 1;
75 |
76 | -- Other Settings as per the Best Practice
77 | EXEC sp_configure 'index create memory', 0
78 | RECONFIGURE;
79 | EXEC sp_configure 'min memory per query', 1024;
80 | RECONFIGURE;
81 | EXEC sp_configure 'priority boost', 0;
82 | RECONFIGURE;
83 | EXEC sp_configure 'max worker threads', 0;
84 | RECONFIGURE;
85 | EXEC sp_configure 'lightweight pooling', 0;
86 | RECONFIGURE;
87 | EXEC sp_configure 'fill factor', 0;
88 | RECONFIGURE;
89 | EXEC sp_configure 'backup compression default', 1;
90 | RECONFIGURE WITH OVERRIDE ;
91 |
92 | -- Setting up Min/Max SQL Memory
93 | SET @MinMem = coalesce(nullif(@MinMem, ''), 0)
94 | DECLARE @MaximumMememory int
95 | SET @MaxMem = coalesce(nullif(@MaxMem, ''), 90)
96 | Select @MaximumMememory=(select ([total_physical_memory_kb] / 1024 * @MaxMem/100) as totalmin
97 | FROM [master].[sys].[dm_os_sys_memory])
98 | Exec sp_configure 'min server memory', @MinMem;
99 | Exec sp_configure 'max server memory', @MaximumMememory;
100 |
101 | -- Setting up MAX DOP and Cost Threshold limit
102 | DECLARE @hyperthreadingRatio bit
103 | DECLARE @logicalCPUs int
104 | DECLARE @HTEnabled int
105 | DECLARE @physicalCPU int
106 | DECLARE @SOCKET int
107 | DECLARE @logicalCPUPerNuma int
108 | DECLARE @NoOfNUMA int
109 | DECLARE @MaxDOP int
110 |
111 | select @logicalCPUs = cpu_count -- [Logical CPU Count]
112 | , @hyperthreadingRatio = hyperthread_ratio -- [Hyperthread Ratio]
113 | , @physicalCPU = cpu_count / hyperthread_ratio -- [Physical CPU Count]
114 | , @HTEnabled = case
115 | when cpu_count > hyperthread_ratio
116 | then 1
117 | else 0
118 | end
119 | -- HTEnabled
120 | from sys.dm_os_sys_info
121 | option
122 | (recompile);
123 |
124 | select @logicalCPUPerNuma = COUNT(parent_node_id)
125 | -- [NumberOfLogicalProcessorsPerNuma]
126 | from sys.dm_os_schedulers
127 | where [status] = 'VISIBLE ONLINE'
128 | and parent_node_id < 64
129 | group by parent_node_id
130 | option
131 | (recompile);
132 |
133 | select @NoOfNUMA = count(distinct parent_node_id)
134 | from sys.dm_os_schedulers
135 | -- find NO OF NUMA Nodes
136 | where [status] = 'VISIBLE ONLINE'
137 | and parent_node_id < 64
138 | SET @P_MAXDOP = coalesce(nullif(@P_MAXDOP, ''), (select
139 | --- 8 or less processors and NO HT enabled
140 | case
141 | when @logicalCPUs < 8
142 | and @HTEnabled = 0
143 | then CAST(@logicalCPUs as varchar(3))
144 | --- 8 or more processors and NO HT enabled
145 | when @logicalCPUs >= 8
146 | and @HTEnabled = 0
147 | then 8
148 | --- 8 or more processors and HT enabled and NO NUMA
149 | when @logicalCPUs >= 8
150 | and @HTEnabled = 1
151 | and @NoofNUMA = 1
152 | then CAST(@logicalCPUPerNuma / @physicalCPU as varchar(3))
153 | --- 8 or more processors and HT enabled and NUMA
154 | when @logicalCPUs >= 8
155 | and @HTEnabled = 1
156 | and @NoofNUMA > 1
157 | then CAST(@logicalCPUPerNuma / @physicalCPU as varchar(3))
158 | else ''
159 | end as Recommendations
160 | ))
161 | SET @CostThresHold = coalesce(nullif(@CostThresHold, ''), 50)
162 | EXEC sp_configure 'max degree of parallelism', @P_MAXDOP
163 | EXEC sp_configure 'cost threshold for parallelism', @CostThresHold
164 | ;
165 |
166 | -- Setting up Default Directories for Data/Log/Backup
167 | DECLARE @BackupDirectory NVARCHAR(100)
168 | EXEC master..xp_instance_regread @rootkey = 'HKEY_LOCAL_MACHINE',
169 | @key = 'Software\Microsoft\MSSQLServer\MSSQLServer',
170 | @value_name = 'BackupDirectory', @BackupDirectory = @BackupDirectory OUTPUT
171 | ;
172 | SET @Backup = coalesce(nullif(@Backup, ''), @BackupDirectory)
173 | SET @DBfile = coalesce(nullif(@DBfile, ''), (SELECT CONVERT(nvarchar(500), SERVERPROPERTY('INSTANCEDEFAULTDATAPATH'))))
174 | SET @Logfile = coalesce(nullif(@Logfile, ''), (SELECT CONVERT(nvarchar(500), SERVERPROPERTY('INSTANCEDEFAULTLOGPATH'))))
175 |
176 |
177 | EXEC xp_instance_regwrite
178 | N'HKEY_LOCAL_MACHINE',
179 | N'Software\Microsoft\MSSQLServer\MSSQLServer',
180 | N'DefaultData',
181 | REG_SZ,
182 | @DBfile
183 |
184 | EXEC xp_instance_regwrite
185 | N'HKEY_LOCAL_MACHINE',
186 | N'Software\Microsoft\MSSQLServer\MSSQLServer',
187 | N'DefaultLog',
188 | REG_SZ,
189 | @Logfile
190 |
191 | EXEC xp_instance_regwrite
192 | N'HKEY_LOCAL_MACHINE',
193 | N'Software\Microsoft\MSSQLServer\MSSQLServer',
194 | N'BackupDirectory',
195 | REG_SZ,
196 | @Logfile
197 |
198 | -- Add temp files
199 | -- Calculate Number of Required TempDB Files
200 | Declare @cpu int =( SELECT count(cpu_count)
201 | FROM sys.dm_os_sys_info )
202 | Declare @currenttempfine int = (SELECT count(name)
203 | FROM tempdb.sys.database_files)
204 | Declare @requiredtmpfiles int
205 | IF @cpu < 8 Set @requiredtmpfiles = 5
206 | IF @CPU >8 Set @requiredtmpfiles = 9
207 |
208 | -- Declare variables for adding new tempDB files
209 | Declare @int int
210 | Declare @MAX_File int
211 |
212 | SET @TempfileSize = coalesce(nullif(@TempfileSize, ''), '100MB')
213 |
214 | IF @currenttempfine = @requiredtmpfiles Print 'TempDB Files Are OK'
215 | SET @int=1
216 | Set @MAX_File = (@requiredtmpfiles -@currenttempfine)
217 |
218 | -- Adding TempDB Files
219 | WHILE @int <= @MAX_File
220 | Begin
221 | Declare @addfiles nvarchar(500)= (select 'ALTER DATABASE [tempdb] ADD FILE (NAME = '+'''tempdb_'+cast(@int as nvarchar(10))+''', FILENAME ='''+@TempfilePath+'tempdb_'+cast(@int as nvarchar(10))+'.ndf'' , SIZE = '+cast(@TempfileSize as nvarchar(10))+')' )
222 | --print @addfiles
223 | EXEC (@addfiles)
224 | SET @int=@int+1
225 | END
226 | IF @currenttempfine > @requiredtmpfiles print Cast(@currenttempfine-@requiredtmpfiles as nvarchar(100))+' File need to be removed'
227 | GO
228 |
229 |
--------------------------------------------------------------------------------
/LICENSE:
--------------------------------------------------------------------------------
1 | GNU GENERAL PUBLIC LICENSE
2 | Version 3, 29 June 2007
3 |
4 | Copyright (C) 2007 Free Software Foundation, Inc.
5 | Everyone is permitted to copy and distribute verbatim copies
6 | of this license document, but changing it is not allowed.
7 |
8 | Preamble
9 |
10 | The GNU General Public License is a free, copyleft license for
11 | software and other kinds of works.
12 |
13 | The licenses for most software and other practical works are designed
14 | to take away your freedom to share and change the works. By contrast,
15 | the GNU General Public License is intended to guarantee your freedom to
16 | share and change all versions of a program--to make sure it remains free
17 | software for all its users. We, the Free Software Foundation, use the
18 | GNU General Public License for most of our software; it applies also to
19 | any other work released this way by its authors. You can apply it to
20 | your programs, too.
21 |
22 | When we speak of free software, we are referring to freedom, not
23 | price. Our General Public Licenses are designed to make sure that you
24 | have the freedom to distribute copies of free software (and charge for
25 | them if you wish), that you receive source code or can get it if you
26 | want it, that you can change the software or use pieces of it in new
27 | free programs, and that you know you can do these things.
28 |
29 | To protect your rights, we need to prevent others from denying you
30 | these rights or asking you to surrender the rights. Therefore, you have
31 | certain responsibilities if you distribute copies of the software, or if
32 | you modify it: responsibilities to respect the freedom of others.
33 |
34 | For example, if you distribute copies of such a program, whether
35 | gratis or for a fee, you must pass on to the recipients the same
36 | freedoms that you received. You must make sure that they, too, receive
37 | or can get the source code. And you must show them these terms so they
38 | know their rights.
39 |
40 | Developers that use the GNU GPL protect your rights with two steps:
41 | (1) assert copyright on the software, and (2) offer you this License
42 | giving you legal permission to copy, distribute and/or modify it.
43 |
44 | For the developers' and authors' protection, the GPL clearly explains
45 | that there is no warranty for this free software. For both users' and
46 | authors' sake, the GPL requires that modified versions be marked as
47 | changed, so that their problems will not be attributed erroneously to
48 | authors of previous versions.
49 |
50 | Some devices are designed to deny users access to install or run
51 | modified versions of the software inside them, although the manufacturer
52 | can do so. This is fundamentally incompatible with the aim of
53 | protecting users' freedom to change the software. The systematic
54 | pattern of such abuse occurs in the area of products for individuals to
55 | use, which is precisely where it is most unacceptable. Therefore, we
56 | have designed this version of the GPL to prohibit the practice for those
57 | products. If such problems arise substantially in other domains, we
58 | stand ready to extend this provision to those domains in future versions
59 | of the GPL, as needed to protect the freedom of users.
60 |
61 | Finally, every program is threatened constantly by software patents.
62 | States should not allow patents to restrict development and use of
63 | software on general-purpose computers, but in those that do, we wish to
64 | avoid the special danger that patents applied to a free program could
65 | make it effectively proprietary. To prevent this, the GPL assures that
66 | patents cannot be used to render the program non-free.
67 |
68 | The precise terms and conditions for copying, distribution and
69 | modification follow.
70 |
71 | TERMS AND CONDITIONS
72 |
73 | 0. Definitions.
74 |
75 | "This License" refers to version 3 of the GNU General Public License.
76 |
77 | "Copyright" also means copyright-like laws that apply to other kinds of
78 | works, such as semiconductor masks.
79 |
80 | "The Program" refers to any copyrightable work licensed under this
81 | License. Each licensee is addressed as "you". "Licensees" and
82 | "recipients" may be individuals or organizations.
83 |
84 | To "modify" a work means to copy from or adapt all or part of the work
85 | in a fashion requiring copyright permission, other than the making of an
86 | exact copy. The resulting work is called a "modified version" of the
87 | earlier work or a work "based on" the earlier work.
88 |
89 | A "covered work" means either the unmodified Program or a work based
90 | on the Program.
91 |
92 | To "propagate" a work means to do anything with it that, without
93 | permission, would make you directly or secondarily liable for
94 | infringement under applicable copyright law, except executing it on a
95 | computer or modifying a private copy. Propagation includes copying,
96 | distribution (with or without modification), making available to the
97 | public, and in some countries other activities as well.
98 |
99 | To "convey" a work means any kind of propagation that enables other
100 | parties to make or receive copies. Mere interaction with a user through
101 | a computer network, with no transfer of a copy, is not conveying.
102 |
103 | An interactive user interface displays "Appropriate Legal Notices"
104 | to the extent that it includes a convenient and prominently visible
105 | feature that (1) displays an appropriate copyright notice, and (2)
106 | tells the user that there is no warranty for the work (except to the
107 | extent that warranties are provided), that licensees may convey the
108 | work under this License, and how to view a copy of this License. If
109 | the interface presents a list of user commands or options, such as a
110 | menu, a prominent item in the list meets this criterion.
111 |
112 | 1. Source Code.
113 |
114 | The "source code" for a work means the preferred form of the work
115 | for making modifications to it. "Object code" means any non-source
116 | form of a work.
117 |
118 | A "Standard Interface" means an interface that either is an official
119 | standard defined by a recognized standards body, or, in the case of
120 | interfaces specified for a particular programming language, one that
121 | is widely used among developers working in that language.
122 |
123 | The "System Libraries" of an executable work include anything, other
124 | than the work as a whole, that (a) is included in the normal form of
125 | packaging a Major Component, but which is not part of that Major
126 | Component, and (b) serves only to enable use of the work with that
127 | Major Component, or to implement a Standard Interface for which an
128 | implementation is available to the public in source code form. A
129 | "Major Component", in this context, means a major essential component
130 | (kernel, window system, and so on) of the specific operating system
131 | (if any) on which the executable work runs, or a compiler used to
132 | produce the work, or an object code interpreter used to run it.
133 |
134 | The "Corresponding Source" for a work in object code form means all
135 | the source code needed to generate, install, and (for an executable
136 | work) run the object code and to modify the work, including scripts to
137 | control those activities. However, it does not include the work's
138 | System Libraries, or general-purpose tools or generally available free
139 | programs which are used unmodified in performing those activities but
140 | which are not part of the work. For example, Corresponding Source
141 | includes interface definition files associated with source files for
142 | the work, and the source code for shared libraries and dynamically
143 | linked subprograms that the work is specifically designed to require,
144 | such as by intimate data communication or control flow between those
145 | subprograms and other parts of the work.
146 |
147 | The Corresponding Source need not include anything that users
148 | can regenerate automatically from other parts of the Corresponding
149 | Source.
150 |
151 | The Corresponding Source for a work in source code form is that
152 | same work.
153 |
154 | 2. Basic Permissions.
155 |
156 | All rights granted under this License are granted for the term of
157 | copyright on the Program, and are irrevocable provided the stated
158 | conditions are met. This License explicitly affirms your unlimited
159 | permission to run the unmodified Program. The output from running a
160 | covered work is covered by this License only if the output, given its
161 | content, constitutes a covered work. This License acknowledges your
162 | rights of fair use or other equivalent, as provided by copyright law.
163 |
164 | You may make, run and propagate covered works that you do not
165 | convey, without conditions so long as your license otherwise remains
166 | in force. You may convey covered works to others for the sole purpose
167 | of having them make modifications exclusively for you, or provide you
168 | with facilities for running those works, provided that you comply with
169 | the terms of this License in conveying all material for which you do
170 | not control copyright. Those thus making or running the covered works
171 | for you must do so exclusively on your behalf, under your direction
172 | and control, on terms that prohibit them from making any copies of
173 | your copyrighted material outside their relationship with you.
174 |
175 | Conveying under any other circumstances is permitted solely under
176 | the conditions stated below. Sublicensing is not allowed; section 10
177 | makes it unnecessary.
178 |
179 | 3. Protecting Users' Legal Rights From Anti-Circumvention Law.
180 |
181 | No covered work shall be deemed part of an effective technological
182 | measure under any applicable law fulfilling obligations under article
183 | 11 of the WIPO copyright treaty adopted on 20 December 1996, or
184 | similar laws prohibiting or restricting circumvention of such
185 | measures.
186 |
187 | When you convey a covered work, you waive any legal power to forbid
188 | circumvention of technological measures to the extent such circumvention
189 | is effected by exercising rights under this License with respect to
190 | the covered work, and you disclaim any intention to limit operation or
191 | modification of the work as a means of enforcing, against the work's
192 | users, your or third parties' legal rights to forbid circumvention of
193 | technological measures.
194 |
195 | 4. Conveying Verbatim Copies.
196 |
197 | You may convey verbatim copies of the Program's source code as you
198 | receive it, in any medium, provided that you conspicuously and
199 | appropriately publish on each copy an appropriate copyright notice;
200 | keep intact all notices stating that this License and any
201 | non-permissive terms added in accord with section 7 apply to the code;
202 | keep intact all notices of the absence of any warranty; and give all
203 | recipients a copy of this License along with the Program.
204 |
205 | You may charge any price or no price for each copy that you convey,
206 | and you may offer support or warranty protection for a fee.
207 |
208 | 5. Conveying Modified Source Versions.
209 |
210 | You may convey a work based on the Program, or the modifications to
211 | produce it from the Program, in the form of source code under the
212 | terms of section 4, provided that you also meet all of these conditions:
213 |
214 | a) The work must carry prominent notices stating that you modified
215 | it, and giving a relevant date.
216 |
217 | b) The work must carry prominent notices stating that it is
218 | released under this License and any conditions added under section
219 | 7. This requirement modifies the requirement in section 4 to
220 | "keep intact all notices".
221 |
222 | c) You must license the entire work, as a whole, under this
223 | License to anyone who comes into possession of a copy. This
224 | License will therefore apply, along with any applicable section 7
225 | additional terms, to the whole of the work, and all its parts,
226 | regardless of how they are packaged. This License gives no
227 | permission to license the work in any other way, but it does not
228 | invalidate such permission if you have separately received it.
229 |
230 | d) If the work has interactive user interfaces, each must display
231 | Appropriate Legal Notices; however, if the Program has interactive
232 | interfaces that do not display Appropriate Legal Notices, your
233 | work need not make them do so.
234 |
235 | A compilation of a covered work with other separate and independent
236 | works, which are not by their nature extensions of the covered work,
237 | and which are not combined with it such as to form a larger program,
238 | in or on a volume of a storage or distribution medium, is called an
239 | "aggregate" if the compilation and its resulting copyright are not
240 | used to limit the access or legal rights of the compilation's users
241 | beyond what the individual works permit. Inclusion of a covered work
242 | in an aggregate does not cause this License to apply to the other
243 | parts of the aggregate.
244 |
245 | 6. Conveying Non-Source Forms.
246 |
247 | You may convey a covered work in object code form under the terms
248 | of sections 4 and 5, provided that you also convey the
249 | machine-readable Corresponding Source under the terms of this License,
250 | in one of these ways:
251 |
252 | a) Convey the object code in, or embodied in, a physical product
253 | (including a physical distribution medium), accompanied by the
254 | Corresponding Source fixed on a durable physical medium
255 | customarily used for software interchange.
256 |
257 | b) Convey the object code in, or embodied in, a physical product
258 | (including a physical distribution medium), accompanied by a
259 | written offer, valid for at least three years and valid for as
260 | long as you offer spare parts or customer support for that product
261 | model, to give anyone who possesses the object code either (1) a
262 | copy of the Corresponding Source for all the software in the
263 | product that is covered by this License, on a durable physical
264 | medium customarily used for software interchange, for a price no
265 | more than your reasonable cost of physically performing this
266 | conveying of source, or (2) access to copy the
267 | Corresponding Source from a network server at no charge.
268 |
269 | c) Convey individual copies of the object code with a copy of the
270 | written offer to provide the Corresponding Source. This
271 | alternative is allowed only occasionally and noncommercially, and
272 | only if you received the object code with such an offer, in accord
273 | with subsection 6b.
274 |
275 | d) Convey the object code by offering access from a designated
276 | place (gratis or for a charge), and offer equivalent access to the
277 | Corresponding Source in the same way through the same place at no
278 | further charge. You need not require recipients to copy the
279 | Corresponding Source along with the object code. If the place to
280 | copy the object code is a network server, the Corresponding Source
281 | may be on a different server (operated by you or a third party)
282 | that supports equivalent copying facilities, provided you maintain
283 | clear directions next to the object code saying where to find the
284 | Corresponding Source. Regardless of what server hosts the
285 | Corresponding Source, you remain obligated to ensure that it is
286 | available for as long as needed to satisfy these requirements.
287 |
288 | e) Convey the object code using peer-to-peer transmission, provided
289 | you inform other peers where the object code and Corresponding
290 | Source of the work are being offered to the general public at no
291 | charge under subsection 6d.
292 |
293 | A separable portion of the object code, whose source code is excluded
294 | from the Corresponding Source as a System Library, need not be
295 | included in conveying the object code work.
296 |
297 | A "User Product" is either (1) a "consumer product", which means any
298 | tangible personal property which is normally used for personal, family,
299 | or household purposes, or (2) anything designed or sold for incorporation
300 | into a dwelling. In determining whether a product is a consumer product,
301 | doubtful cases shall be resolved in favor of coverage. For a particular
302 | product received by a particular user, "normally used" refers to a
303 | typical or common use of that class of product, regardless of the status
304 | of the particular user or of the way in which the particular user
305 | actually uses, or expects or is expected to use, the product. A product
306 | is a consumer product regardless of whether the product has substantial
307 | commercial, industrial or non-consumer uses, unless such uses represent
308 | the only significant mode of use of the product.
309 |
310 | "Installation Information" for a User Product means any methods,
311 | procedures, authorization keys, or other information required to install
312 | and execute modified versions of a covered work in that User Product from
313 | a modified version of its Corresponding Source. The information must
314 | suffice to ensure that the continued functioning of the modified object
315 | code is in no case prevented or interfered with solely because
316 | modification has been made.
317 |
318 | If you convey an object code work under this section in, or with, or
319 | specifically for use in, a User Product, and the conveying occurs as
320 | part of a transaction in which the right of possession and use of the
321 | User Product is transferred to the recipient in perpetuity or for a
322 | fixed term (regardless of how the transaction is characterized), the
323 | Corresponding Source conveyed under this section must be accompanied
324 | by the Installation Information. But this requirement does not apply
325 | if neither you nor any third party retains the ability to install
326 | modified object code on the User Product (for example, the work has
327 | been installed in ROM).
328 |
329 | The requirement to provide Installation Information does not include a
330 | requirement to continue to provide support service, warranty, or updates
331 | for a work that has been modified or installed by the recipient, or for
332 | the User Product in which it has been modified or installed. Access to a
333 | network may be denied when the modification itself materially and
334 | adversely affects the operation of the network or violates the rules and
335 | protocols for communication across the network.
336 |
337 | Corresponding Source conveyed, and Installation Information provided,
338 | in accord with this section must be in a format that is publicly
339 | documented (and with an implementation available to the public in
340 | source code form), and must require no special password or key for
341 | unpacking, reading or copying.
342 |
343 | 7. Additional Terms.
344 |
345 | "Additional permissions" are terms that supplement the terms of this
346 | License by making exceptions from one or more of its conditions.
347 | Additional permissions that are applicable to the entire Program shall
348 | be treated as though they were included in this License, to the extent
349 | that they are valid under applicable law. If additional permissions
350 | apply only to part of the Program, that part may be used separately
351 | under those permissions, but the entire Program remains governed by
352 | this License without regard to the additional permissions.
353 |
354 | When you convey a copy of a covered work, you may at your option
355 | remove any additional permissions from that copy, or from any part of
356 | it. (Additional permissions may be written to require their own
357 | removal in certain cases when you modify the work.) You may place
358 | additional permissions on material, added by you to a covered work,
359 | for which you have or can give appropriate copyright permission.
360 |
361 | Notwithstanding any other provision of this License, for material you
362 | add to a covered work, you may (if authorized by the copyright holders of
363 | that material) supplement the terms of this License with terms:
364 |
365 | a) Disclaiming warranty or limiting liability differently from the
366 | terms of sections 15 and 16 of this License; or
367 |
368 | b) Requiring preservation of specified reasonable legal notices or
369 | author attributions in that material or in the Appropriate Legal
370 | Notices displayed by works containing it; or
371 |
372 | c) Prohibiting misrepresentation of the origin of that material, or
373 | requiring that modified versions of such material be marked in
374 | reasonable ways as different from the original version; or
375 |
376 | d) Limiting the use for publicity purposes of names of licensors or
377 | authors of the material; or
378 |
379 | e) Declining to grant rights under trademark law for use of some
380 | trade names, trademarks, or service marks; or
381 |
382 | f) Requiring indemnification of licensors and authors of that
383 | material by anyone who conveys the material (or modified versions of
384 | it) with contractual assumptions of liability to the recipient, for
385 | any liability that these contractual assumptions directly impose on
386 | those licensors and authors.
387 |
388 | All other non-permissive additional terms are considered "further
389 | restrictions" within the meaning of section 10. If the Program as you
390 | received it, or any part of it, contains a notice stating that it is
391 | governed by this License along with a term that is a further
392 | restriction, you may remove that term. If a license document contains
393 | a further restriction but permits relicensing or conveying under this
394 | License, you may add to a covered work material governed by the terms
395 | of that license document, provided that the further restriction does
396 | not survive such relicensing or conveying.
397 |
398 | If you add terms to a covered work in accord with this section, you
399 | must place, in the relevant source files, a statement of the
400 | additional terms that apply to those files, or a notice indicating
401 | where to find the applicable terms.
402 |
403 | Additional terms, permissive or non-permissive, may be stated in the
404 | form of a separately written license, or stated as exceptions;
405 | the above requirements apply either way.
406 |
407 | 8. Termination.
408 |
409 | You may not propagate or modify a covered work except as expressly
410 | provided under this License. Any attempt otherwise to propagate or
411 | modify it is void, and will automatically terminate your rights under
412 | this License (including any patent licenses granted under the third
413 | paragraph of section 11).
414 |
415 | However, if you cease all violation of this License, then your
416 | license from a particular copyright holder is reinstated (a)
417 | provisionally, unless and until the copyright holder explicitly and
418 | finally terminates your license, and (b) permanently, if the copyright
419 | holder fails to notify you of the violation by some reasonable means
420 | prior to 60 days after the cessation.
421 |
422 | Moreover, your license from a particular copyright holder is
423 | reinstated permanently if the copyright holder notifies you of the
424 | violation by some reasonable means, this is the first time you have
425 | received notice of violation of this License (for any work) from that
426 | copyright holder, and you cure the violation prior to 30 days after
427 | your receipt of the notice.
428 |
429 | Termination of your rights under this section does not terminate the
430 | licenses of parties who have received copies or rights from you under
431 | this License. If your rights have been terminated and not permanently
432 | reinstated, you do not qualify to receive new licenses for the same
433 | material under section 10.
434 |
435 | 9. Acceptance Not Required for Having Copies.
436 |
437 | You are not required to accept this License in order to receive or
438 | run a copy of the Program. Ancillary propagation of a covered work
439 | occurring solely as a consequence of using peer-to-peer transmission
440 | to receive a copy likewise does not require acceptance. However,
441 | nothing other than this License grants you permission to propagate or
442 | modify any covered work. These actions infringe copyright if you do
443 | not accept this License. Therefore, by modifying or propagating a
444 | covered work, you indicate your acceptance of this License to do so.
445 |
446 | 10. Automatic Licensing of Downstream Recipients.
447 |
448 | Each time you convey a covered work, the recipient automatically
449 | receives a license from the original licensors, to run, modify and
450 | propagate that work, subject to this License. You are not responsible
451 | for enforcing compliance by third parties with this License.
452 |
453 | An "entity transaction" is a transaction transferring control of an
454 | organization, or substantially all assets of one, or subdividing an
455 | organization, or merging organizations. If propagation of a covered
456 | work results from an entity transaction, each party to that
457 | transaction who receives a copy of the work also receives whatever
458 | licenses to the work the party's predecessor in interest had or could
459 | give under the previous paragraph, plus a right to possession of the
460 | Corresponding Source of the work from the predecessor in interest, if
461 | the predecessor has it or can get it with reasonable efforts.
462 |
463 | You may not impose any further restrictions on the exercise of the
464 | rights granted or affirmed under this License. For example, you may
465 | not impose a license fee, royalty, or other charge for exercise of
466 | rights granted under this License, and you may not initiate litigation
467 | (including a cross-claim or counterclaim in a lawsuit) alleging that
468 | any patent claim is infringed by making, using, selling, offering for
469 | sale, or importing the Program or any portion of it.
470 |
471 | 11. Patents.
472 |
473 | A "contributor" is a copyright holder who authorizes use under this
474 | License of the Program or a work on which the Program is based. The
475 | work thus licensed is called the contributor's "contributor version".
476 |
477 | A contributor's "essential patent claims" are all patent claims
478 | owned or controlled by the contributor, whether already acquired or
479 | hereafter acquired, that would be infringed by some manner, permitted
480 | by this License, of making, using, or selling its contributor version,
481 | but do not include claims that would be infringed only as a
482 | consequence of further modification of the contributor version. For
483 | purposes of this definition, "control" includes the right to grant
484 | patent sublicenses in a manner consistent with the requirements of
485 | this License.
486 |
487 | Each contributor grants you a non-exclusive, worldwide, royalty-free
488 | patent license under the contributor's essential patent claims, to
489 | make, use, sell, offer for sale, import and otherwise run, modify and
490 | propagate the contents of its contributor version.
491 |
492 | In the following three paragraphs, a "patent license" is any express
493 | agreement or commitment, however denominated, not to enforce a patent
494 | (such as an express permission to practice a patent or covenant not to
495 | sue for patent infringement). To "grant" such a patent license to a
496 | party means to make such an agreement or commitment not to enforce a
497 | patent against the party.
498 |
499 | If you convey a covered work, knowingly relying on a patent license,
500 | and the Corresponding Source of the work is not available for anyone
501 | to copy, free of charge and under the terms of this License, through a
502 | publicly available network server or other readily accessible means,
503 | then you must either (1) cause the Corresponding Source to be so
504 | available, or (2) arrange to deprive yourself of the benefit of the
505 | patent license for this particular work, or (3) arrange, in a manner
506 | consistent with the requirements of this License, to extend the patent
507 | license to downstream recipients. "Knowingly relying" means you have
508 | actual knowledge that, but for the patent license, your conveying the
509 | covered work in a country, or your recipient's use of the covered work
510 | in a country, would infringe one or more identifiable patents in that
511 | country that you have reason to believe are valid.
512 |
513 | If, pursuant to or in connection with a single transaction or
514 | arrangement, you convey, or propagate by procuring conveyance of, a
515 | covered work, and grant a patent license to some of the parties
516 | receiving the covered work authorizing them to use, propagate, modify
517 | or convey a specific copy of the covered work, then the patent license
518 | you grant is automatically extended to all recipients of the covered
519 | work and works based on it.
520 |
521 | A patent license is "discriminatory" if it does not include within
522 | the scope of its coverage, prohibits the exercise of, or is
523 | conditioned on the non-exercise of one or more of the rights that are
524 | specifically granted under this License. You may not convey a covered
525 | work if you are a party to an arrangement with a third party that is
526 | in the business of distributing software, under which you make payment
527 | to the third party based on the extent of your activity of conveying
528 | the work, and under which the third party grants, to any of the
529 | parties who would receive the covered work from you, a discriminatory
530 | patent license (a) in connection with copies of the covered work
531 | conveyed by you (or copies made from those copies), or (b) primarily
532 | for and in connection with specific products or compilations that
533 | contain the covered work, unless you entered into that arrangement,
534 | or that patent license was granted, prior to 28 March 2007.
535 |
536 | Nothing in this License shall be construed as excluding or limiting
537 | any implied license or other defenses to infringement that may
538 | otherwise be available to you under applicable patent law.
539 |
540 | 12. No Surrender of Others' Freedom.
541 |
542 | If conditions are imposed on you (whether by court order, agreement or
543 | otherwise) that contradict the conditions of this License, they do not
544 | excuse you from the conditions of this License. If you cannot convey a
545 | covered work so as to satisfy simultaneously your obligations under this
546 | License and any other pertinent obligations, then as a consequence you may
547 | not convey it at all. For example, if you agree to terms that obligate you
548 | to collect a royalty for further conveying from those to whom you convey
549 | the Program, the only way you could satisfy both those terms and this
550 | License would be to refrain entirely from conveying the Program.
551 |
552 | 13. Use with the GNU Affero General Public License.
553 |
554 | Notwithstanding any other provision of this License, you have
555 | permission to link or combine any covered work with a work licensed
556 | under version 3 of the GNU Affero General Public License into a single
557 | combined work, and to convey the resulting work. The terms of this
558 | License will continue to apply to the part which is the covered work,
559 | but the special requirements of the GNU Affero General Public License,
560 | section 13, concerning interaction through a network will apply to the
561 | combination as such.
562 |
563 | 14. Revised Versions of this License.
564 |
565 | The Free Software Foundation may publish revised and/or new versions of
566 | the GNU General Public License from time to time. Such new versions will
567 | be similar in spirit to the present version, but may differ in detail to
568 | address new problems or concerns.
569 |
570 | Each version is given a distinguishing version number. If the
571 | Program specifies that a certain numbered version of the GNU General
572 | Public License "or any later version" applies to it, you have the
573 | option of following the terms and conditions either of that numbered
574 | version or of any later version published by the Free Software
575 | Foundation. If the Program does not specify a version number of the
576 | GNU General Public License, you may choose any version ever published
577 | by the Free Software Foundation.
578 |
579 | If the Program specifies that a proxy can decide which future
580 | versions of the GNU General Public License can be used, that proxy's
581 | public statement of acceptance of a version permanently authorizes you
582 | to choose that version for the Program.
583 |
584 | Later license versions may give you additional or different
585 | permissions. However, no additional obligations are imposed on any
586 | author or copyright holder as a result of your choosing to follow a
587 | later version.
588 |
589 | 15. Disclaimer of Warranty.
590 |
591 | THERE IS NO WARRANTY FOR THE PROGRAM, TO THE EXTENT PERMITTED BY
592 | APPLICABLE LAW. EXCEPT WHEN OTHERWISE STATED IN WRITING THE COPYRIGHT
593 | HOLDERS AND/OR OTHER PARTIES PROVIDE THE PROGRAM "AS IS" WITHOUT WARRANTY
594 | OF ANY KIND, EITHER EXPRESSED OR IMPLIED, INCLUDING, BUT NOT LIMITED TO,
595 | THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR
596 | PURPOSE. THE ENTIRE RISK AS TO THE QUALITY AND PERFORMANCE OF THE PROGRAM
597 | IS WITH YOU. SHOULD THE PROGRAM PROVE DEFECTIVE, YOU ASSUME THE COST OF
598 | ALL NECESSARY SERVICING, REPAIR OR CORRECTION.
599 |
600 | 16. Limitation of Liability.
601 |
602 | IN NO EVENT UNLESS REQUIRED BY APPLICABLE LAW OR AGREED TO IN WRITING
603 | WILL ANY COPYRIGHT HOLDER, OR ANY OTHER PARTY WHO MODIFIES AND/OR CONVEYS
604 | THE PROGRAM AS PERMITTED ABOVE, BE LIABLE TO YOU FOR DAMAGES, INCLUDING ANY
605 | GENERAL, SPECIAL, INCIDENTAL OR CONSEQUENTIAL DAMAGES ARISING OUT OF THE
606 | USE OR INABILITY TO USE THE PROGRAM (INCLUDING BUT NOT LIMITED TO LOSS OF
607 | DATA OR DATA BEING RENDERED INACCURATE OR LOSSES SUSTAINED BY YOU OR THIRD
608 | PARTIES OR A FAILURE OF THE PROGRAM TO OPERATE WITH ANY OTHER PROGRAMS),
609 | EVEN IF SUCH HOLDER OR OTHER PARTY HAS BEEN ADVISED OF THE POSSIBILITY OF
610 | SUCH DAMAGES.
611 |
612 | 17. Interpretation of Sections 15 and 16.
613 |
614 | If the disclaimer of warranty and limitation of liability provided
615 | above cannot be given local legal effect according to their terms,
616 | reviewing courts shall apply local law that most closely approximates
617 | an absolute waiver of all civil liability in connection with the
618 | Program, unless a warranty or assumption of liability accompanies a
619 | copy of the Program in return for a fee.
620 |
621 | END OF TERMS AND CONDITIONS
622 |
623 | How to Apply These Terms to Your New Programs
624 |
625 | If you develop a new program, and you want it to be of the greatest
626 | possible use to the public, the best way to achieve this is to make it
627 | free software which everyone can redistribute and change under these terms.
628 |
629 | To do so, attach the following notices to the program. It is safest
630 | to attach them to the start of each source file to most effectively
631 | state the exclusion of warranty; and each file should have at least
632 | the "copyright" line and a pointer to where the full notice is found.
633 |
634 |
635 | Copyright (C)
636 |
637 | This program is free software: you can redistribute it and/or modify
638 | it under the terms of the GNU General Public License as published by
639 | the Free Software Foundation, either version 3 of the License, or
640 | (at your option) any later version.
641 |
642 | This program is distributed in the hope that it will be useful,
643 | but WITHOUT ANY WARRANTY; without even the implied warranty of
644 | MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
645 | GNU General Public License for more details.
646 |
647 | You should have received a copy of the GNU General Public License
648 | along with this program. If not, see .
649 |
650 | Also add information on how to contact you by electronic and paper mail.
651 |
652 | If the program does terminal interaction, make it output a short
653 | notice like this when it starts in an interactive mode:
654 |
655 | Copyright (C)
656 | This program comes with ABSOLUTELY NO WARRANTY; for details type `show w'.
657 | This is free software, and you are welcome to redistribute it
658 | under certain conditions; type `show c' for details.
659 |
660 | The hypothetical commands `show w' and `show c' should show the appropriate
661 | parts of the General Public License. Of course, your program's commands
662 | might be different; for a GUI interface, you would use an "about box".
663 |
664 | You should also get your employer (if you work as a programmer) or school,
665 | if any, to sign a "copyright disclaimer" for the program, if necessary.
666 | For more information on this, and how to apply and follow the GNU GPL, see
667 | .
668 |
669 | The GNU General Public License does not permit incorporating your program
670 | into proprietary programs. If your program is a subroutine library, you
671 | may consider it more useful to permit linking proprietary applications with
672 | the library. If this is what you want to do, use the GNU Lesser General
673 | Public License instead of this License. But first, please read
674 | .
675 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | # T-SQLtools
2 | Tsql stored procedures and scripts to help the DBAs and Developers to make their job easier.
3 |
4 | ## Index
5 | * Security
6 | * [All In One Security Audit](https://github.com/SqlAdmin/tsqltools/blob/master/Security%20Audit/tsqltools_AllInOneSecurityAudit.sql)
7 |
8 | * SQLcompare
9 | * [Objects Compare](https://github.com/SqlAdmin/tsqltools/blob/master/SQLCompare/TsqlTools-SQLcompare-ObjectsCompare.sql)
10 | * [Index Compare](https://github.com/SqlAdmin/tsqltools/blob/master/SQLCompare/TsqlTools-SQLcompare-IndexCompare.sql)
11 | * [Row Count Compare](https://github.com/SqlAdmin/tsqltools/blob/master/SQLCompare/TsqlTools-SQLcompare-RowsCompare.sql)
12 |
13 | * AWS RDS
14 | * [Enable CDC on exsiting tables in one shot](https://github.com/SqlAdmin/tsqltools/blob/master/AWS%20RDS/sp_add_cdc.sql)
15 | * [Automate - enable CDC on when table is created](https://github.com/SqlAdmin/tsqltools/blob/master/AWS%20RDS/sp_auto_cdc.sql)
--------------------------------------------------------------------------------
/SQLCompare/TsqlTools-SQLcompare-IndexCompare.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************
2 | -----------------------
3 | tsqltools - SQLCOMPARE - Index Compare
4 | -----------------------
5 | Version: v1.0
6 | Release Date: 2017-07-30
7 | Author: Bhuvanesh(@SQLadmin)
8 | Feedback: mailto:r.bhuvanesh@outlook.com
9 | Updates: http://medium.com/sqladmin
10 | Repo: https://github.com/SqlAdmin/tsqltools/
11 | License:
12 | tsqltools is free to download.It contains Tsql stored procedures
13 | and scripts to help the DBAs and Developers to make their job easier
14 | (C) 2017
15 |
16 |
17 | ======================================================================
18 |
19 | What is TsqlTools-SQLcompare?
20 |
21 | TsqlTools-SQLcompare is a tsqlscript that will help to compare Databases,
22 | Tables, Objects, Indexices between two servers without any tools.
23 |
24 | ======================================================================
25 | How to Start?
26 |
27 | Use a centalized server and create LinkedServers from the centralized server.
28 | Or Create LinkedServer on SourceDB server then run this query on SourceDB server.
29 |
30 | ========================================================================*/
31 | DECLARE @SOURCEDBSERVER varchar(100)
32 | DECLARE @DESTINATIONDBSERVER varchar(100)
33 | DECLARE @SOURCE_SQL_DBNAME nvarchar(300)
34 | DECLARE @SOURCE_DATABASENAME TABLE ( dbname varchar(100))
35 | DECLARE @DESTINATION_SQL_DBNAME nvarchar(300)
36 | DECLARE @DESTINATION_DATABASENAME TABLE ( dbname varchar(100))
37 |
38 |
39 | SELECT @SOURCEDBSERVER = '[db01]' --==> Replace Your Source DB serverName Here
40 |
41 | SELECT @DESTINATIONDBSERVER = '[db02]' --==> Replace Your Target DB serverName Here
42 |
43 | SELECT
44 | @SOURCE_SQL_DBNAME = 'select name from ' + @SOURCEDBSERVER + '.master.sys.databases where database_id>4'
45 | INSERT INTO @SOURCE_DATABASENAME EXEC sp_executesql @SOURCE_SQL_DBNAME
46 | SELECT
47 | @DESTINATION_SQL_DBNAME = 'select name from ' + @DESTINATIONDBSERVER + '.master.sys.databases where database_id>4'
48 | INSERT INTO @DESTINATION_DATABASENAME EXEC sp_executesql @DESTINATION_SQL_DBNAME
49 |
50 |
51 | CREATE TABLE #SOURCEDB_INDEX (
52 | DB nvarchar(100),
53 | TableName nvarchar(500),
54 | IndexName varchar(300),
55 | Type varchar(100)
56 | )
57 | CREATE TABLE #DESTINATIONDB_INDEX (
58 | DB nvarchar(100),
59 | TableName nvarchar(500),
60 | IndexName varchar(300),
61 | Type varchar(100)
62 | )
63 |
64 |
65 |
66 | DECLARE dbcursor CURSOR FOR
67 | SELECT
68 | dbname
69 | FROM @SOURCE_DATABASENAME
70 |
71 | OPEN dbcursor
72 | DECLARE @Source_DBname varchar(100)
73 | FETCH NEXT FROM dbcursor INTO @Source_DBNAME
74 | WHILE @@FETCH_STATUS = 0
75 | BEGIN
76 |
77 | DECLARE @SOURCE_SQL nvarchar(max)
78 |
79 | SELECT
80 | @SOURCE_SQL ='
81 | insert into #SOURCEDB_INDEX SELECT ' + '''' + @Source_DBname + '''' + ',
82 | so.name AS TableName,
83 | si.name AS IndexName,
84 | si.type_desc AS IndexType
85 | FROM ' + @SOURCEDBSERVER + '.' + @Source_DBname + '.sys.indexes si
86 | JOIN ' + @SOURCEDBSERVER + '.' + @Source_DBname + '.sys.objects so
87 | ON si.[object_id] = so.[object_id]
88 | WHERE
89 | so.type = ' + '''U''' + '
90 | AND si.name IS NOT NULL ORDER BY
91 | so.name, si.type
92 | '
93 |
94 |
95 | EXEC sp_executesql @SOURCE_SQL
96 | FETCH NEXT FROM dbcursor INTO @Source_DBname
97 | END
98 |
99 | CLOSE dbcursor
100 |
101 | DEALLOCATE dbcursor
102 |
103 |
104 |
105 |
106 |
107 | DECLARE dbcursor CURSOR FOR
108 | SELECT
109 | dbname
110 | FROM @DESTINATION_DATABASENAME
111 |
112 | OPEN dbcursor
113 | DECLARE @DESTINATION_DBname varchar(100)
114 | FETCH NEXT FROM dbcursor INTO @DESTINATION_DBNAME
115 | WHILE @@FETCH_STATUS = 0
116 | BEGIN
117 |
118 | DECLARE @DESTINATION_SQL nvarchar(max)
119 |
120 | SELECT
121 | @DESTINATION_SQL ='
122 | insert into #DESTINATIONDB_INDEX SELECT ' + '''' + @DESTINATION_DBname + '''' + ',
123 | so.name AS TableName,
124 | si.name AS IndexName,
125 | si.type_desc AS IndexType
126 | FROM ' + @DESTINATIONDBSERVER + '.' + @DESTINATION_DBname + '.sys.indexes si
127 | JOIN ' + @DESTINATIONDBSERVER + '.' + @DESTINATION_DBname + '.sys.objects so
128 | ON si.[object_id] = so.[object_id]
129 | WHERE
130 | so.type = ' + '''U''' + '
131 | AND si.name IS NOT NULL ORDER BY
132 | so.name, si.type '
133 |
134 |
135 | EXEC sp_executesql @DESTINATION_SQL
136 | FETCH NEXT FROM dbcursor INTO @DESTINATION_DBname
137 | END
138 |
139 | CLOSE dbcursor
140 |
141 | DEALLOCATE dbcursor
142 |
143 |
144 | ;
145 | WITH cte
146 | AS (SELECT
147 | DB,
148 | TableName,
149 | IndexName,
150 | HASHBYTES('sha1', concat(DB, TableName, IndexName)) AS tb1
151 | FROM #SOURCEDB_INDEX)
152 | SELECT
153 | ISNULL(c.DB, b.DB) AS DB,
154 | ISNULL(c.TableName, b.TableName) AS TableName,
155 | ISNULL(c.IndexName, b.IndexName) AS IndexName,
156 | CASE
157 | WHEN c.tb1 IS NULL THEN 'Available On ' + @DESTINATIONDBSERVER + ' Only'
158 | WHEN c.tb1 IS NOT NULL AND
159 | b.tb1 IS NOT NULL THEN 'Available On Both Servers'
160 | WHEN b.tb1 IS NULL THEN 'Available On ' + @SOURCEDBSERVER + ' Only'
161 | END AS 'Status'
162 | FROM cte c
163 | FULL JOIN (SELECT
164 | DB,
165 | TableName,
166 | IndexName,
167 | HASHBYTES('sha1', concat(DB, TableName, IndexName)) AS tb1
168 | FROM #DESTINATIONDB_INDEX) b
169 | ON b.tb1 = c.tb1
170 | ORDER BY tablename
171 |
172 | DROP TABLE #SOURCEDB_INDEX
173 | DROP TABLE #DESTINATIONDB_INDEX
--------------------------------------------------------------------------------
/SQLCompare/TsqlTools-SQLcompare-ObjectsCompare.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************
2 | -----------------------
3 | tsqltools - SQLCOMPARE - Objects Compare
4 | -----------------------
5 | Version: v1.0
6 | Release Date: 2017-07-30
7 | Author: Bhuvanesh(@SQLadmin)
8 | Feedback: mailto:r.bhuvanesh@outlook.com
9 | Updates: http://medium.com/sqladmin
10 | Repo: https://github.com/SqlAdmin/tsqltools/
11 | License:
12 | tsqltools is free to download.It contains Tsql stored procedures
13 | and scripts to help the DBAs and Developers to make their job easier
14 | (C) 2017
15 |
16 |
17 | ======================================================================
18 |
19 | What is TsqlTools-SQLcompare?
20 |
21 | TsqlTools-SQLcompare is a tsqlscript that will help to compare Databases,
22 | Tables, Objects, Indexices between two servers without any tools.
23 |
24 | ======================================================================
25 | How to Start?
26 |
27 | Use a centalized server and create LinkedServers from the centralized server.
28 | Or Create LinkedServer on SourceDB server then run this query on SourceDB server.
29 |
30 | ========================================================================*/
31 | DECLARE @SOURCEDBSERVER VARCHAR(100)
32 | DECLARE @DESTINATIONDBSERVER VARCHAR(100)
33 | DECLARE @SOURCE_SQL_DBNAME NVARCHAR(300)
34 | DECLARE @SOURCE_DATABASENAME TABLE
35 | (
36 | dbname VARCHAR(100)
37 | )
38 |
39 | SELECT @SOURCEDBSERVER = '[db01]' --==> Replace Your Source DB serverName Here
40 |
41 | SELECT @DESTINATIONDBSERVER = '[db02]' --==> Replace Your Target DB serverName Here
42 |
43 | SELECT @SOURCE_SQL_DBNAME = 'select name from ' + @SOURCEDBSERVER
44 | + '.master.sys.databases where database_id>4'
45 |
46 | INSERT INTO @SOURCE_DATABASENAME
47 | EXEC Sp_executesql
48 | @SOURCE_SQL_DBNAME
49 |
50 | CREATE TABLE #objectstaus
51 | (
52 | dbname NVARCHAR(500)
53 | , objectname NVARCHAR(500)
54 | , objecttype VARCHAR(500)
55 | , status NVARCHAR(500)
56 | )
57 |
58 | DECLARE dbcursor CURSOR FOR
59 | SELECT dbname
60 | FROM @SOURCE_DATABASENAME
61 |
62 | OPEN dbcursor
63 |
64 | DECLARE @SOURCE_DBNAME VARCHAR(100)
65 |
66 | FETCH next FROM dbcursor INTO @SOURCE_DBNAME
67 |
68 | WHILE @@FETCH_STATUS = 0
69 | BEGIN
70 | DECLARE @SOURCEDBSERVERNAME SYSNAME
71 | DECLARE @DESTDBNAME SYSNAME
72 | DECLARE @SQL VARCHAR(max)
73 |
74 | SELECT @SOURCEDBSERVERNAME = (SELECT
75 | @SOURCEDBSERVER + '.' + @SOURCE_DBNAME)
76 |
77 | SELECT @DESTDBNAME = @DESTINATIONDBSERVER + '.' + @SOURCE_DBNAME
78 |
79 | SELECT @SQL = ' SELECT ' + '''' + @SOURCE_DBNAME + '''' + ' as DB,
80 | ISNULL(SoSource.name,SoDestination.name) ''Object Name'' , SoDestination.type_desc ,
81 | CASE
82 | WHEN SoSource.object_id IS NULL THEN + '' Available on ' + @DESTDBNAME + ''' COLLATE database_default
83 | WHEN SoDestination.object_id IS NULL THEN + '' Available On ' + @SOURCEDBSERVERNAME + ''' COLLATE database_default
84 | ELSE
85 | + '' Available On Both Servers'' COLLATE database_default END ''Status''
86 | FROM (SELECT * FROM '
87 | + @SOURCEDBSERVERNAME
88 | + '.SYS.objects WHERE Type_desc not in (''INTERNAL_TABLE'',''SYSTEM_TABLE'',''SERVICE_QUEUE'')) SoSource
89 | FULL OUTER JOIN (SELECT * FROM ' + @DESTDBNAME
90 | + '.SYS.objects
91 | WHERE Type_desc not in (''INTERNAL_TABLE'',''SYSTEM_TABLE'',''SERVICE_QUEUE''))
92 | SoDestination ON SoSource.name = SoDestination.name COLLATE database_default
93 | AND SoSource.type = SoDestination.type
94 | COLLATE database_default
95 | ORDER BY isnull(SoSource.type,SoDestination.type)'
96 |
97 | INSERT INTO #objectstaus
98 | EXEC (@SQL)
99 |
100 | FETCH next FROM dbcursor INTO @SOURCE_DBNAME
101 | END
102 |
103 | CLOSE dbcursor
104 |
105 | DEALLOCATE dbcursor
106 |
107 | SELECT *
108 | FROM #objectstaus where objecttype='USER_TABLE'
109 | ORDER BY dbname ASC
110 |
111 | SELECT *
112 | FROM #objectstaus where objecttype='CHECK_CONSTRAINT'
113 | ORDER BY dbname ASC
114 |
115 | SELECT *
116 | FROM #objectstaus where objecttype='DEFAULT_CONSTRAINT'
117 | ORDER BY dbname ASC
118 |
119 | SELECT *
120 | FROM #objectstaus where objecttype='FOREIGN_KEY_CONSTRAINT'
121 | ORDER BY dbname ASC
122 |
123 | SELECT *
124 | FROM #objectstaus where objecttype='PRIMARY_KEY_CONSTRAINT'
125 | ORDER BY dbname ASC
126 |
127 | SELECT *
128 | FROM #objectstaus where objecttype='UNIQUE_CONSTRAINT'
129 | ORDER BY dbname ASC
130 |
131 | SELECT *
132 | FROM #objectstaus where objecttype='SQL_TRIGGER'
133 | ORDER BY dbname ASC
134 |
135 | SELECT *
136 | FROM #objectstaus where objecttype='VIEW'
137 | ORDER BY dbname ASC
138 |
139 | SELECT *
140 | FROM #objectstaus where objecttype='SQL_STORED_PROCEDURE'
141 | ORDER BY dbname ASC
142 |
143 | SELECT *
144 | FROM #objectstaus where objecttype not in ('USER_TABLE',
145 | 'CHECK_CONSTRAINT',
146 | 'DEFAULT_CONSTRAINT',
147 | 'FOREIGN_KEY_CONSTRAINT',
148 | 'PRIMARY_KEY_CONSTRAINT',
149 | 'SQL_TRIGGER',
150 | 'VIEW',
151 | 'SQL_STORED_PROCEDURE'
152 | 'UNIQUE_CONSTRAINT')
153 | ORDER BY dbname ASC
154 | DROP TABLE #objectstaus
155 |
156 |
157 |
158 |
159 |
160 |
161 |
162 |
163 |
--------------------------------------------------------------------------------
/SQLCompare/TsqlTools-SQLcompare-RowsCompare.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************
2 | -----------------------
3 | tsqltools - SQLCOMPARE - Rows Compare
4 | -----------------------
5 | Version: v1.0
6 | Release Date: 2017-07-30
7 | Author: Bhuvanesh(@SQLadmin)
8 | Feedback: mailto:r.bhuvanesh@outlook.com
9 | Updates: http://medium.com/sqladmin
10 | Repo: https://github.com/SqlAdmin/tsqltools/
11 | License:
12 | tsqltools is free to download.It contains Tsql stored procedures
13 | and scripts to help the DBAs and Developers to make their job easier
14 | (C) 2017
15 |
16 |
17 | ======================================================================
18 |
19 | What is TsqlTools-SQLcompare?
20 |
21 | TsqlTools-SQLcompare is a tsqlscript that will help to compare Databases,
22 | Tables, Objects, Indexices between two servers without any tools.
23 |
24 | ======================================================================
25 | How to Start?
26 |
27 | Use a centalized server and create LinkedServers from the centralized server.
28 | Or Create LinkedServer on SourceDB server then run this query on SourceDB server.
29 |
30 | ========================================================================*/
31 | DECLARE @SOURCEDBSERVER varchar(100)
32 | DECLARE @DESTINATIONDBSERVER varchar(100)
33 | DECLARE @SOURCE_SQL_DBNAME nvarchar(300)
34 | DECLARE @SOURCE_DATABASENAME TABLE ( dbname varchar(100))
35 | DECLARE @DESTINATION_SQL_DBNAME nvarchar(300)
36 | DECLARE @DESTINATION_DATABASENAME TABLE ( dbname varchar(100))
37 |
38 | SELECT @SOURCEDBSERVER = '[db01]' --==> Replace Your Source DB serverName Here
39 |
40 | SELECT @DESTINATIONDBSERVER = '[db02]' --==> Replace Your Target DB serverName Here
41 |
42 | Create table #sourceTbl (DBname nvarchar(200),TableName nvarchar(200),Rows bigint)
43 | Create table #DestTbl (DBname nvarchar(200),TableName nvarchar(200),Rows bigint)
44 |
45 | SELECT @SOURCE_SQL_DBNAME = 'select name from ' + @SOURCEDBSERVER + '.master.sys.databases where database_id>4'
46 | INSERT INTO @SOURCE_DATABASENAME EXEC sp_executesql @SOURCE_SQL_DBNAME
47 |
48 | SELECT @DESTINATION_SQL_DBNAME = 'select name from ' + @DESTINATIONDBSERVER + '.master.sys.databases where database_id>4'
49 | INSERT INTO @DESTINATION_DATABASENAME EXEC sp_executesql @DESTINATION_SQL_DBNAME
50 |
51 | DECLARE dbcursor CURSOR FOR
52 | SELECT dbname FROM @SOURCE_DATABASENAME
53 | OPEN dbcursor
54 | DECLARE @Source_DBname varchar(100)
55 | FETCH NEXT FROM dbcursor INTO @Source_DBNAME
56 | WHILE @@FETCH_STATUS = 0
57 |
58 | BEGIN
59 |
60 | DECLARE @SOURCE_SQL nvarchar(max)
61 |
62 | SELECT
63 | @SOURCE_SQL =
64 |
65 | ' SELECT '+''''+@Source_DBNAME+''''+' as DBname, sc.name +'+''''+'.'+''''+'+ ta.name TableName
66 | ,SUM(pa.rows) RowCnt
67 | FROM '+@SOURCEDBSERVER+'.'+@Source_DBNAME+'.sys.tables ta
68 | INNER JOIN '+@SOURCEDBSERVER+'.'+@Source_DBNAME+'.sys.partitions pa
69 | ON pa.OBJECT_ID = ta.OBJECT_ID
70 | INNER JOIN '+@SOURCEDBSERVER+'.'+@Source_DBNAME+'.sys.schemas sc
71 | ON ta.schema_id = sc.schema_id
72 | WHERE ta.is_ms_shipped = 0 AND pa.index_id IN (1,0)
73 | GROUP BY sc.name,ta.name
74 | ORDER BY SUM(pa.rows) DESC'
75 |
76 |
77 | insert into #sourceTbl EXEC sp_executesql @SOURCE_SQL
78 | FETCH NEXT FROM dbcursor INTO @Source_DBname
79 | END
80 |
81 | CLOSE dbcursor
82 |
83 | DEALLOCATE dbcursor
84 |
85 |
86 | DECLARE dbcursor CURSOR FOR
87 | SELECT
88 | dbname
89 | FROM @DESTINATION_DATABASENAME
90 |
91 | OPEN dbcursor
92 | DECLARE @DESTINATION_DBname varchar(100)
93 | FETCH NEXT FROM dbcursor INTO @DESTINATION_DBNAME
94 | WHILE @@FETCH_STATUS = 0
95 | BEGIN
96 |
97 | DECLARE @DESTINATION_SQL nvarchar(max)
98 |
99 | SELECT
100 | @DESTINATION_SQL =
101 | ' SELECT '+''''+@DESTINATION_DBNAME+''''+' as DBname,sc.name +'+''''+'.'+''''+'+ ta.name TableName
102 | ,SUM(pa.rows) RowCnt
103 | FROM '+@DESTINATIONDBSERVER+'.'+@DESTINATION_DBNAME+'.sys.tables ta
104 | INNER JOIN '+@DESTINATIONDBSERVER+'.'+@DESTINATION_DBNAME+'.sys.partitions pa
105 | ON pa.OBJECT_ID = ta.OBJECT_ID
106 | INNER JOIN '+@DESTINATIONDBSERVER+'.'+@DESTINATION_DBNAME+'.sys.schemas sc
107 | ON ta.schema_id = sc.schema_id
108 | WHERE ta.is_ms_shipped = 0 AND pa.index_id IN (1,0)
109 | GROUP BY sc.name,ta.name
110 | ORDER BY SUM(pa.rows) DESC'
111 |
112 |
113 | insert into #DestTbl EXEC sp_executesql @DESTINATION_SQL
114 | FETCH NEXT FROM dbcursor INTO @DESTINATION_DBname
115 | END
116 |
117 | CLOSE dbcursor
118 |
119 | DEALLOCATE dbcursor
120 |
121 | select a.DBname,a.TableName,(b.Rows-a.rows) as RowsDifference,
122 | case
123 | when(b.Rows-a.rows) >=100 then 'Alert'
124 | when(b.Rows-a.rows) <100 then 'OK' End as Status
125 | from #sourceTbl a,#DestTbl b where a.DBname=b.DBname and a.TableName=b.TableName
126 | drop table #sourceTbl
127 | drop table #DestTbl
128 |
129 |
--------------------------------------------------------------------------------
/Security Audit/tsqltools_AllInOneSecurityAudit.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************
2 | -------------------------------------
3 | tsqltools - All In One Security Audit
4 | -------------------------------------
5 |
6 | Version: v1.0
7 | Release Date: 2017-06-02
8 | Author: Bhuvanesh(@SQLadmin)
9 | Feedback: mailto:r.bhuvanesh@outlook.com
10 | Updates: https://github.com/SqlAdmin/tsqltools/
11 |
12 | License:
13 | tsqltools is free to download.It contains Tsql stored procedures
14 | and scripts to help the DBAs and Developers to make job easier
15 | (C) 2017
16 |
17 | *******************************************************************/
18 | /*
19 | Checks:
20 | -------
21 | 1. SQL services account - All sql services must run under an AD account or Administrator account
22 | 2. Default directories - Data,Log and backup directories must not be in C:\ drive
23 | 3. Startup Type - SQL serices should be start automatically
24 | 4. SA Account name - Its a best practice to rename SA account
25 | 5. Disable SA account - Create an alternate SQL user with SYSADMIN priileges and disable SA account
26 | 6. Password Check - Change SQL users password at every 3 months,
27 | Don't make Username and password is same,
28 | Don't user blank passwords
29 | 7. SysAdmin User - List of users who have sysadmin role.
30 | 8. SQL Port Type - SQL is using Static Port or Dynamic Port
31 | 9. SQL Port - Use any port other than 1433.
32 | 10. Number of databases - Use 100 or < 100 databases for a server.
33 | 11. Buildin Administrator - Disables Buildin\Administrator group from sql login.
34 | 12. Database level Access - Limit the db_owner users.
35 | */
36 |
37 |
38 | IF OBJECT_ID('tempdb.dbo.#Result', 'U') IS NOT NULL
39 | DROP TABLE #result
40 |
41 | CREATE TABLE #result (
42 | CHECKS nvarchar(500),
43 | RECOMMENTATION nvarchar(500)
44 | )
45 |
46 | IF OBJECT_ID('tempdb.dbo.#ServiceAccount', 'U') IS NOT NULL
47 | DROP TABLE #serviceaccount
48 |
49 | CREATE TABLE #serviceaccount (
50 | servicename varchar(100),
51 | serviceaccount varchar(100)
52 | )
53 |
54 | INSERT INTO #serviceaccount
55 | SELECT
56 | servicename,
57 | service_account
58 | FROM sys.dm_server_services;
59 |
60 | --select * from #ServiceAccount
61 | INSERT INTO #result
62 | SELECT
63 | Concat('Service Account - ', servicename),
64 | CASE
65 | WHEN serviceaccount like 'NT%' or serviceaccount like 'Local%' THEN 'Try to change an AD account or Administrator Account'
66 | ELSE 'OK'
67 | END AS Recommendation
68 | FROM #serviceaccount
69 |
70 | IF OBJECT_ID('tempdb.dbo.#DataDirectory', 'U') IS NOT NULL
71 | DROP TABLE #datadirectory
72 |
73 | CREATE TABLE #datadirectory (
74 | directorytype varchar(500),
75 | defaultdirectory nvarchar(500)
76 | )
77 |
78 | DECLARE @DefaultBackup nvarchar(512)
79 |
80 | EXEC master.dbo.Xp_instance_regread N'HKEY_LOCAL_MACHINE',
81 | N'Software\Microsoft\MSSQLServer\MSSQLServer',
82 | N'BackupDirectory',
83 | @DefaultBackup OUTPUT
84 |
85 | INSERT INTO #datadirectory
86 | SELECT
87 | 'Data',
88 | CONVERT(nvarchar(500), SERVERPROPERTY('INSTANCEDEFAULTDATAPATH'))
89 |
90 | INSERT INTO #datadirectory
91 | SELECT
92 | 'Log',
93 | CONVERT(nvarchar(500), SERVERPROPERTY('INSTANCEDEFAULTLOGPATH'))
94 |
95 | INSERT INTO #datadirectory
96 | SELECT
97 | 'Backup',
98 | @DefaultBackup
99 |
100 | --select * from #DataDirectory
101 | INSERT INTO #result
102 | SELECT
103 | Concat('Default Directory - ', directorytype),
104 | CASE
105 | WHEN defaultdirectory LIKE 'C:\%' THEN 'Please Avoid to keep Data files in C: drive'
106 | ELSE 'OK'
107 | END AS Recommendation
108 | FROM #datadirectory
109 |
110 | IF OBJECT_ID('tempdb.dbo.#StartupType', 'U') IS NOT NULL
111 | begin DROP TABLE #startuptype end
112 |
113 | CREATE TABLE #startuptype (
114 | sqlservice varchar(50),
115 | startuptype nvarchar(50)
116 | )
117 |
118 | INSERT INTO #startuptype
119 | SELECT
120 | servicename,
121 | startup_type_desc
122 | FROM sys.dm_server_services;
123 |
124 | --select * from #StartupType
125 | INSERT INTO #result
126 | SELECT
127 | Concat('Startup Type - ', sqlservice),
128 | CASE
129 | WHEN startuptype LIKE 'Manual' THEN 'Make this startup type as Automatic'
130 | ELSE 'OK'
131 | END AS Recommendation
132 | FROM #startuptype
133 |
134 | IF OBJECT_ID('tempdb.dbo.#saname', 'U') IS NOT NULL
135 | DROP TABLE #saname
136 |
137 | CREATE TABLE #saname (
138 | NAME varchar(20)
139 | )
140 |
141 | INSERT INTO #saname
142 | SELECT
143 | NAME
144 | FROM sys.sql_logins
145 | WHERE sid = 0x01;
146 |
147 | INSERT INTO #result
148 | SELECT
149 | Concat('SA account name - ', NAME),
150 | CASE
151 | WHEN NAME = 'sa' THEN 'Rename SA account to someother name'
152 | ELSE 'OK'
153 | END AS Recomendation
154 | FROM #saname
155 |
156 | IF OBJECT_ID('tempdb.dbo.#saaccountstatus', 'U') IS NOT NULL
157 | DROP TABLE #saaccountstatus
158 |
159 | CREATE TABLE #saaccountstatus (
160 | NAME varchar(10),
161 | status int
162 | )
163 |
164 | INSERT INTO #saaccountstatus
165 | SELECT
166 | NAME,
167 | is_disabled
168 | FROM sys.server_principals
169 | WHERE NAME = 'sa'
170 |
171 | INSERT INTO #result
172 | SELECT
173 | 'SA Account Status',
174 | CASE
175 | WHEN status = 1 THEN 'OK'
176 | ELSE 'Its a best practice to disable SA account or rename it'
177 | END AS Recomendation
178 | FROM #saaccountstatus
179 |
180 | IF OBJECT_ID('tempdb.dbo.#PasswordCheck', 'U') IS NOT NULL
181 | DROP TABLE #passwordcheck
182 |
183 | CREATE TABLE #passwordcheck (
184 | passwordtype varchar(20),
185 | logins varchar(50)
186 | )
187 |
188 | INSERT INTO #passwordcheck
189 | SELECT
190 | 'Name = Password',
191 | NAME
192 | FROM sys.sql_logins
193 | WHERE Pwdcompare(NAME, password_hash) = 1;
194 |
195 | INSERT INTO #passwordcheck
196 | SELECT
197 | 'Blank Password',
198 | NAME
199 | FROM sys.sql_logins
200 | WHERE Pwdcompare('', password_hash) = 1;
201 |
202 | --select * from #PasswordCheck
203 | DECLARE @lastPassword TABLE (
204 | date date,
205 | logins varchar(100)
206 | )
207 |
208 | INSERT INTO @lastPassword
209 | SELECT
210 | CONVERT(date, LOGINPROPERTY([name], 'PasswordLastSetTime')) AS
211 | 'PasswordChanged',
212 | NAME
213 | FROM sys.sql_logins
214 | WHERE NOT (LEFT([name], 2) = '##'
215 | AND RIGHT([name], 2) = '##')
216 | ORDER BY CONVERT(date, LOGINPROPERTY([name], 'PasswordLastSetTime'))
217 |
218 | INSERT INTO #passwordcheck
219 | SELECT
220 | Concat(DATEDIFF(DAY, date, (SELECT
221 | CAST(GETDATE() AS date))
222 | ), ' Days Ago'
223 | ) AS
224 | LastUpdated,
225 | logins
226 | FROM @lastPassword
227 |
228 | INSERT INTO #result
229 | SELECT
230 | Concat('Password Check - ', logins),
231 | CASE
232 | WHEN passwordtype = 'Name = Password' THEN 'User Name and password is same'
233 | WHEN passwordtype = 'Blank Password' THEN 'Blank Password'
234 | WHEN passwordtype LIKE '%Days Ago%' THEN 'Password updated before 90Days Ago'
235 | ELSE 'OK'
236 | END
237 | FROM #passwordcheck
238 |
239 | IF OBJECT_ID('tempdb.dbo.#sysadminusers', 'U') IS NOT NULL
240 | DROP TABLE #sysadminusers
241 |
242 | CREATE TABLE #sysadminusers (
243 | logins varchar(50)
244 | )
245 |
246 | INSERT INTO #sysadminusers
247 | SELECT
248 | NAME
249 | FROM master.sys.server_principals
250 | WHERE IS_SRVROLEMEMBER('sysadmin', NAME) = 1
251 | ORDER BY NAME
252 |
253 | INSERT INTO #result
254 | SELECT
255 | Concat('Admin User - ', logins),
256 | 'This user has SysAdmin role' AS Recomentation
257 | FROM #sysadminusers
258 |
259 | IF OBJECT_ID('tempdb.dbo.#sqlport', 'U') IS NOT NULL
260 | DROP TABLE #sqlport
261 |
262 | CREATE TABLE #sqlport (
263 | porttype varchar(20),
264 | portnumber int
265 | )
266 |
267 | DECLARE @portNo nvarchar(10)
268 |
269 | EXEC Xp_instance_regread @rootkey = 'HKEY_LOCAL_MACHINE',
270 | @key =
271 | 'Software\Microsoft\Microsoft SQL Server\MSSQLServer\SuperSocketNetLib\Tcp\IpAll',
272 | @value_name = 'TcpDynamicPorts',
273 | @value = @portNo OUTPUT
274 |
275 | INSERT INTO #sqlport
276 | SELECT
277 | 'Dynamic Port',
278 | @portNo
279 |
280 | GO
281 |
282 | DECLARE @portNo nvarchar(10)
283 |
284 | EXEC Xp_instance_regread @rootkey = 'HKEY_LOCAL_MACHINE',
285 | @key =
286 | 'Software\Microsoft\Microsoft SQL Server\MSSQLServer\SuperSocketNetLib\Tcp\IpAll',
287 | @value_name = 'TcpPort',
288 | @value = @portNo OUTPUT
289 |
290 | INSERT INTO #sqlport
291 | SELECT
292 | 'Static Port',
293 | @portNo
294 |
295 | --select * from #sqlport
296 | INSERT INTO #result
297 | SELECT
298 | Concat('SQL Port - ', porttype),
299 | portnumber
300 | FROM #sqlport
301 | WHERE portnumber IS NOT NULL
302 |
303 | INSERT INTO #result
304 | SELECT
305 | Concat('SQL Port Number ', portnumber),
306 | CASE
307 | WHEN portnumber = 1433 THEN 'Please change Default port Number for SQL Server'
308 | WHEN portnumber != 1433 THEN 'OK'
309 | END
310 | FROM #sqlport
311 | WHERE portnumber IS NOT NULL
312 |
313 | IF OBJECT_ID('tempdb.dbo.#numberofdb', 'U') IS NOT NULL
314 | DROP TABLE #numberofdb
315 |
316 | CREATE TABLE #numberofdb (
317 | count int
318 | )
319 |
320 | INSERT INTO #numberofdb
321 | SELECT
322 | COUNT(*)
323 | FROM sys.databases
324 |
325 | INSERT INTO #result
326 | SELECT
327 | Concat('Number of DB - ', count),
328 | CASE
329 | WHEN count > 100 THEN 'Please remove unwanted Databases'
330 | ELSE 'OK'
331 | END
332 | FROM #numberofdb
333 |
334 | IF OBJECT_ID('tempdb.dbo.#buildinadmin', 'U') IS NOT NULL
335 | DROP TABLE #buildinadmin
336 |
337 | CREATE TABLE #buildinadmin (
338 | login sysname,
339 | status smallint
340 | )
341 |
342 | INSERT INTO #buildinadmin
343 | SELECT
344 | NAME,
345 | status
346 | FROM sys.syslogins
347 | WHERE NAME = 'BUILTIN\Administrators'
348 |
349 | IF EXISTS (SELECT
350 | *
351 | FROM #buildinadmin
352 | WHERE status = 9)
353 | INSERT INTO #result
354 | SELECT
355 | 'Is Buildin AdminGroup enabled',
356 | CASE
357 | WHEN status = '9' THEN 'Please remove BUILTIN\Administrators login'
358 | END
359 | FROM #buildinadmin
360 | ELSE
361 | INSERT INTO #result
362 | SELECT
363 | 'Is Buildin AdminGroup enabled',
364 | 'OK'
365 | Insert into #result
366 | values
367 | ('For More Updates','https://github.com/SqlAdmin/tsqltools/')
368 | SELECT
369 | *
370 | FROM #result
371 |
372 | -------------------------------
373 | -- Database Level Privileges --
374 | -------------------------------
375 | DECLARE @DB_USers TABLE (
376 | DBName sysname,
377 | UserName sysname,
378 | LoginType sysname,
379 | AssociatedRole varchar(max),
380 | create_date datetime,
381 | modify_date datetime
382 | )
383 |
384 | INSERT @DB_USers
385 | EXEC sp_MSforeachdb '
386 | use [?]
387 | SELECT ''?'' AS DB_Name,
388 | case prin.name when ''dbo'' then prin.name + '' (''+ (select SUSER_SNAME(owner_sid) from master.sys.databases where name =''?'') + '')'' else prin.name end AS UserName,
389 | prin.type_desc AS LoginType,
390 | isnull(USER_NAME(mem.role_principal_id),'''') AS AssociatedRole ,create_date,modify_date
391 | FROM sys.database_principals prin
392 | LEFT OUTER JOIN sys.database_role_members mem ON prin.principal_id=mem.member_principal_id
393 | WHERE prin.sid IS NOT NULL and prin.sid NOT IN (0x00) and
394 | prin.is_fixed_role <> 1 AND prin.name NOT LIKE ''##%'''
395 |
396 | SELECT
397 |
398 | DBname,
399 | UserName,
400 | LoginType,
401 | create_date as CreateDate,
402 | modify_date as ModifiedDate,
403 |
404 | STUFF((SELECT
405 | ',' + CONVERT(varchar(500), associatedrole)
406 |
407 | FROM @DB_USers user2
408 |
409 | WHERE user1.DBName = user2.DBName
410 | AND user1.UserName = user2.UserName
411 |
412 | FOR xml PATH ('')), 1, 1, '') AS PermissionUser
413 |
414 | FROM @DB_USers user1
415 |
416 | GROUP BY dbname,
417 | username,
418 | logintype,
419 | create_date,
420 | modify_date
421 |
422 | ORDER BY DBName, username
423 |
--------------------------------------------------------------------------------
/_config.yml:
--------------------------------------------------------------------------------
1 | theme: jekyll-theme-minimal
--------------------------------------------------------------------------------