forked from jehama/MSSQL-audit-scripts
-
Notifications
You must be signed in to change notification settings - Fork 2
/
MSSQL_Audit_Script.ps1
2559 lines (2310 loc) · 127 KB
/
MSSQL_Audit_Script.ps1
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
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
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
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
<#
.SYNOPSIS
Audits the MSSQL Server against the CIS-benchmark, and looks at all users, roles and their rights.
.DESCRIPTION
This scripts checks the recommendations of the CIS-benchmark for MSSQL Server 2016 and MSSQL Server 2012 against the current configuration of the MSSQL Server.
It will also display the following information from the database:
* The databases on the MSSQL Server, the date and time they were created, and the number of users each database has..
* The logins and their corresponding database accounts.
* The roles that are defined, both on server and database level.
* The rights granted or denied to users and roles, both on server and database level.
.PARAMETER Server
Specifies the MSSQL Server to connect to.
.PARAMETER Database
Specifies the database to connect to.
This parameter is optional. If no database is selected it will default to auditing all available databases.
.PARAMETER WindowsAuthentication
Specifies to use Windows Authentication when connecting to the MSSQL Server.
.PARAMETER SQLAuthentication
Specifies to use SQL Authentication when connecting to the MSSQL Server.
.PARAMETER Username
Specifies the username to use when authenticating to the MSSQL Server.
This parameter is only used when authenticating with SQL Authentication.
.PARAMETER Include
Specifies which sections of the script to run.
This parameter is optional. If it is not used the default 'All' will be used.
Valid options are: 'All', 'CIS', 'STIG', 'UserManagement'.
.PARAMETER NoCsvOutput
Specifies whether to create CSV files or not. Default true.
.PARAMETER Version
Specifies which mssql server version the server is running,
e.g. 2012 = 12, 2016 = 16. Defaulting to the latest.
.INPUTS
None.
.OUTPUTS
The output is saved in a HTML file.
This file will be saved in the same folder the script is run from.
.EXAMPLE
.\MSSQL_Audit_Script.ps1 -Server "Servername" -WindowsAuthentication
.EXAMPLE
.\MSSQL_Audit_Script.ps1 -Server "Servername" -SQLAuthentication -Username "test"
.EXAMPLE
.\MSSQL_Audit_Script.ps1 -Server "Servername" -Database "DatabaseName" -WindowsAuthentication
.EXAMPLE
.\MSSQL_Audit_Script.ps1 -Server "Servername" -Include "CIS,UserManagement" -WindowsAuthentication
#>
[CmdletBinding()]
# This initializes the parameters which were present when the script was launched.
param(
# Specifies the MSSQL Server to connect to.
[parameter(ParameterSetName = "WindowsAuthentication", Mandatory = $true)]
[parameter(ParameterSetName = "SQLAuthentication", Mandatory = $true)]
[String]
$Server,
# Specifies the database to connect to.
# This parameter is optional. If no database is selected it will default to auditing all available databases.
[parameter(ParameterSetName = "WindowsAuthentication")]
[parameter(ParameterSetName = "SQLAuthentication")]
[String]
$Database,
# Specifies to use Windows Authentication when connecting to the MSSQL Server.
[parameter(ParameterSetName = "WindowsAuthentication", Mandatory = $true)]
[switch]
$WindowsAuthentication,
# Specifies to use SQL Authentication when connecting to the MSSQL Server.
[parameter(ParameterSetName = "SQLAuthentication", Mandatory = $true)]
[switch]
$SQLAuthentication,
# Specifies the username to use when authenticating to the MSSQL Server.
# This parameter is only used when authenticating with SQL Authentication.
[parameter(ParameterSetName = "SQLAuthentication", Mandatory = $true)]
[String]
$Username,
# Specifies the sections of the script to run.
# This parameter is optional. If it is not used every section will be run.
[parameter(ParameterSetName = "WindowsAuthentication")]
[parameter(ParameterSetName = "SQLAuthentication")]
[ValidateSet('All', 'CIS', 'STIG', 'UserManagement')]
[String[]]
$Include = 'All',
# Parameter help description
[parameter(ParameterSetName = "WindowsAuthentication")]
[parameter(ParameterSetName = "SQLAuthentication")]
[int]
$Version = 19,
# Specifies wether to create output CSVs.
# This parameter is optional. If it is not set it will be true..
[parameter(ParameterSetName = "WindowsAuthentication")]
[parameter(ParameterSetName = "SQLAuthentication")]
[switch]
$NoCsvOutput
)
function Startup {
<#
.SYNOPSIS
Method executed on startup.
.DESCRIPTION
This methods is called at the start of the program to verify it has started correctly.
It also makes any necessary preparations.
.EXAMPLE
Startup
#>
# This statement is used to signal the start of the script.
# It verifies that the script has started successfully.
[CmdletBinding()]
param()
Write-Host "#########################`nMSSQL audit tool`n#########################"
# A stopwatch is used to check how long a section of the script has needed to be completed.
# It is also used to check the total amount of time needed to complete the script.
$Script:Stopwatch = New-Object -TypeName System.Diagnostics.Stopwatch
$Script:TotalTime = $Script:Stopwatch.Elapsed
$Script:Stopwatch.Start()
# The password will not be visible while typing it in.
if ($SQLAuthentication) {
$SecurePassword = Read-Host -AsSecureString "Enter password"
$BSTR = [System.Runtime.InteropServices.Marshal]::SecureStringToBSTR($SecurePassword)
$Script:Password = [System.Runtime.InteropServices.Marshal]::PtrToStringAuto($BSTR)
}
$Script:StartTime = (Get-Date).ToString('MM-dd-yyyy-hh-mm')
mkdir $Script:StartTime
#Sets the output file. If the file already exists the user is prompted to override it or stop the script.
$Script:Outfile = ".\$($Script:StartTime)\audit-MSSQL-" + $Script:Server + ".html"
if (Test-Path -Path $Script:Outfile) {
Write-Host "The output file already exists, would you like to overwrite it?"
Remove-Item $Script:Outfile -Confirm
if (Test-Path -Path $Script:Outfile) {
Write-Host "Please move the output file: $Script:Outfile"
exit
}
}
HTMLPrinter -HTMLStart
Write-Host "Using $Script:Server as target server"
if ($Script:Database -ne "") {
Write-Host "Using $Script:Database as target database"
$Script:AllDatabases = $false
}
else {
Write-Host "There Currently no database selected."
Write-Host "Selecting database `"master`" for the connection string"
$Script:Database = "master"
$Script:AllDatabases = $true
}
HTMLPrinter -OpeningTag "<h1 id='Basic_information' class='headers header1'>" -Content "Basic information" -ClosingTag "</h1>"
HTMLPrinter -OpeningTag "<p>" -Content "Using $Script:Server as target server." -ClosingTag "</p>"
HTMLPrinter -OpeningTag "<p>" -Content "Using $Script:Database as target database." -ClosingTag "</p>"
$Script:OriginalDatabase = $Script:Database
SqlConnectionBuilder
try {
Write-Host "Testing Database connection."
$Script:SqlConnection.Open()
}
catch {
Write-Warning "Something went wrong while opening the connection."
exit 1
return
}
finally {
$Script:SqlConnection.Close()
}
CheckFullVersion
GenerateDatabasesInfo
Write-Host "Setup completed in: " $Script:Stopwatch.Elapsed
$Script:TotalTime += $Script:Stopwatch.Elapsed
Write-Host "Total time elapsed: " $Script:TotalTime
$Script:Stopwatch.Restart()
Main
HTMLPrinter -HTMLEnd
$Script:TotalTime += $Script:Stopwatch.Elapsed
Write-Host "Audit has finished, total time elapsed: " $Script:TotalTime
}
function Main {
<#
.SYNOPSIS
The main function.
.DESCRIPTION
The main function executes all methods.
.EXAMPLE
Main
#>
[CmdletBinding()]
param()
if ($Script:Include -eq 'All' -or $Script:Include -eq 'CIS') {
SecurityChecklists
Write-Host "CIS Microsoft SQL Server benchmark completed in:" $Script:Stopwatch.Elapsed
$Script:TotalTime += $Script:Stopwatch.Elapsed
Write-Host "Total time elapsed: " $Script:TotalTime
$Script:Stopwatch.Restart()
}
if ($Script:Include -eq 'All' -or $Script:Include -eq 'UserManagement') {
# Used to obtain all users and their rights.
UserManagement
Write-Host "User management completed in: " $Script:Stopwatch.Elapsed
$Script:TotalTime += $Script:Stopwatch.Elapsed
Write-Host "Total time elapsed: " $Script:TotalTime
$Script:Stopwatch.Restart()
}
}
function SqlConnectionBuilder {
<#
.SYNOPSIS
Builds and returns the SqlConnection object.
.DESCRIPTION
Creates a ConnectionString based on the global script variables $Script:Server and $Script:Database.
.EXAMPLE
SqlConnectionBuilder
#>
[CmdletBinding()]
# "Integrated Security = True" means that the connection uses windows authentication.
# The supplied credentials will be the credentials of owner of the powershell session.
$Script:SqlConnection = New-Object System.Data.SqlClient.SqlConnection
if ($WindowsAuthentication) {
$Script:SqlConnection.ConnectionString = "Server = $Script:Server; Database = $Script:Database; Integrated Security = True;"
}
if ($SQLAuthentication) {
$Script:SqlConnection.ConnectionString = "Server = $Script:Server; Database = $Script:Database; User Id = $Script:Username; Password = $Script:Password;"
}
}
function DataCollector {
<#
.SYNOPSIS
Collects data from the MSSQL instance.
.DESCRIPTION
Creates an SqlAdapter based on the SQL query and fills it with data.
This dataset is then returned.
.EXAMPLE
SqlAdapter $SqlQuery
#>
[CmdletBinding()]
[OutputType([System.Data.Dataset])]
param (
# The SQL query to run.
[parameter(Mandatory = $true)]
[String[]]
$SqlQuery,
[parameter()]
[String]
$AllTables
)
$SQLCommand = New-Object System.Data.SqlClient.SqlCommand
$SQLCommand.CommandText = $SqlQuery
$SQLCommand.Connection = $Script:SqlConnection
$SQLAdapter = New-Object System.Data.SqlClient.SqlDataAdapter
$SQLAdapter.SelectCommand = $SQLCommand
$Dataset = New-Object System.Data.DataSet
$SqlAdapter.Fill($Dataset) | Out-Null
if ($AllTables -eq "y") {
, $Dataset
}
else {
$DataTable = New-Object System.Data.DataTable
$DataTable = $Dataset.Tables[0]
, $DataTable
}
}
function CheckFullVersion {
<#
.SYNOPSIS
Check the full version of the MSSQL Server.
.DESCRIPTION
Checks and displays the full version info of the MSSQL server.
This includes the major version, service pack, build.
.EXAMPLE
CheckFullVersion
#>
[CmdletBinding()]
$SqlQuery = "SELECT
@@VERSION AS Version, SERVERPROPERTY('MachineName') as Hostname
;"
$Dataset = DataCollector $SqlQuery
HTMLPrinter -OpeningTag "<h3 id='Server_version' class='headers'>" -Content "Server version" -ClosingTag "</h3>"
HTMLPrinter -Table $Dataset -Columns @("Version", "Hostname")
CsvWriter 'GEN-Version' "Version, Hostname"
foreach ($Row in $Dataset) {
CsvWriter 'GEN-Version' "$([string]::join('',($Row.Version.Split("`r?`n")))), $($Row.Hostname)"
}
}
function GenerateDatabasesInfo {
<#
.SYNOPSIS
Generate list of databases.
.DESCRIPTION
Generates a list of databases on the server.
This list is used for queries that are used on every database on the server.
.EXAMPLE
GenerateDatabasesInfo
.NOTES
General notes
#>
[CmdletBinding()]
param ()
$SqlQuery = "SELECT
*
FROM
sys.databases AS DB
;"
$Script:DatabasesInfo = DataCollector $SqlQuery
$Script:DatabasesInfo.Columns.Add("number_of_users", "System.String") | Out-Null
$SqlQuery = "SELECT
COUNT(*) AS users
FROM
sys.database_principals AS DP
WHERE
DP.type IN (
'C',
'E',
'G',
'K',
'S',
'U',
'X'
)
;"
foreach ($db in $Script:DatabasesInfo) {
$Script:Database = $db.name
SqlConnectionBuilder
$Dataset = DataCollector $SqlQuery
$db.number_of_users = $Dataset.users
}
$Script:Database = $Script:OriginalDatabase
SqlConnectionBuilder
HTMLPrinter -OpeningTag "<h3 id='Databases' class='headers'>" -Content "Databases" -ClosingTag "</h3>"
HTMLPrinter -Table $Script:DatabasesInfo -Columns @("name", "create_date", "number_of_users")
CsvWriter 'GEN-Databases' "name,create_date,number_of_users"
foreach ($Row in $Script:DatabasesInfo) {
CsvWriter 'GEN-Databases' "$($Row.name),$($Row.create_date),$($Row.number_of_users)"
}
}
function CsvWriter {
param (
# The SQL query to run.
[parameter(Mandatory = $true)]
[String]
$FileName,
[parameter(Mandatory = $true)]
[String]
$Text
)
$FileName = ".\$($Script:StartTime)\audit-MSSQL-" + $Script:Server + "-" + $FileName + ".CSV"
if ($Script:NoCsvOutput) {
# Empty switch to prevent CSV writing when the NoCsvOutput argument is present.
}
else {
Add-Content $FileName $Text
}
}
function ConvertTo-SQLHashString {
<#
.SYNOPSIS
Converts SID back into the SID as seen in SSMS.
.DESCRIPTION
Converts SID back into the SID as seen in SSMS.
Since it automatically is converted to a binary, therefor powershell can't show the value properly.
.EXAMPLE
ConvertTo-SQLHashString $sid
.NOTES
General notes
#>
[CmdletBinding()]
[OutputType([String])]
param([parameter(Mandatory = $true)] $binhash)
$outstring = '0x'
$binhash | ForEach-Object { $outstring += ('{0:X}' -f $_).PadLeft(2, '0') }
return $outstring
}
function SecurityChecklists {
<#
.SYNOPSIS
Checks the MSSQL server against checklists available on the NIST NCP repository.
Currently these include:
* CIS Microsoft SQL Server 2012 (1.4.0)
* CIS Microsoft SQL Server 2016 (1.0.0)
* Microsoft SQL Server 2016 STIG (Ver 1, Rel 4)
.DESCRIPTION
When checking the MSSQL server it will use the different parameters provided at the startup of the script to determine the checks to run.
The options to test are currently CIS and STIG. It will use the latest implemented version based on version data of the server.
Since not every check from the checklists can be performed on PowerShell this list is not complete.
Checks that aren't supported will be noted so they can be checked manually.
The CIS benchmark recommendatons are assigned a scoring status:
Scored: Failure to comply with "Scored" recommendations will decrease the final fenchmark score.
Compliance with "Scored" recommendations will increase the final benchmark score.
Not Scored: Failure to comply with "Not Scored" recommendations will not decrease the final benchmark score.
Compliance with "Not Scored" recommendations will not increase the final benchmark score.
The STIG policies are assigned a Severity Category Code (CAT):
CAT I: Any vulnerability, the exploitation of which will directly and immediately result in loss of Confidentiality, Availability, or Integrity.
CAT II: Any vulnerability, the exploitation of which has a potential to result in loss of Confidentiality, Availability, or Integrity.
CAT III: Any vulnerability, the existence of which degrades measures to protect against loss of Confidentiality, Availability, or Integrity.
This method can check any combination of CIS benchmark and STIG CAT checks.
.EXAMPLE
SecurityChecklists
.NOTES
The SecurityChecklists function does not check every MSSQL checklist found in the NIST NCP repository.
It will only check MSSQL versions that are currently supported by Microsoft.
The following checks can be performed by this function:
CIS Microsoft SQL Server 2012 benchmark:
* Section 1.1 (Not Scored)
* Section 1.2 (Not Scored) (Manual)
* Section 2.1 (Scored)
* Section 2.2 (Scored)
* Section 2.3 (Scored)
* Section 2.4 (Scored)
* Section 2.5 (Scored)
* Section 2.6 (Scored)
* Section 2.7 (Scored)
* Section 2.8 (Scored)
* Section 2.9 (Scored)
* Section 2.10 (Not Scored) (Manual)
* Section 2.11 (Scored)
* Section 2.12 (Scored)
* Section 2.13 (Scored)
* Section 2.14 (Scored)
* Section 2.15 (Scored)
* Section 2.16 (Scored)
* Section 2.17 (Scored)
* Section 3.1 (Scored)
* Section 3.2 (Scored)
* Section 3.3 (Scored)
* Section 3.4 (Scored)
* Section 3.5 (Scored) (Manual) Can this be automated?
* Section 3.6 (Scored) (Manual) Can this be automated?
* Section 3.7 (Scored) (Manual) Can this be automated? Net user and such?
* Section 3.8 (Scored)
* Section 3.9 (Scored)
* Section 3.10 (Scored)
* Section 3.11 (Scored)
* Section 4.1 (Not Scored) (Manual)
* Section 4.2 (Scored)
* Section 4.3 (Scored)
* Section 5.1 (Scored)
* Section 5.2 (Scored)
* Section 5.3 (Scored)
* Section 5.4 (Scored)
* Section 6.1 (Not Scored) (Manual)
* Section 6.2 (Scored)
* Section 7.1 (Scored)
* Section 7.2 (Scored)
* Section 8.1 (Not Scored) (Manual)
CIS Microsoft SQL Server 2016 benchmark:
* Section 1.1 (Not Scored)
* Section 1.2 (Not Scored) (Manual)
* Section 2.1 (Scored)
* Section 2.2 (Scored)
* Section 2.3 (Scored)
* Section 2.4 (Scored)
* Section 2.5 (Scored)
* Section 2.6 (Scored)
* Section 2.7 (Scored)
* Section 2.8 (Scored)
* Section 2.9 (Scored)
* Section 2.10 (Not Scored) (Manual)
* Section 2.11 (Scored)
* Section 2.12 (Scored)
* Section 2.13 (Scored)
* Section 2.14 (Scored)
* Section 2.15 (Scored)
* Section 2.16 (Scored)
* Section 2.17 (Scored)
* Section 3.1 (Scored)
* Section 3.2 (Scored)
* Section 3.3 (Scored)
* Section 3.4 (Scored)
* Section 3.5 (Scored) (Manual)
* Section 3.6 (Scored) (Manual)
* Section 3.7 (Scored) (Manual)
* Section 3.8 (Scored)
* Section 3.9 (Scored)
* Section 3.10 (Scored)
* Section 3.11 (Scored)
* Section 4.1 (Not Scored) (Manual)
* Section 4.2 (Scored)
* Section 4.3 (Scored)
* Section 5.1 (Scored)
* Section 5.2 (Scored)
* Section 5.3 (Scored)
* Section 5.4 (Scored)
* Section 6.1 (Not Scored) (Manual)
* Section 6.2 (Scored)
* Section 7.1 (Scored)
* Section 7.2 (Scored)
* Section 8.1 (Not Scored) (Manual)
#>
HTMLPrinter -OpeningTag "<h1 id='CIS_benchmark' class='headers'>" -Content "CIS benchmark" -ClosingTag "</h1>"
# This query is based on CIS Microsoft SQL Server 2019 benchmark section 1.1.
# Checks the productlevel and productversion.
$SqlQuery = "SELECT
SERVERPROPERTY('ProductLevel') as SP_installed,
SERVERPROPERTY('ProductVersion') as Version,
SERVERPROPERTY('ProductUpdateLevel') as 'ProductUpdate_Level',
SERVERPROPERTY('ProductUpdateReference') as 'KB_Number';
;"
$Dataset = DataCollector $SqlQuery
HTMLPrinter -OpeningTag "<p>" -Content "The server contains the following Service Pack and Version. These can be found on microsofts website." -ClosingTag "</p>"
HTMLPrinter -OpeningTag "<p><h3>" -Content "1.1 Ensure Latest SQL Server Cumulative and Security Updates are Installed (Manual)" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check if these match the expected versions. Visit <a target='_blank' href='https://learn.microsoft.com/en-us/troubleshoot/sql/releases/download-and-install-latest-updates#latest-updates-available-for-currently-supported-versions-of-sql-server'> MSSQL Versions </a> for more details." -ClosingTag "</p>"
HTMLPrinter -Table $Dataset -Columns @("SP_installed", "Version", "ProductUpdate_Level", "KB_Number")
CsvWriter 'CIS-Version' "SP_installed,Version,ProductUpdate_Level,KB_Number"
foreach ($Row in $Dataset) {
CsvWriter 'CIS-Version' "$($Row.SP_installed),$($Row.Version),$($Row.ProductUpdate_Level),$($Row.KB_Number)"
}
# This query is based on CIS Microsoft SQL Server 2012 benchmark section 2.1.
# This query is based on CIS Microsoft SQL Server 2016 benchmark section 2.1.
# This query is based on CIS Microsoft SQL Server 2019 benchmark section 2.1.
# Checks if the option 'Ad Hoc Distributed Queries' is disabled.
$SqlQuery = "SELECT name AS name,
CAST(value AS int) AS value_configured,
CAST(value_in_use AS int) AS value_in_use
FROM
sys.configurations AS C
WHERE
C.name = 'Ad Hoc Distributed Queries'
;"
$Dataset = DataCollector $SqlQuery
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.1 Ensure 'Ad Hoc Distributed Queries' Server Configuration Option is set to '0' (Automated)" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check if 'Add Hoc Distributed Queries' is disabled (0)." -ClosingTag "</p>"
HTMLPrinter -Table $Dataset -Columns @("name", "value_configured", "value_in_use")
CsvWriter 'CIS-Compliance' "name,value_configured,value_in_use,expected,database"
foreach ($Row in $Dataset) {
CsvWriter 'CIS-Compliance' "$($Row.name),$($Row.value_configured),$($Row.value_in_use),0"
}
# This first query is based on CIS Microsoft SQL Server 2012 benchmark section 2.2.
# This first query is based on CIS Microsoft SQL Server 2016 benchmark section 2.2.
# This second query is based on CIS Microsoft SQL Server 2019 benchmark section 2.2 and 2.17.
# Checks if the option 'clr enabled' is disabled or 'clr strict security' is enabled for 2019..
$SqlQuery = ""
$SqlQuery = "SELECT name AS name,
CAST(value AS int) AS value_configured,
CAST(value_in_use AS int) AS value_in_use
FROM
sys.configurations AS C
WHERE
C.name = 'clr enabled'
;"
$Dataset = DataCollector $SqlQuery
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.2 Ensure 'CLR Enabled' Server Configuration Option is set to '0' (Automated)" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check if 'clr enabled' is disabled (0)." -ClosingTag "</p>"
HTMLPrinter -Table $Dataset -Columns @("name", "value_configured", "value_in_use")
foreach ($Row in $Dataset) {
CsvWriter 'CIS-Compliance' "$($Row.name),$($Row.value_configured),$($Row.value_in_use),0"
}
# For 2019 (And above?) Only.
if ($Script:AllDatabases) {
foreach ($db in $Script:DatabasesInfo) {
$SqlQuery = "
SELECT
name AS name,
CAST(value as int) as value_configured,
CAST(value_in_use as int) as value_in_use
FROM
sys.configurations
WHERE
name = 'clr strict security';
;"
$Script:Database = $db.name
SqlConnectionBuilder
$Dataset = DataCollector $SqlQuery
if ($Dataset.Rows.Count -gt 0) {
HTMLPrinter -OpeningTag "<p>" -Content "Check if 'clr strict security' is enabled (1) for $($db.name)." -ClosingTag "</p>"
HTMLPrinter -Table $Dataset -Columns @("name", "value_configured", "value_in_use")
foreach ($Row in $Dataset) {
CsvWriter 'CIS-Compliance' "$($Row.name),$($Row.value_configured),$($Row.value_in_use),0,$($db.name)"
}
}
}
$Script:Database = $Script:OriginalDatabase
}
else {
if ($Script:Version -ge 19) {
$SqlQuery = "SELECT name AS name,
CAST(value as int) as value_configured,
CAST(value_in_use as int) as value_in_use
FROM
sys.configurations
WHERE
name = 'clr strict security';
;"
$Dataset = DataCollector $SqlQuery
HTMLPrinter -OpeningTag "<p>" -Content "Check if 'clr strict security' is enabled (1)." -ClosingTag "</p>"
HTMLPrinter -Table $Dataset -Columns @("name", "value_configured", "value_in_use")
foreach ($Row in $Dataset) {
CsvWriter 'CIS-Compliance' "$($Row.name),$($Row.value_configured),$($Row.value_in_use),0"
}
}
}
# This query is based on CIS Microsoft SQL Server 2012 benchmark section 2.3.
# This query is based on CIS Microsoft SQL Server 2016 benchmark section 2.3.
# Checks if the option 'cross db ownership chaining' is disabled.
$SqlQuery = "SELECT name AS name,
CAST(value AS int) AS value_configured,
CAST(value_in_use AS int) AS value_in_use
FROM
sys.configurations AS C
WHERE
C.name = 'cross db ownership chaining'
;"
$Dataset = DataCollector $SqlQuery
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.3 Ensure 'Cross DB Ownership Chaining' Server Configuration Option is set to '0' (Automated)" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check if 'cross db ownership chaining' is disabled (0)." -ClosingTag "</p>"
HTMLPrinter -Table $Dataset -Columns @("name", "value_configured", "value_in_use")
foreach ($Row in $Dataset) {
CsvWriter 'CIS-Compliance' "$($Row.name),$($Row.value_configured),$($Row.value_in_use),0"
}
# This query is based on CIS Microsoft SQL Server 2012 benchmark section 2.4.
# This query is based on CIS Microsoft SQL Server 2016 benchmark section 2.4.
# Checks if the option 'Database Mail XPs' is disabled.
$SqlQuery = "SELECT name AS name,
CAST(value AS int) AS value_configured,
CAST(value_in_use AS int) AS value_in_use
FROM
sys.configurations AS C
WHERE
C.name = 'Database Mail XPs'
;"
$Dataset = DataCollector $SqlQuery
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.4 Ensure 'Database Mail XPs' Server Configuration Option is set to '0' (Automated)" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check if 'Database Mail XPs' is disabled (0)." -ClosingTag "</p>"
HTMLPrinter -Table $Dataset -Columns @("name", "value_configured", "value_in_use")
foreach ($Row in $Dataset) {
CsvWriter 'CIS-Compliance' "$($Row.name),$($Row.value_configured),$($Row.value_in_use),0"
}
# This query is based on CIS Microsoft SQL Server 2012 benchmark section 2.5.
# This query is based on CIS Microsoft SQL Server 2016 benchmark section 2.5.
# Checks if the option 'Ole Automation Procedures' is disabled.
$SqlQuery = "SELECT name AS name,
CAST(value AS int) AS value_configured,
CAST(value_in_use AS int) AS value_in_use
FROM
sys.configurations AS C
WHERE
C.name = 'Ole Automation Procedures'
;"
$Dataset = DataCollector $SqlQuery
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.5 Ensure 'Ole Automation Procedures' Server Configuration Option is set to '0' (Automated)" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check if 'Ole Automation Procedures' is disabled (0)." -ClosingTag "</p>"
HTMLPrinter -Table $Dataset -Columns @("name", "value_configured", "value_in_use")
foreach ($Row in $Dataset) {
CsvWriter 'CIS-Compliance' "$($Row.name),$($Row.value_configured),$($Row.value_in_use),0"
}
# This query is based on CIS Microsoft SQL Server 2012 benchmark section 2.6.
# This query is based on CIS Microsoft SQL Server 2016 benchmark section 2.6.
# Checks if the option 'remote access' is disabled.
$SqlQuery = "SELECT name AS name,
CAST(value AS int) AS value_configured,
CAST(value_in_use AS int) AS value_in_use
FROM
sys.configurations AS C
WHERE
C.name = 'remote access'
;"
$Dataset = DataCollector $SqlQuery
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.6 Ensure 'Remote Access' Server Configuration Option is set to '0' (Automated)" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check if 'remote access' is disabled (0)." -ClosingTag "</p>"
HTMLPrinter -Table $Dataset -Columns @("name", "value_configured", "value_in_use")
foreach ($Row in $Dataset) {
CsvWriter 'CIS-Compliance' "$($Row.name),$($Row.value_configured),$($Row.value_in_use),0"
}
# This query is based on CIS Microsoft SQL Server 2012 benchmark section 2.7.
# This query is based on CIS Microsoft SQL Server 2016 benchmark section 2.7.
# Checks if the option 'remote admin connections' is disabled if the server is not in a cluster.
$SqlQuery = "SELECT name AS name,
CAST(value AS int) AS value_configured,
CAST(value_in_use AS int) AS value_in_use
FROM
sys.configurations AS C
WHERE
C.name = 'remote admin connections'
AND SERVERPROPERTY('IsClustered') = 0
;"
$Dataset = DataCollector $SqlQuery
if ($Dataset.Rows.Count -gt 0) {
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.7 Ensure 'Remote Admin Connections' Server Configuration Option is set to '0' (Automated)" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check if 'remote admin connections' is disabled (0)." -ClosingTag "</p>"
HTMLPrinter -Table $Dataset -Columns @("name", "value_configured", "value_in_use")
}
else {
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.7 Ensure 'Remote Admin Connections' Server Configuration Option is set to '0' (Automated)" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "This server is in a cluster. Therefore the check for 'remote admin connections' does not apply." -ClosingTag "</p>"
}
foreach ($Row in $Dataset) {
CsvWriter 'CIS-Compliance' "$($Row.name),$($Row.value_configured),$($Row.value_in_use),0"
}
# This query is based on CIS Microsoft SQL Server 2012 benchmark section 2.8.
# This query is based on CIS Microsoft SQL Server 2016 benchmark section 2.8.
# Checks if the option 'scan for startup procs' is disabled.
$SqlQuery = "SELECT name AS name,
CAST(value AS int) AS value_configured,
CAST(value_in_use AS int) AS value_in_use
FROM
sys.configurations AS C
WHERE
C.name = 'scan for startup procs'
;"
$Dataset = DataCollector $SqlQuery
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.8 Ensure 'Scan For Startup Procs' Server Configuration Option is set to '0' (Automated)" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check if 'scan for startup procs' is disabled (0)" -ClosingTag "</p>"
HTMLPrinter -OpeningTag "<p>" -Content "Note that this option might be enabled to use certain audit traces, stored procedures and replication." -ClosingTag "</p>"
HTMLPrinter -Table $Dataset -Columns @("name", "value_configured", "value_in_use")
foreach ($Row in $Dataset) {
CsvWriter 'CIS-Compliance' "$($Row.name),$($Row.value_configured),$($Row.value_in_use),0"
}
# This query is based on CIS Microsoft SQL Server 2012 benchmark section 2.9.
# This query is based on CIS Microsoft SQL Server 2016 benchmark section 2.9.
# Checks if the option 'is_trustworthy_on' is disabled.
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.9 Ensure 'Trustworthy' Database Property is set to 'Off' (Automated)" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check for the following databases if they have the (is_trustworthy_on set to False)." -ClosingTag "</p>"
HTMLPrinter -OpeningTag "<p>" -Content "The 'msdb' database is required to have 'is_trustworthy_on set to True.`n" -ClosingTag "</p>"
HTMLPrinter -Table $Script:DatabasesInfo -Columns @("name", "is_trustworthy_on")
CsvWriter 'CIS-Trustworthy' "name,is_trustworthy_on"
foreach ($Row in $Script:DatabasesInfo) {
CsvWriter 'CIS-Trustworthy' "$($Row.name),$($Row.is_trustworthy_on)"
}
# This query is based on CIS Microsoft SQL Server 2012 benchmark section 2.10.
# This query is based on CIS Microsoft SQL Server 2016 benchmark section 2.10.
# Checks if unnecessary SQL server protocols are disabled
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.10 Ensure Unnecessary SQL Server Protocols are set to 'Disabled' (Manual)" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check that unnecessary SQL server protocols are disabled." -ClosingTag "</p>"
HTMLPrinter -OpeningTag "<p>" -Content "TCP/IP and Shared Memory protocols are enabled on all commercial editions.`n" -ClosingTag "</p>"
$SqlQuery = "SELECT 'Named Pipes' AS [Protocol],
iif(value_data = 1, 'Yes', 'No') AS isEnabled
FROM sys.dm_server_registry
WHERE registry_key LIKE '%np' AND value_name = 'Enabled'
UNION
SELECT 'Shared Memory', iif(value_data = 1, 'Yes', 'No')
FROM sys.dm_server_registry
WHERE registry_key LIKE '%sm' AND value_name = 'Enabled'
UNION
SELECT 'TCP/IP', iif(value_data = 1, 'Yes', 'No')
FROM sys.dm_server_registry
WHERE registry_key LIKE '%tcp' AND value_name = 'Enabled'
;"
$Dataset = DataCollector $SqlQuery
HTMLPrinter -Table $Dataset -Columns @("protocol", "isEnabled")
foreach ($Row in $Dataset) {
CsvWriter 'CIS-Compliance' "$($Row.protocol),$($Row.isEnabled)"
}
# This query is based on CIS Microsoft SQL Server 2012 benchmark section 2.11.
# This query is based on CIS Microsoft SQL Server 2016 benchmark section 2.11.
# Checks if the MSSQL Server does not use the default port 1433.
# Outdated but still works. Newer versions don't work when run from the machine it's hosted on.
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.11 Ensure SQL Server is configured to use non-standard ports (Automated)" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check that the server does not use the default TCP_Port 1433." -ClosingTag "</p>"
$SqlQuery = "SELECT registry_key AS regKey,
value_name AS name,
value_data AS port
FROM sys.dm_server_registry
WHERE value_name like '%Tcp%' and value_data='1433';
;"
$Dataset = DataCollector $SqlQuery
HTMLPrinter -Table $Dataset -Columns @("regKey", "name", "port")
foreach ($Row in $Dataset) {
CsvWriter 'CIS-Compliance' "$($Row.regKey),$($Row.name),$($Row.port)"
}
# This query is based on CIS Microsoft SQL Server 2012 benchmark section 2.12.
# This query is based on CIS Microsoft SQL Server 2016 benchmark section 2.12.
# Checks if the server is hidden. If the server is in a cluster it might be necessary to have this turned off.
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.12 Ensure 'Hide Instance' option is set to 'Yes' for Production SQL Server instances (Automated)" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check if the server is hidden (1)." -ClosingTag "</p>"
HTMLPrinter -OpeningTag "<p>" -Content "If the server is in a cluster it might be necessary to have this turned off." -ClosingTag "</p>"
$SqlQuery = "DECLARE
@getValue INT
;
EXEC
master..xp_instance_regread
@rootkey = N'HKEY_LOCAL_MACHINE',
@key = N'SOFTWARE\Microsoft\Microsoft SQL Server\MSSQLServer\SuperSocketNetLib',
@value_name = N'HideInstance',
@value = @getValue OUTPUT
;
SELECT
@getValue AS is_hidden,
SERVERPROPERTY('IsClustered') AS is_in_cluster
;"
$Dataset = DataCollector $SqlQuery
HTMLPrinter -Table $Dataset -Columns @("is_hidden", "is_in_cluster")
CsvWriter 'CIS-Hidden-Cluster' "is_hidden,is_in_cluster,expected_is_hidden"
foreach ($Row in $Dataset) {
CsvWriter 'CIS-Hidden-Cluster' "$($Row.is_hidden),$($Row.is_in_cluster),1"
}
# This query is based on CIS Microsoft SQL Server 2012 benchmark section 2.13.
# This query is based on CIS Microsoft SQL Server 2016 benchmark section 2.13.
# Checks if the default 'sa' account is disabled.
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.13 Ensure the 'sa' Login Account is set to 'Disabled' (Automated)" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check if the default 'sa' account is disabled (True)" -ClosingTag "</p>"
$SqlQuery = "SELECT
SP.sid AS SID,
SP.name AS name,
SP.is_disabled AS is_disabled
FROM
sys.server_principals AS SP
WHERE
SP.SID = 0x01
;"
$Dataset = DataCollector $SqlQuery
HTMLPrinter -Table $Dataset -Columns @("SID", "name", "is_disabled")
CsvWriter 'CIS-sa-account' "SID,name,is_disabled"
foreach ($Row in $Dataset) {
CsvWriter 'CIS-sa-account' "$($Row.SID),$($Row.name),$($Row.is_disabled)"
}
# This query is based on CIS Microsoft SQL Server 2012 benchmark section 2.14.
# This query is based on CIS Microsoft SQL Server 2016 benchmark section 2.14.
# Checks if the default 'sa' account has been renamed.
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.14 Ensure the 'sa' Login Account has been renamed (Automated) " -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check if the default 'sa' account has been renamed." -ClosingTag "</p>"
$SqlQuery = "SELECT
SP.sid AS SID,
SP.name AS name,
SP.is_disabled AS is_disabled
FROM
sys.server_principals AS SP
WHERE
SP.SID = 0x01
;"
$Dataset = DataCollector $SqlQuery
HTMLPrinter -Table $Dataset -Columns @("SID", "name", "is_disabled")
CsvWriter 'CIS-sa-account' "SID,name,is_disabled"
foreach ($Row in $Dataset) {
CsvWriter 'CIS-sa-account' "$($Row.SID),$($Row.name),$($Row.is_disabled)"
}
# This query is based on CIS Microsoft SQL Server 2012 benchmark section 2.15.
# This query is based on CIS Microsoft SQL Server 2016 benchmark section 2.15.
# Checks if the option 'xp_cmdshell' is disabled.
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.?? Ensure the 'xp_cmdshell' feature is set to 'Disabled' (Automated)" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check if 'xp_cmdshell' is disabled (0)." -ClosingTag "</p>"
$SqlQuery = "SELECT name AS name,
CAST(value AS int) AS value_configured,
CAST(value_in_use AS int) AS value_in_use
FROM
sys.configurations AS C
WHERE
C.name = 'xp_cmdshell'
;"
$Dataset = DataCollector $SqlQuery
HTMLPrinter -Table $Dataset -Columns @("name", "value_configured", "value_in_use")
foreach ($Row in $Dataset) {
CsvWriter 'CIS-Compliance' "$($Row.name),$($Row.value_configured),$($Row.value_in_use),0"
}
# This query is based on CIS Microsoft SQL Server 2012 benchmark section 2.16.
# This query is based on CIS Microsoft SQL Server 2016 benchmark section 2.16.
# This query is based on CIS Microsoft SQL Server 2019 benchmark section 2.15.
# Checks if the is_auto_close_on option is turned off for contained databases.
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.15 Ensure 'AUTO_CLOSE' is set to 'OFF' on contained" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check if the 'is_auto_close_on' option is set to 'False' for the databases with 'containment' not set to '0'." -ClosingTag "</p>"
HTMLPrinter -Table $Script:DatabasesInfo -Columns @("name", "containment", "containment_desc", "is_auto_close_on")
CsvWriter 'CIS-containment' "name,containment,containment_desc,is_auto_close_on"
foreach ($Row in $Script:DatabasesInfo) {
CsvWriter 'CIS-containment' "$($Row.name),$($Row.containment),$($Row.containment_desc),$($Row.is_auto_close_on)"
}
# This query is based on CIS Microsoft SQL Server 2012 benchmark section 2.17.
# This query is based on CIS Microsoft SQL Server 2016 benchmark section 2.17.
# This query is based on CIS Microsoft SQL Server 2019 benchmark section 2.16.
# Checks if no login exists with the name 'sa'.
$SqlQuery = "SELECT
SP.principal_id AS principal_ID,
SP.name AS name,
SP.is_disabled AS is_disabled
FROM
sys.server_principals AS SP
WHERE
SP.type = 'S'
OR SP.type = 'U'
OR SP.type = 'G'
ORDER BY
SP.principal_ID
;"
$Dataset = DataCollector $SqlQuery
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.16 Ensure no login exists with the name 'sa' (Automated)" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check if no login exists with the name 'sa', even if this is not the original 'sa' account." -ClosingTag "</p>"
HTMLPrinter -Table $Dataset -Columns @("principal_ID", "name", "is_disabled")
CsvWriter 'CIS-sa' "principal_ID,name,is_disabled,expected"
foreach ($Row in $Dataset) {
CsvWriter 'CIS-sa' "$($Row.principal_ID),$($Row.name),$($Row.is_disabled),True"
}
# This second query is based on CIS Microsoft SQL Server 2019 benchmark section 2.2 and 2.17.
# Checks if the option 'clr enabled' is disabled or 'clr strict security' is enabled for 2019.
HTMLPrinter -OpeningTag "<p><h3>" -Content "2.17 Ensure 'clr strict security' Server Configuration Option is set to '1' (Automated)" -ClosingTag "</h3></p>"
HTMLPrinter -OpeningTag "<p>" -Content "Check if 'clr enabled' is disabled (0)." -ClosingTag "</p>"
$SqlQuery = ""
$SqlQuery = "SELECT name AS name,
CAST(value AS int) AS value_configured,
CAST(value_in_use AS int) AS value_in_use
FROM
sys.configurations AS C
WHERE
C.name = 'clr enabled'
;"
$Dataset = DataCollector $SqlQuery