forked from ktaranov/sqlserver-kit
-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathGet-SQLServerSecurityReview.ps1
1049 lines (983 loc) · 45 KB
/
Get-SQLServerSecurityReview.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
The Script retrives the Security Best Practises for SQL Server and put's all that info in a html document.
.DESCRIPTION
The Following information collectors can be found in the report.
1. Server Information
2. Database owners
3. Windows Authenticated Logins
4. SQL Authenticated Logins
5. Server Level Permissions
6. Server Role Members
7. Database Level Permissions
8. Database Role Members
9. Job Owners
10. Login Account for SQL Services
11. SQL Server Network Protocols
12. SQL Server TCP Port
13. SQL Server Login Auditing Property Setting
14. SQL Server Global Configuration Parameter (Secrity Affecting One's)
.PARAMETER Computer
Specify the Computer\Machine\Sever Name here to make IO analysis for the Server. One hostname per run.
For Example: Get-SQLSecurityReview -computer ServerName ......
.PARAMETER instance
Specify the SQL instance Name to make IO analysis for the Server. One SQL instance per run.
For Example: Get-SQLSecurityReview ...... -instance ServerName\SQLInstance ......
.PARAMETER report
Specify the location for the output report
For Example: Get-SQLSecurityReview ...... C:\temp\ServerName$SQLInstance-Security_Review.html
.EXAMPLE
Get-SQLSecurityReview -computer ServerName -instance ServerName\SQLInstance -report C:\temp\ServerName$SQLInstance-Security_Review.html
This will generate a html color coded report for localhost with sql instance jupiter
and will dump the report @ location - C:\temp\ServerName$SQLInstance-Security_Review.html
.NOTES
Author: Sandeep Arora [email protected] [email protected]
Version Info:
1.1 - 01/15/2016 - Initial Draft
1.2 - 06/25/2016 - Bug Fixes with SMO Objects for Collecting SQL Server Port Info and Details for Networking Protocols
Verified on following platforms
Powershell v2.0 and higher versions
Microsoft SQL Server 2008 and higher versions
Windows Server 2008 and higher versions
#>
[CmdletBinding()]
Param(
[Parameter(Mandatory=$true, ValueFromPipeline=$true, ValueFromPipelineByPropertyName=$true)]
[Alias('hostname')]
[string]$computer,
[Parameter(Mandatory=$true, ValueFromPipeline=$true, ValueFromPipelineByPropertyName=$true)]
[string]$instance,
[Parameter(Mandatory=$true, ValueFromPipeline=$true, ValueFromPipelineByPropertyName=$true)]
[string]$report
)
Function Get-SQLServerInfo {
[CmdletBinding()]
Param(
[Parameter(Mandatory=$true)]
[Alias('instance')]
[string]$sqlinstance
)
BEGIN{
Try{
$query = @"
exec sp_configure 'show advanced options', 1;
RECONFIGURE with override;
------------------------------------------------
SET NOCOUNT ON
create table #spconfig(s_name varchar(50), mini bigint, maxi bigint, config_value bigint, run_value bigint)
insert into #spconfig(s_name, mini, maxi,config_value, run_value) execute sp_configure
declare @testvaluec as int
declare @testvaluer as int
set @testvaluec = (select config_value from #spconfig where s_name like '%xp_cmdshell%' )
set @testvaluer = (select run_value from #spconfig where s_name like '%xp_cmdshell%' )
---------------------------------------------------------------------------------------------------------------
---------------------------------------------CONDITION 1
IF (@testvaluec =0 AND @testvaluer = 0)
----------------------------------------------BLOCK A
BEGIN
---------------------------------------------------
exec sp_configure 'show advanced options', 1;
RECONFIGURE with override;
exec sp_configure 'xp_cmdshell', 1;
RECONFIGURE with override;
---------------------------------------------------------------
declare @rootdir nvarchar(1000)
exec master.dbo.xp_instance_regread
N'HKEY_LOCAL_MACHINE',
N'SOFTWARE\Microsoft\MSSQLServer\Setup',
N'SQLPath', @rootdir OUTPUT
IF EXISTS(SELECT 1 FROM [master].[sys].[databases] WHERE [name] = 'zzTempDBForDefaultPath')
BEGIN
DROP DATABASE zzTempDBForDefaultPath
END;
CREATE DATABASE zzTempDBForDefaultPath;
DECLARE @Default_Data_Path1 VARCHAR(512),
@Default_Log_Path2 VARCHAR(512);
SELECT @Default_Data_Path1 =
( SELECT LEFT(physical_name,LEN(physical_name)-CHARINDEX('\',REVERSE(physical_name))+1)
FROM sys.master_files mf
INNER JOIN sys.[databases] d
ON mf.[database_id] = d.[database_id]
WHERE d.[name] = 'zzTempDBForDefaultPath' AND type = 0);
SELECT @Default_Log_Path2 =
( SELECT LEFT(physical_name,LEN(physical_name)-CHARINDEX('\',REVERSE(physical_name))+1)
FROM sys.master_files mf
INNER JOIN sys.[databases] d
ON mf.[database_id] = d.[database_id]
WHERE d.[name] = 'zzTempDBForDefaultPath' AND type = 1);
IF EXISTS(SELECT 1 FROM [master].[sys].[databases] WHERE [name] = 'zzTempDBForDefaultPath')
BEGIN
DROP DATABASE zzTempDBForDefaultPath
END
declare @ErrLogPath1 nvarchar(500)
exec master.dbo.xp_instance_regread
N'HKEY_LOCAL_MACHINE',
N'Software\Microsoft\MSSQLServer\MSSQLServer\Parameters',
N'SqlArg1', @ErrLogPath1 OUTPUT
DECLARE @DBEngineLogin VARCHAR(100)
EXECUTE master.dbo.xp_instance_regread
@rootkey = N'HKEY_LOCAL_MACHINE',
@key = N'SYSTEM\CurrentControlSet\Services\MSSQLServer',
@value_name = N'ObjectName',
@value = @DBEngineLogin OUTPUT
DECLARE @tmpNewValue TABLE (newvalue varchar(500))
INSERT INTO @tmpNewValue EXEC xp_cmdshell 'systeminfo | findstr /c:"System Manufacturer"'
DECLARE @localVariable varchar(500)
SET @localVariable = (SELECT top 1 rtrim(ltrim(newvalue)) FROM @tmpNewValue )
--case when @localVariable like '%VMware%' OR @localVariable like '%hyper%'Then 'Virtual' else 'Physical' end as 'ServerType'
select
Case SERVERPROPERTY('IsClustered') when 1 then 'CLUSTERED' else 'STANDALONE' end as 'ServerType',
case when @localVariable like '%VMware%' OR @localVariable like '%hyper%'Then 'Virtual' else 'Physical' end as 'ServerType(PhysicalorVirtual)',
SERVERPROPERTY('MachineName') as 'MachineName',
(SELECT TOP(1) c.local_net_address
FROM sys.dm_exec_connections AS c
WHERE c.local_net_address IS NOT NULL) as IPAddress,'MSSQL' as 'Technology',
@@servername as 'InstanceName',
(SELECT top 1 local_tcp_port
FROM sys.dm_exec_connections
WHERE local_tcp_port IS NOT NULL
and net_transport = 'TCP' and protocol_type not like 'Database Mirroring' and endpoint_id = 4) as 'port',
@DBEngineLogin as 'ServiceAccount',
left(@@VERSION, CHARINDEX(' - ',@@version)-1) as 'Version',
SERVERPROPERTY ('Edition') as 'Edition',
SERVERPROPERTY('productversion') 'VersionNumber',
SERVERPROPERTY ('productlevel') as 'ServicePack',
(select stuff((SELECT ', '+ cast (ROW_NUMBER() Over(order by dbid) as varchar)+'.'+ UPPER(name)
FROM sys.sysdatabases FOR XML PATH ('')), 1, 1, '') as 'DB') as 'Databases',
@Default_Data_Path1 as 'data', @Default_Log_Path2 as 'log',
(select top 1 filename from sys.sysaltfiles where name like '%tempdev%' and filename like '%.mdf') as 'tempdbdata',
(select top 1 filename from sys.sysaltfiles where name like '%templog%' and filename like '%.ldf') as 'tempdblog',
@rootdir as 'root',
SUBSTRING(substring(@ErrLogPath1, 1, len(@ErrLogPath1) - charindex('\', reverse(@ErrLogPath1))),3,500) as 'ErrorLogPath'
---------------------------------------------------------------
exec sp_configure 'show advanced options', 1;
RECONFIGURE with override;
exec sp_configure 'xp_cmdshell', 0;
RECONFIGURE with override;
exec sp_configure 'show advanced options', 0;
Reconfigure with override;
----------------------------------------------------------------
Drop Table #spconfig
END
----------------------------------------------------------------
---------------------------------------------CONDITION 2
ELSE IF (@testvaluec =1 AND @testvaluer = 1)
----------------------------------------------------------BLOCK B
BEGIN
-------------------------------------------------------------------
declare @rootdir3 nvarchar(500)
exec master.dbo.xp_instance_regread
N'HKEY_LOCAL_MACHINE',
N'SOFTWARE\Microsoft\MSSQLServer\Setup',
N'SQLPath', @rootdir3 OUTPUT
IF EXISTS(SELECT 1 FROM [master].[sys].[databases] WHERE [name] = 'zzTempDBForDefaultPath')
BEGIN
DROP DATABASE zzTempDBForDefaultPath
END;
CREATE DATABASE zzTempDBForDefaultPath;
DECLARE @Default_Data_Path3 VARCHAR(512),
@Default_Log_Path4 VARCHAR(512);
SELECT @Default_Data_Path3 =
( SELECT LEFT(physical_name,LEN(physical_name)-CHARINDEX('\',REVERSE(physical_name))+1)
FROM sys.master_files mf
INNER JOIN sys.[databases] d
ON mf.[database_id] = d.[database_id]
WHERE d.[name] = 'zzTempDBForDefaultPath' AND type = 0);
SELECT @Default_Log_Path4 =
( SELECT LEFT(physical_name,LEN(physical_name)-CHARINDEX('\',REVERSE(physical_name))+1)
FROM sys.master_files mf
INNER JOIN sys.[databases] d
ON mf.[database_id] = d.[database_id]
WHERE d.[name] = 'zzTempDBForDefaultPath' AND type = 1);
IF EXISTS(SELECT 1 FROM [master].[sys].[databases] WHERE [name] = 'zzTempDBForDefaultPath')
BEGIN
DROP DATABASE zzTempDBForDefaultPath
END
DECLARE @DBEngineLogin1 VARCHAR(100)
EXECUTE master.dbo.xp_instance_regread
@rootkey = N'HKEY_LOCAL_MACHINE',
@key = N'SYSTEM\CurrentControlSet\Services\MSSQLServer',
@value_name = N'ObjectName',
@value = @DBEngineLogin1 OUTPUT
declare @ErrLogPath nvarchar(500)
exec master.dbo.xp_instance_regread
N'HKEY_LOCAL_MACHINE',
N'Software\Microsoft\MSSQLServer\MSSQLServer\Parameters',
N'SqlArg1', @ErrLogPath OUTPUT
DECLARE @tmpNewValue1 TABLE (newvalue varchar(500))
INSERT INTO @tmpNewValue1 EXEC xp_cmdshell 'systeminfo | findstr /c:"System Manufacturer"'
DECLARE @localVariable1 varchar(500)
SET @localVariable1 = (SELECT top 1 rtrim(ltrim(newvalue)) FROM @tmpNewValue1 )
--case when @localVariable like '%VMware%' OR @localVariable like '%hyper%'Then 'Virtual' else 'Physical' end as 'ServerType'
select
Case SERVERPROPERTY('IsClustered') when 1 then 'CLUSTERED' else 'STANDALONE' end as 'ServerType',
case when @localVariable like '%VMware%' OR @localVariable like '%hyper%'Then 'Virtual' else 'Physical' end as 'ServerType(PhysicalorVirtual)',
SERVERPROPERTY('MachineName') as 'MachineName',
(SELECT TOP(1) c.local_net_address FROM sys.dm_exec_connections AS c
WHERE c.local_net_address IS NOT NULL) as IPAddress,'MSSQL' as 'Technology',
@@servername as 'InstanceName',
(SELECT top 1 local_tcp_port
FROM sys.dm_exec_connections
WHERE local_tcp_port IS NOT NULL
and net_transport = 'TCP' and protocol_type not like 'Database Mirroring' and endpoint_id = 4) as 'port',
@DBEngineLogin1 as 'ServiceAccount',
left(@@VERSION, CHARINDEX(' - ',@@version)-1) as 'Version',
SERVERPROPERTY ('Edition') as 'Edition',
SERVERPROPERTY('productversion') 'VersionNumber',
SERVERPROPERTY ('productlevel') as 'ServicePack',
(select stuff((SELECT ', '+ cast (ROW_NUMBER() Over(order by dbid) as varchar)+'.'+ UPPER(name)
FROM sys.sysdatabases FOR XML PATH ('')), 1, 1, '') as 'DB') as 'Databases',
@Default_Data_Path3 as 'data', @Default_Log_Path4 as 'log',
(select top 1 filename from sys.sysaltfiles where name like '%tempdev%' and filename like '%.mdf') as 'tempdbdata',
(select top 1 filename from sys.sysaltfiles where name like '%templog%' and filename like '%.ldf') as 'tempdblog',
@rootdir3 as 'root',
SUBSTRING(substring(@ErrLogPath, 1, len(@ErrLogPath) - charindex('\', reverse(@ErrLogPath))),3,500) as 'ErrorLogPath'
-------------------------------------------------------------------
exec sp_configure 'show advanced options', 0;
Reconfigure with override;
---------------------------------------------------------
drop table #spconfig
END
----------------------------------------------------------
"@
$ErrorActionPreference = "Stop"
$SqlConnection = New-Object System.Data.SqlClient.SqlConnection
$SqlConnection.ConnectionString = "Data Source = $sqlinstance; Initial Catalog = Master; Integrated Security=true; Connection Timeout=300;"
$SqlCmd = New-Object System.Data.SqlClient.SqlCommand
$SqlCmd.CommandText = $query
$SqlCmd.CommandTimeout = 0;
$SqlCmd.Connection = $SqlConnection
$SqlAdapter = New-Object System.Data.SqlClient.SqlDataAdapter
$SqlAdapter.SelectCommand = $SqlCmd
$DataSet = New-Object System.Data.DataSet
$SqlAdapter.Fill($DataSet) | Out-Null
$ErrorActionPreference = "Continue"
}
Catch{
Write-Host "Unable to connect to the SQL Instance [$sqlinstance] in specified time-out period of 300s. Please Check the Instance availability and try again." -ForegroundColor "Red"
}
}
Process{
return $DataSet.Tables[0]
}
END{
$SqlConnection.Close()
}
}
Function Get-DBOwners {
[CmdletBinding()]
Param(
[Parameter(Mandatory=$true)]
[Alias('instance')]
[string]$sqlinstance
)
BEGIN{
Try{
$query = @"
select d.name [Database], d.owner_sid [Owner SID], p.name [Owner], p.type_desc [Owner Type]
from sys.databases d left outer join sys.server_principals p on (d.owner_sid = p.sid)
where d.database_id > 4 order by 1
"@
$ErrorActionPreference = "Stop"
$SqlConnection = New-Object System.Data.SqlClient.SqlConnection
$SqlConnection.ConnectionString = "Data Source = $sqlinstance; Initial Catalog = Master; Integrated Security=true; Connection Timeout=60;"
$SqlCmd = New-Object System.Data.SqlClient.SqlCommand
$SqlCmd.CommandText = $query
$SqlCmd.Connection = $SqlConnection
$SqlAdapter = New-Object System.Data.SqlClient.SqlDataAdapter
$SqlAdapter.SelectCommand = $SqlCmd
$DataSet = New-Object System.Data.DataSet
$SqlAdapter.Fill($DataSet) | Out-Null
$ErrorActionPreference = "Continue"
}
Catch{
Write-Host "Unable to connect to the SQL Instance [$sqlinstance] in specified time-out period of 60s. Please Check the Instance availability and try again." -ForegroundColor "Red"
}
}
Process{
return $DataSet.Tables[0]
}
END{
$SqlConnection.Close()
}
}
Function Get-WindowAuthLogins {
[CmdletBinding()]
Param(
[Parameter(Mandatory=$true)]
[Alias('instance')]
[string]$sqlinstance
)
BEGIN{
Try{
$query = @"
select name [Login], type_desc [Type],
case when is_disabled = 0 then 'N'
else 'Y'
end as [Disabled?],
create_date [Create Date],
default_database_name [Default Database]
from sys.server_principals
where type in ('U', 'G')
"@
$ErrorActionPreference = "Stop"
$SqlConnection = New-Object System.Data.SqlClient.SqlConnection
$SqlConnection.ConnectionString = "Data Source = $sqlinstance; Initial Catalog = Master; Integrated Security=true; Connection Timeout=60;"
$SqlCmd = New-Object System.Data.SqlClient.SqlCommand
$SqlCmd.CommandText = $query
$SqlCmd.Connection = $SqlConnection
$SqlAdapter = New-Object System.Data.SqlClient.SqlDataAdapter
$SqlAdapter.SelectCommand = $SqlCmd
$DataSet = New-Object System.Data.DataSet
$SqlAdapter.Fill($DataSet) | Out-Null
$ErrorActionPreference = "Continue"
}
Catch{
Write-Host "Unable to connect to the SQL Instance [$sqlinstance] in specified time-out period of 60s. Please Check the Instance availability and try again." -ForegroundColor "Red"
}
}
Process{
return $DataSet.Tables[0]
}
END{
$SqlConnection.Close()
}
}
Function Get-SQLAuthLogins {
[CmdletBinding()]
Param(
[Parameter(Mandatory=$true)]
[Alias('instance')]
[string]$sqlinstance
)
BEGIN{
Try{
$query = @"
select name [Login], type_desc [Type],
case when is_disabled = 0 then 'N'
else 'Y'
end as [Disabled?],
create_date [Create Date],
default_database_name [Default Database],
case when is_policy_checked = 0 then 'N'
else 'Y'
end as [Enforce Password Policy],
case when is_expiration_checked = 0 then 'N'
else 'Y'
end as [Enforce Password Expiration]
from sys.sql_logins
order by 1
"@
$ErrorActionPreference = "Stop"
$SqlConnection = New-Object System.Data.SqlClient.SqlConnection
$SqlConnection.ConnectionString = "Data Source = $sqlinstance; Initial Catalog = Master; Integrated Security=true; Connection Timeout=30;"
$SqlCmd = New-Object System.Data.SqlClient.SqlCommand
$SqlCmd.CommandText = $query
$SqlCmd.Connection = $SqlConnection
$SqlAdapter = New-Object System.Data.SqlClient.SqlDataAdapter
$SqlAdapter.SelectCommand = $SqlCmd
$DataSet = New-Object System.Data.DataSet
$SqlAdapter.Fill($DataSet) | Out-Null
$ErrorActionPreference = "Continue"
}
Catch{
Write-Host "Unable to connect to the SQL Instance [$sqlinstance] in specified time-out period of 30s. Please Check the Instance availability and try again." -ForegroundColor "Red"
}
}
Process{
return $DataSet.Tables[0]
}
END{
$SqlConnection.Close()
}
}
Function Get-ServerLevelPermissions {
[CmdletBinding()]
Param(
[Parameter(Mandatory=$true)]
[Alias('instance')]
[string]$sqlinstance
)
BEGIN{
Try{
$query = @"
select pa.name [Grantee Login], pa.type_desc [Type], pb.name [Grantor Login],
permission_name [Permission], state_desc [State]
from sys.server_permissions s
inner join sys.server_principals pa on (s.grantee_principal_id = pa.principal_id)
inner join sys.server_principals pb on (s.grantor_principal_id = pb.principal_id)
where pa.type in ('S', 'U', 'G', 'R')
order by 1,4
"@
$ErrorActionPreference = "Stop"
$SqlConnection = New-Object System.Data.SqlClient.SqlConnection
$SqlConnection.ConnectionString = "Data Source = $sqlinstance; Initial Catalog = Master; Integrated Security=true; Connection Timeout=30;"
$SqlCmd = New-Object System.Data.SqlClient.SqlCommand
$SqlCmd.CommandText = $query
$SqlCmd.Connection = $SqlConnection
$SqlAdapter = New-Object System.Data.SqlClient.SqlDataAdapter
$SqlAdapter.SelectCommand = $SqlCmd
$DataSet = New-Object System.Data.DataSet
$SqlAdapter.Fill($DataSet) | Out-Null
$ErrorActionPreference = "Continue"
}
Catch{
Write-Host "Unable to connect to the SQL Instance [$sqlinstance] in specified time-out period of 30s. Please Check the Instance availability and try again." -ForegroundColor "Red"
}
}
Process{
return $DataSet.Tables[0]
}
END{
$SqlConnection.Close()
}
}
Function Get-ServerRoleMembers {
[CmdletBinding()]
Param(
[Parameter(Mandatory=$true)]
[Alias('instance')]
[string]$sqlinstance
)
BEGIN{
Try{
$query = @"
select pa.name [Role], pb.name [Login]
from sys.server_role_members r
inner join sys.server_principals pa on (r.role_principal_id = pa.principal_id)
inner join sys.server_principals pb on (r.member_principal_id = pb.principal_id)
order by 1,2
"@
$ErrorActionPreference = "Stop"
$SqlConnection = New-Object System.Data.SqlClient.SqlConnection
$SqlConnection.ConnectionString = "Data Source = $sqlinstance; Initial Catalog = Master; Integrated Security=true; Connection Timeout=60;"
$SqlCmd = New-Object System.Data.SqlClient.SqlCommand
$SqlCmd.CommandText = $query
$SqlCmd.Connection = $SqlConnection
$SqlAdapter = New-Object System.Data.SqlClient.SqlDataAdapter
$SqlAdapter.SelectCommand = $SqlCmd
$DataSet = New-Object System.Data.DataSet
$SqlAdapter.Fill($DataSet) | Out-Null
$ErrorActionPreference = "Continue"
}
Catch{
Write-Host "Unable to connect to the SQL Instance [$sqlinstance] in specified time-out period of 60s. Please Check the Instance availability and try again." -ForegroundColor "Red"
}
}
Process{
return $DataSet.Tables[0]
}
END{
$SqlConnection.Close()
}
}
Function Get-DBLevelPermissions {
[CmdletBinding()]
Param(
[Parameter(Mandatory=$true)]
[Alias('instance')]
[string]$sqlinstance
)
BEGIN{
Try{
$query = @"
if exists (select [id] from tempdb..sysobjects where [id] = OBJECT_ID ('tempdb..#tmpTable'))
drop table #tmpTable
create table #tmpTable (
[Database] sysname NOT NULL,
[Grantee Login] sysname NOT NULL,
[Type] sysname NOT NULL,
[Grantor Login] sysname NOT NULL,
[Permission] sysname NOT NULL,
[Applies To] sysname NOT NULL,
[State] sysname NOT NULL)
exec sp_msforeachdb
'use [?];
insert into #tmpTable
select distinct db_name() [Database], pa.name [Grantee Login], pa.type_desc [Type], pb.name [Grantor Login],
permission_name [Permission], class_desc [Applies To], state_desc [State]
from sys.database_permissions d
inner join sys.database_principals pa on (d.grantee_principal_id = pa.principal_id)
inner join sys.database_principals pb on (d.grantor_principal_id = pb.principal_id)
where pa.type in (''S'', ''U'', ''G'', ''A'', ''R'')'
select * from #tmpTable order by 1,2,5,6
drop table #tmpTable
"@
$ErrorActionPreference = "Stop"
$SqlConnection = New-Object System.Data.SqlClient.SqlConnection
$SqlConnection.ConnectionString = "Data Source = $sqlinstance; Initial Catalog = Master; Integrated Security=true; Connection Timeout=60;"
$SqlCmd = New-Object System.Data.SqlClient.SqlCommand
$SqlCmd.CommandText = $query
$SqlCmd.Connection = $SqlConnection
$SqlAdapter = New-Object System.Data.SqlClient.SqlDataAdapter
$SqlAdapter.SelectCommand = $SqlCmd
$DataSet = New-Object System.Data.DataSet
$SqlAdapter.Fill($DataSet) | Out-Null
$ErrorActionPreference = "Continue"
}
Catch{
Write-Host "Unable to connect to the SQL Instance [$sqlinstance] in specified time-out period of 60s. Please Check the Instance availability and try again." -ForegroundColor "Red"
}
}
Process{
return $DataSet.Tables[0]
}
END{
$SqlConnection.Close()
}
}
Function Get-DBRoleMembers {
[CmdletBinding()]
Param(
[Parameter(Mandatory=$true)]
[Alias('instance')]
[string]$sqlinstance
)
BEGIN{
Try{
$query = @"
if exists (select [id] from tempdb..sysobjects where [id] = OBJECT_ID ('tempdb..#tmpTable'))
drop table #tmpTable
create table #tmpTable (
[Database] sysname NOT NULL,
[Role] sysname NOT NULL,
[Login] sysname NOT NULL)
exec sp_msforeachdb
'use [?];
insert into #tmpTable
select db_name() [Database], pa.name [Role], pb.name [Login]
from sys.database_role_members r
inner join sys.database_principals pa on (r.role_principal_id = pa.principal_id)
inner join sys.database_principals pb on (r.member_principal_id = pb.principal_id)'
select [Database], Role, Login from #tmpTable
order by 1,2,3
drop table #tmpTable
"@
$ErrorActionPreference = "Stop"
$SqlConnection = New-Object System.Data.SqlClient.SqlConnection
$SqlConnection.ConnectionString = "Data Source = $sqlinstance; Initial Catalog = Master; Integrated Security=true; Connection Timeout=30;"
$SqlCmd = New-Object System.Data.SqlClient.SqlCommand
$SqlCmd.CommandText = $query
$SqlCmd.Connection = $SqlConnection
$SqlAdapter = New-Object System.Data.SqlClient.SqlDataAdapter
$SqlAdapter.SelectCommand = $SqlCmd
$DataSet = New-Object System.Data.DataSet
$SqlAdapter.Fill($DataSet) | Out-Null
$ErrorActionPreference = "Continue"
}
Catch{
Write-Host "Unable to connect to the SQL Instance [$sqlinstance] in specified time-out period of 30s. Please Check the Instance availability and try again." -ForegroundColor "Red"
}
}
Process{
return $DataSet.Tables[0]
}
END{
$SqlConnection.Close()
}
}
Function Get-SQLJobOwner {
[CmdletBinding()]
Param(
[Parameter(Mandatory=$true)]
[Alias('instance')]
[string]$sqlinstance
)
BEGIN{
Try{
$query = @"
select j.name [Job], p.name [Owner],
case
when p.type like 'S' then 'SQL Login'
when p.type like 'U' then 'Windows Login'
end as 'Login Type'
from msdb..sysjobs j inner join sys.server_principals p on (j.owner_sid = p.sid)
"@
$ErrorActionPreference = "Stop"
$SqlConnection = New-Object System.Data.SqlClient.SqlConnection
$SqlConnection.ConnectionString = "Data Source = $sqlinstance; Initial Catalog = Master; Integrated Security=true; Connection Timeout=30;"
$SqlCmd = New-Object System.Data.SqlClient.SqlCommand
$SqlCmd.CommandText = $query
$SqlCmd.Connection = $SqlConnection
$SqlAdapter = New-Object System.Data.SqlClient.SqlDataAdapter
$SqlAdapter.SelectCommand = $SqlCmd
$DataSet = New-Object System.Data.DataSet
$SqlAdapter.Fill($DataSet) | Out-Null
$ErrorActionPreference = "Continue"
}
Catch{
Write-Host "Unable to connect to the SQL Instance [$sqlinstance] in specified time-out period of 30s. Please Check the Instance availability and try again." -ForegroundColor "Red"
}
}
Process{
return $DataSet.Tables[0]
}
END{
$SqlConnection.Close()
}
}
Function Get-SQLServiceAccount {
[CmdletBinding()]
Param(
[Parameter(Mandatory=$true, ValueFromPipeline=$true, ValueFromPipelineByPropertyName=$true)]
[Alias('hostname')]
[string[]]$ComputerName
)
BEGIN{}
PROCESS{
if (Test-Connection $Computer -Quiet -Count 2) {
return Get-WmiObject -Class Win32_Service | Select Caption, startname, StartMode, Started | Where-Object {$_.Caption -like '*SQL*'}
}
else {
Write-Host "Could not connect to $Computer." -ForegroundColor "Red"
}
}
END{}
}
Function Get-SQLNetworkingProtocols {
[CmdletBinding()]
Param(
[Parameter(Mandatory=$true)]
[Alias('hostname')]
[string]$ComputerName
,
[Parameter(Mandatory=$true)]
[Alias('instance')]
[string]$sqlinstance
)
BEGIN{
if (Get-Module -ListAvailable | ?{$_.Name -eq 'SQLPS'}){Push-location; Import-Module SQLPS -DisableNameChecking -WarningAction SilentlyContinue; Pop-Location;} else {Add-PSSnapin SQL* -WarningAction SilentlyContinue -ErrorAction SilentlyContinue;}
try {add-type -AssemblyName "Microsoft.SqlServer.SqlWmiManagement, Version=10.0.0.0, Culture=neutral, PublicKeyToken=89845dcd8080cc91" -EA Stop}
catch {add-type -AssemblyName "Microsoft.SqlServer.SqlWmiManagement"}
$wmi = new-object "Microsoft.SqlServer.Management.Smo.Wmi.ManagedComputer"
if ($sqlinstance -like '*\*') {$sqlinstance = $sqlinstance.Split("\")[1].Split(' ')} else {$sqlinstance = 'MSSQLSERVER'}
$ComputerName = $ComputerName.ToUpper();
try{
$uri = "ManagedComputer[@Name='" + $ComputerName + "']/ ServerInstance[@Name='" + $sqlinstance + "']/ServerProtocol[@Name='Tcp']"
$Tcp = $wmi.GetSmoObject($uri)
$uri = "ManagedComputer[@Name='" + $ComputerName + "']/ ServerInstance[@Name='" + $sqlinstance + "']/ServerProtocol[@Name='np']"
$np = $wmi.GetSmoObject($uri)
$uri = "ManagedComputer[@Name='" + $ComputerName + "']/ ServerInstance[@Name='" + $sqlinstance + "']/ServerProtocol[@Name='sm']"
$sm = $wmi.GetSmoObject($uri)
try{
$uri = "ManagedComputer[@Name='" + $ComputerName + "']/ ServerInstance[@Name='" + $sqlinstance + "']/ServerProtocol[@Name='via']"
$via = $wmi.GetSmoObject($uri)
}
catch{
Write-Host "VIA Protocol is discontinued"
}
}
catch{
Write-Host "Unable to connect to the SQL Instance [$sqlinstance] in specified time-out period of 30s. Please Check the Instance availability and try again." -ForegroundColor "Red"
}
}
PROCESS{
$sm | select @{n="Protocol Name";e={if($_.Name -like 'sm'){"Shared Memory"}}}, IsEnabled
$np | select @{n="Protocol Name";e={if($_.Name -like 'np'){"Named Pipes"}}}, IsEnabled
$Tcp | select @{n="Protocol Name";e={if($_.Name -like 'Tcp'){"TCP\IP"}}}, IsEnabled
$via | select @{n="Protocol Name";e={if($_.Name -like 'via'){"Via"}}}, IsEnabled
}
END{}
}
Function Get-SQLTCPPort {
[CmdletBinding()]
Param(
[string]$ComputerName,
[string]$sqlinstance
)
BEGIN{
if (Get-Module -ListAvailable | ?{$_.Name -eq 'SQLPS'}){Push-location; Import-Module SQLPS -DisableNameChecking -WarningAction SilentlyContinue; Pop-location;} else {Add-PSSnapin SQL* -WarningAction SilentlyContinue -ErrorAction SilentlyContinue;}
try {add-type -AssemblyName "Microsoft.SqlServer.SqlWmiManagement, Version=10.0.0.0, Culture=neutral, PublicKeyToken=89845dcd8080cc91" -EA Stop}
catch {add-type -AssemblyName "Microsoft.SqlServer.SqlWmiManagement"}
$wmi = new-object "Microsoft.SqlServer.Management.Smo.Wmi.ManagedComputer"
if ($sqlinstance -like '*\*') {$sqlinstance = $sqlinstance.Split("\")[1].Split(' ')} else {$sqlinstance = 'MSSQLSERVER'}
Try {
$ComputerName = $ComputerName.ToUpper();
$uri = "ManagedComputer[@Name='$ComputerName']/ ServerInstance[@Name='$sqlinstance']/ServerProtocol[@Name='Tcp']"
$Tcp = $wmi.GetSmoObject($uri);
}
Catch{
Write-Host "Unable to connect to the SQL Instance [$sqlinstance] in specified time-out period of 30s. Please Check the Instance availability and try again." -ForegroundColor "Red"
}
}
PROCESS{
return $wmi.GetSmoObject($uri + "/IPAddress[@Name='IPAll']").IPAddressProperties;
}
END{}
}
Function Get-LoginAuditing {
[CmdletBinding()]
Param(
[Parameter(Mandatory=$true)]
[Alias('instance')]
[string]$sqlinstance
)
BEGIN{
Try{
$query = @"
declare @AuditLevel int
exec master..xp_instance_regread
@rootkey='HKEY_LOCAL_MACHINE',
@key='SOFTWARE\Microsoft\MSSQLServer\MSSQLServer',
@value_name='AuditLevel',
@value=@AuditLevel output
select case
when @AuditLevel = 0 then 'None'
when @AuditLevel = 1 then 'Successful Logins Only'
when @AuditLevel = 2 then 'Failed Logins Only'
when @AuditLevel = 3 then 'Successful Logins'
end as 'LoginAuditing'
"@
$ErrorActionPreference = "Stop"
$SqlConnection = New-Object System.Data.SqlClient.SqlConnection
$SqlConnection.ConnectionString = "Data Source = $sqlinstance; Initial Catalog = Master; Integrated Security=true; Connection Timeout=30;"
$SqlCmd = New-Object System.Data.SqlClient.SqlCommand
$SqlCmd.CommandText = $query
$SqlCmd.Connection = $SqlConnection
$SqlAdapter = New-Object System.Data.SqlClient.SqlDataAdapter
$SqlAdapter.SelectCommand = $SqlCmd
$DataSet = New-Object System.Data.DataSet
$SqlAdapter.Fill($DataSet) | Out-Null
$ErrorActionPreference = "Continue"
}
Catch{
Write-Host "Unable to connect to the SQL Instance [$sqlinstance] in specified time-out period of 30s. Please Check the Instance availability and try again." -ForegroundColor "Red"
}
}
Process{
return $DataSet.Tables[0]
}
END{
$SqlConnection.Close()
}
}
Function Get-SQLGlobalSettings {
[CmdletBinding()]
Param(
[Parameter(Mandatory=$true)]
[Alias('instance')]
[string]$sqlinstance
)
BEGIN{
Try{
$query = @"
exec sp_configure 'show advanced options', 1;
RECONFIGURE with override;
SET NOCOUNT ON
create table #spconfig(s_name varchar(50), mini bigint, maxi bigint, config_value bigint, run_value bigint)
insert into #spconfig(s_name, mini, maxi,config_value, run_value) execute sp_configure
select s_name,
case when run_value = 1 then 'Enabled'
when run_value = 0 then 'Disbaled'
End as 'CurrentSetting'
from #spconfig where s_name in ('xp_cmdshell','SMO and DMO XPs','remote access','default trace enabled')
drop table #spconfig
exec sp_configure 'show advanced options', 0;
RECONFIGURE with override;
"@
$ErrorActionPreference = "Stop"
$SqlConnection = New-Object System.Data.SqlClient.SqlConnection
$SqlConnection.ConnectionString = "Data Source = $sqlinstance; Initial Catalog = Master; Integrated Security=true; Connection Timeout=30;"
$SqlCmd = New-Object System.Data.SqlClient.SqlCommand
$SqlCmd.CommandText = $query
$SqlCmd.Connection = $SqlConnection
$SqlAdapter = New-Object System.Data.SqlClient.SqlDataAdapter
$SqlAdapter.SelectCommand = $SqlCmd
$DataSet = New-Object System.Data.DataSet
$SqlAdapter.Fill($DataSet) | Out-Null
$ErrorActionPreference = "Continue"
}
Catch{
Write-Host "Unable to connect to the SQL Instance [$sqlinstance] in specified time-out period of 30s. Please Check the Instance availability and try again." -ForegroundColor "Red"
}
}
Process{
return $DataSet.Tables[0]
}
END{
$SqlConnection.Close()
}
}
Write-Host "[$(Get-date -DisplayHint date -Format g)]Script Execution Started ....`r`n"
Write-Host "Collecting SQL Server Instance details ....`r`n"
$serverinfo = Get-SQLServerInfo -sqlinstance "$instance"
Write-Host "Checking Database Owners ....`r`n"
$dbowners = Get-DBOwners -sqlinstance "$instance"
Write-Host "Collecting details for Logins using Windows Authentication ....`r`n"
$winauth = Get-WindowAuthLogins -sqlinstance "$instance"
Write-Host "Collecting details for Logins using SQL Server Authentication ....`r`n"
$sqlauth = Get-SQLAuthLogins -sqlinstance "$instance"
Write-Host "Collecting Server Level Permissions ....`r`n"
$serlvlperm = Get-ServerLevelPermissions -sqlinstance "$instance"
Write-Host "Collecting Server Roles assigned to Logins ....`r`n"
$serrolmem = Get-ServerRoleMembers -sqlinstance "$instance"
Write-Host "Collecting Database Level Permissions ....`r`n"
$dblvlperm = Get-DBLevelPermissions -sqlinstance "$instance"
Write-Host "Collecting Database Roles Assigned to Logins ....`r`n"
$dbrolmem = Get-DBRoleMembers -sqlinstance "$instance"
Write-Host "Collecting Job Owner Details ....`r`n"
$jobowners = Get-SQLJobOwner -sqlinstance "$instance"
Write-Host "Checking SQL Server Services Logon Accounts ....`r`n"
$servaccount = Get-SQLServiceAccount -ComputerName "$computer"
Write-Host "Collecting Enabled Networking Protocols for SQL Server ...."
$sqlprotocols = Get-SQLNetworkingProtocols -computer "$computer" -sqlinstance "$instance"
Write-Host "`r`nCollecting SQL Server Port Details ....`r`n"
$tcpports = Get-SQLTCPPort -computer "$computer" -sqlinstance "$instance"
Write-Host "Checking if Login Auditing is Enabled ....`r`n"
$loginaudit = Get-LoginAuditing -sqlinstance "$instance"
Write-Host "Evaluating Configuration Parameters for Security Risks ....`r`n"
$config = Get-SQLGlobalSettings -sqlinstance "$instance"
Write-Host "[$(Get-date -DisplayHint date -Format g)]Finished Script Execution. Formatting Report ....`r`n"
#Final Reporting
$css = @"
<style>
body {
background-color:white;
font-family: "Times New Roman", Times, serif;
font-size:11pt;
color:#333;
}
.header {
font-size: 40px;
color: white;
text-align: center;
background: black;
font-family: "Times New Roman", Times, serif;
font-weight: bold;
width: 100%;
border: 1px black;
margin: 0;}
h1 {font-size:40px;color: black;}
h2 {font-size:30px;color: black;}
h4 {font-size:15px;color: black;}
p {font-size:30px;color: black;}
table {margin-left:50px; table-layout: fixed;}
td {word-wrap:break-word;}
td , th {
border:2px solid black;
border-collapse:collapse;
word-wrap:break-word;
}
th {
font-family: "Times New Roman", Times, serif;
font-size:14pt; color:white;
background-color:black;
font-weight:bold;
}
table, tr, td, th {padding: 2px; margin: 1px;}
</style>
"@
if($serverinfo){
$serverinfo = $serverinfo | select ServerType, "ServerType(PhysicalorVirtual)", MachineName, Technology, InstanceName, ServiceAccount, @{n="Version";e={if($_.Version -like '*2005*'){'<td bgcolor="#FF0000">'+$_.Version} elseif($_.Version -like '*2000*'){'<td bgcolor="#FF0000">'+$_.Version} elseif($_.Version -like '*2008*'){'<td bgcolor="#FFFF00">'+$_.Version} else{'<td bgcolor="#00CC33">'+$_.Version}}}, @{n="Edition";e={if($_.Edition -like '*32*bit'){'<td bgcolor="#FF0000">'+$_.Edition} elseif($_.Edition -notlike '*Enterprise*'){'<td bgcolor="#FFFF00">'+$_."Edition"} else{'<td bgcolor="#00CC33">'+$_."Edition"}}}, Databases, @{n="Default DataFile Location";e={if($_.data -like "$log*"){'<td bgcolor="#FF0000">'+$_.data}else{'<td bgcolor="#00CC33">'+$_.data} }}, @{n="Default LogFile Path";e={if($_.log -like "$data*"){'<td bgcolor="#FF0000">'+$_.log}else{'<td bgcolor="#00CC33">'+$_.log}}}, @{n="TempDB Datafile Path";e={if($_.tempdbdata -like '$data*' -or $_.tempdbdata -like '$log*' ){'<td bgcolor="#FF0000">'+$_.tempdbdata}else{'<td bgcolor="#00CC33">'+$_.tempdbdata}}}, @{n="TempDB Logfile Path";e={if($_.tempdblog -like '$log*' -or $_.tempdblog -like '$data*'){'<td bgcolor="#FF0000">'+$_.tempdblog}else{'<td bgcolor="#00CC33">'+$_.tempdblog}}}, @{n="Root Path";e={$_.root}}, ErrorLogPath
$htmlreport = $serverinfo | ConvertTo-HTML -PreContent "<h2><center>SQL Server Information</center></h2><br><br>" -Fragment | out-string
}
else{
$htmlreport = ConvertTo-HTML -PreContent "<h2><center>SQL Server Information</center></h2><br>" -PostContent "<h4><center>Error Encountered in reporting the details. Check the log for details. If nothing is reported in the log then no details exist for this collector.</center></h4><br>" -Fragment | out-string
}
if($dbowners){
$dbowners = $dbowners | select Database , Owner, @{n="Owner Type";e={if($_."Owner Type" -like '*SQL*') {'<td bgcolor="#00CC33">'+$_."Owner Type"} else {'<td bgcolor="#FF0000">'+$_."Owner Type"} }}
$htmlreport += $dbowners | ConvertTo-HTML -PreContent "<h2><center>Database Owners</center></h2><br><br>" -Fragment | out-string
}
else{
$htmlreport += ConvertTo-HTML -PreContent "<h2><center>Database Ownners</center></h2><br>" -PostContent "<h4><center>Error Encountered in reporting the details. Check the script log for details. If nothing is reported in the log then no details exist for this collector.</center></h4><br>" -Fragment | out-string
}
if($winauth){
$winauth = $winauth | select Login, Type, @{n="Disabled?";e={if($_.Login -like 'NT *' -and $_."Disabled?" -like 'N') {'<td bgcolor="#FF0000">'+$_."Disabled?"} elseif($_."Disabled?" -like 'Y'){'<td bgcolor="#FF0000">'+$_."Disabled?"} else {'<td bgcolor="#00CC33">'+$_."Disabled?"}}}, "Create Date", @{n="Default Database";e={if($_."Default Database" -like 'master'){'<td bgcolor="#00CC33">'+$_."Default Database"}else{'<td bgcolor="#FF0000">'+$_."Default Database"}}}
$htmlreport += $winauth | ConvertTo-HTML -PreContent "<h2><center>Windows Authentication Logins</center></h2><br><br>" -Fragment | out-string
}
else{
$htmlreport += ConvertTo-HTML -PreContent "<h2><center>Windows Authentication Logins</center></h2><br>" -PostContent "<h4><center>Error Encountered in reporting the details. Check the script log for details. If nothing is reported in the log then no details exist for this collector.</center></h4><br>" -Fragment | out-string
}
if($sqlauth){
$sqlauth = $sqlauth | select Login, Type, @{n="Disabled?";e={if($_.Login -like '##*' -and $_."Disabled?" -like 'Y') {'<td bgcolor="#00CC33">'+$_."Disabled?"} elseif($_.Login -like '##*' -and $_."Disabled?" -like 'N') {'<td bgcolor="#FF0000">'+$_."Disabled?"} elseif($_."Disabled?" -like 'Y'){'<td bgcolor="#FF0000">'+$_."Disabled?"} else {'<td bgcolor="#00CC33">'+$_."Disabled?"}}} ,"Create Date", "Default Database", "Enforce Password Policy" , "Enforce Password Expiration"
$htmlreport += $sqlauth | ConvertTo-HTML -PreContent "<h2><center>SQL Server Authentication Logins</center></h2><br><br>" -Fragment | out-string
}
else{
$htmlreport += ConvertTo-HTML -PreContent "<h2><center>SQL Server Authentication Logins</center></h2><br>" -PostContent "<h4><center>Error Encountered in reporting the details. Check the script log for details. If nothing is reported in the log then no details exist for this collector.</center></h4><br>" -Fragment | out-string
}
if($serlvlperm){
$serlvlperm = $serlvlperm | select "Grantee Login", Type, "Grantor Login", Permission, State
$htmlreport += $serlvlperm | ConvertTo-HTML -PreContent "<h2><center>Server Level Permissions</center></h2><br><br>" -Fragment | out-string
}
else{
$htmlreport += ConvertTo-HTML -PreContent "<h2><center>Server Level Permissions</center></h2><br>" -PostContent "<h4><center>Error Encountered in reporting the details. Check the script log for details. If nothing is reported in the log then no details exist for this collector.</center></h4><br>" -Fragment | out-string
}
if($serrolmem){
$serrolmem = $serrolmem | select Login, @{n="Role";e={if($_."Role" -like 'sysadmin'){'<td bgcolor="#FFFF00">'+$_."Role"}else{$_."Role"}}}
$htmlreport += $serrolmem | ConvertTo-HTML -PreContent "<h2><center>Server Role Members</center></h2><br><br>" -Fragment | out-string
}
else{
$htmlreport += ConvertTo-HTML -PreContent "<h2><center>Server Role Memebers</center></h2><br>" -PostContent "<h4><center>Error Encountered in reporting the details. Check the script log for details. If nothing is reported in the log then no details exist for this collector.</center></h4><br>" -Fragment | out-string
}
if($dblvlperm){
$dblvlperm = $dblvlperm | select Database, "Grantee Login", Type, "Grantor Login", Permission, "Applies To", State
$htmlreport += $dblvlperm | ConvertTo-HTML -PreContent "<h2><center>Database Level Permissions</center></h2><br><br>" -Fragment | out-string
}
else{
$htmlreport += ConvertTo-HTML -PreContent "<h2><center>Database Level Permissions</center></h2><br>" -PostContent "<h4><center>Error Encountered in reporting the details. Check the script log for details. If nothing is reported in the log then no details exist for this collector.</center></h4><br>" -Fragment | out-string
}
if($dbrolmem){
$dbrolmem = $dbrolmem | select Database, Login,@{n="Role";e={if($_."Role" -like 'db_owner'){'<td bgcolor="#FFFF00">'+$_."Role"}else{$_."Role"}}}
$htmlreport += $dbrolmem | ConvertTo-HTML -PreContent "<h2><center>Database Role Members</center></h2><br><br>" -Fragment | out-string
}
else{
$htmlreport += ConvertTo-HTML -PreContent "<h2><center>Database Role Members</center></h2><br>" -PostContent "<h4><center>Error Encountered in reporting the details. Check the script log for details. If nothing is reported in the log then no details exist for this collector.</center></h4><br>" -Fragment | out-string
}
if($jobowners){
$jobowners = $jobowners | select Job, @{n="Owner";e={if($_.Owner -like 'sa' ){'<td bgcolor="#00CC33">'+$_.Owner} else{'<td bgcolor="#FF0000">'+$_.Owner} }}, "Login Type"
$htmlreport += $jobowners | ConvertTo-HTML -PreContent "<h2><center>SQL Server Job Owners</center></h2><br><br>" -Fragment | out-string
}
else{
$htmlreport += ConvertTo-HTML -PreContent "<h2><center>SQL Server Job Owners</center></h2><br>" -PostContent "<h4><center>Error Encountered in reporting the details. Check the script log for details. If nothing is reported in the log then no details exist for this collector.</center></h4><br>" -Fragment | out-string
}
if($servaccount){
$servaccount = $servaccount | select @{n="Service Name";e={$_.caption}}, @{n="Service Account";e={if($_.startname -like 'Local*' -or $_.startname -like 'NT*'){'<td bgcolor="#FF0000">'+$_.startname}else{'<td bgcolor="#00CC33">'+$_.startname}}}, StartMode
$htmlreport += $servaccount | ConvertTo-HTML -PreContent "<h2><center>Login Account for SQL Services</center></h2><br><br>" -Fragment | out-string
}
else{