Share this
SQL server security review using PowerShell
by Sandeep Arora on Jul 26, 2016 11:14:00 AM
PROBLEM
How often do we do Security Reviews for your SQL Server Instances? We aim to stay on top of security and to be able to so we need to regularly review your Instance security configurations. It’s helpful to build a checklist to be used as part of an internal security audit review, and follow that checklist every time you conduct an audit. I don't know about you, but the latter sounds boring to me. What would be awesome is to take that checklist and automate the whole SQL Server Security Review.
SOLUTION
The PowerShell Script below will evaluate your Instance level, Database Level Access and SQL Server Security options, and generate a HTML Report for you to check for any potential threats.
The Script already has help associated with it so you can download and simply use help to figure out how to use the script or alternatively you can download it to a PS-Scripts folder and provide parameters as shown below,
[code language="powershell"]
PS C:\PS-Scripts>.\Get-SQLSecurityReview -computer ServerName -instance ServerName\SQLInstance -report C:\temp\ServerName$SQLInstance-Security_Review.html
[/code]
Verified on following platforms
- Powershell v2.0 and higher versions
- Microsoft SQL Server 2008 and higher versions
- Windows Server 2008 and higher versions
You can download the script from the below link
ACTUAL SCRIPT
[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{
$htmlreport += ConvertTo-HTML -PreContent "<h2><center>Login Account for SQL Services</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($sqlprotocols){
$sqlprotocols = $sqlprotocols | select "Protocol Name", @{n="IsEnabled?";e={if($_."Protocol Name" -like 'Named*' -or $_."Protocol Name" -like 'VIA' ){if($_.IsEnabled -like 'True'){'<td bgcolor="#FF0000">'+$_.IsEnabled} else{'<td bgcolor="#00CC33">'+$_.IsEnabled}} else{'<td bgcolor="#00CC33">'+$_.IsEnabled}}}
$htmlreport += $sqlprotocols | ConvertTo-HTML -PreContent "<h2><center>SQL Server Network Protocols</center></h2><br><br>" -Fragment | out-string
}
else{
$htmlreport += ConvertTo-HTML -PreContent "<h2><center>SQL Server Network Protocols</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($tcpports){
$statictcpports = @{}
$dynamictcpports = @{}
$statictcpports = $tcpports | Where-Object {$_.Name -like 'TcpPort'} | Select Value
$dynamictcpports = $tcpports | Where-Object {$_.Name -like 'TcpDynamicPorts'} | Select Value
$dport = $($dynamicportvalue).Value
$sport = $($statictcpports).Value
if ($sport) {
$htmlreport += ConvertTo-HTML -PreContent "<h2><center>SQL TCP Port Settings</center></h2><br><br>" -PostContent "<p><mark>SQL Server Instance [$instance] is set to use Static Port # : $sport.</mark></p><br>" -Fragment | out-string
}
else {
$htmlreport += ConvertTo-HTML -PreContent "<h2><center>SQL TCP Port Settings</center></h2><br><br>" -PostContent "<p><mark>SQL Server Instance [$instance] is set to use Dynamic # : $dport.</mark><p><br>" -Fragment | out-string
}
}
else{
$htmlreport += ConvertTo-HTML -PreContent "<h2><center>SQL TCP Port Settings</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($loginaudit){
$loginaudit = $loginaudit | select @{n="Login Auditing";e={$_.LoginAuditing}}, @{n="Recommended Setting";e={if($_.LoginAuditing -like 'Failed Logins Only'){'<td bgcolor="#00CC33">'+"Y"}else{'<td bgcolor="#FF0000">'+"N"}}}
$htmlreport += $loginaudit | ConvertTo-HTML -PreContent "<h2><center>SQL Server Login Auditing</center></h2><br><br>" -Fragment | out-string
}
else{
$htmlreport += ConvertTo-HTML -PreContent "<h2><center>SQL Server Login Auditing</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($config){
$config = $config | select @{n="Configuration Parameter";e={$_.s_name}}, @{n="IsEnabled?";e={if($_.CurrentSetting -like 'Enabled'){'<td bgcolor="#FF0000">'+$_.CurrentSetting}else{'<td bgcolor="#00CC33">'+$_.CurrentSetting} }}
$htmlreport += $config | ConvertTo-HTML -PreContent "<h2><center>SQL Sever Global Configuration Parameters</center></h2><br><br>" -Fragment | out-string
}
else{
$htmlreport += ConvertTo-HTML -PreContent "<h2><center>SQL Sever Global Configuration Parameters</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
}
$htmlreport = $htmlreport.Replace('<td><td bgcolor="#FFFF00">','<td bgcolor="#FFFF00">')
$htmlreport = $htmlreport.Replace('<td><td bgcolor="#FF0000">','<td bgcolor="#FF0000">')
$htmlreport = $htmlreport.Replace('<td><td bgcolor="#00CC33">','<td bgcolor="#00CC33">')
$body = convertto-html -Head $css -PostContent "$htmlreport <br/><br/><h1 class = `"header`">END OF REPORT</h1>" -body "<h1 class = `"header`">SQL SERVER SECURITY REVIEW</h1><center><h4>Report Generated on $(Get-date -DisplayHint date -Format g)</h4></center>" -Title "SQL SERVER SECURITY REVIEW" | out-string
$body = $body.Replace("<table>`r`n</table>","")
$body | Out-File "$report"
<#
.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
#>
Share this
- Technical Track (967)
- Oracle (410)
- MySQL (140)
- Cloud (128)
- Microsoft SQL Server (117)
- Open Source (90)
- Google Cloud (81)
- Microsoft Azure (63)
- Amazon Web Services (AWS) (58)
- Big Data (52)
- Google Cloud Platform (46)
- Cassandra (44)
- DevOps (41)
- Pythian (33)
- Linux (30)
- Database (26)
- Performance (25)
- Podcasts (25)
- Site Reliability Engineering (25)
- PostgreSQL (24)
- Oracle E-Business Suite (23)
- Oracle Database (22)
- Docker (21)
- DBA (20)
- Security (20)
- Exadata (18)
- MongoDB (18)
- Oracle Cloud Infrastructure (OCI) (18)
- Oracle Exadata (18)
- Automation (17)
- Hadoop (16)
- Oracleebs (16)
- Amazon RDS (15)
- Ansible (15)
- Snowflake (15)
- ASM (13)
- Artificial Intelligence (AI) (13)
- BigQuery (13)
- Replication (13)
- Advanced Analytics (12)
- Data (12)
- GenAI (12)
- Kubernetes (12)
- LLM (12)
- Authentication, SSO and MFA (11)
- Cloud Migration (11)
- Machine Learning (11)
- Rman (11)
- Datascape Podcast (10)
- Monitoring (10)
- Apache Cassandra (9)
- ChatGPT (9)
- Data Guard (9)
- Infrastructure (9)
- Oracle Applications (9)
- Python (9)
- Series (9)
- AWR (8)
- High Availability (8)
- Oracle EBS (8)
- Oracle Enterprise Manager (OEM) (8)
- Percona (8)
- Apache Beam (7)
- Data Governance (7)
- Innodb (7)
- Microsoft Azure SQL Database (7)
- Migration (7)
- Myrocks (7)
- Performance Tuning (7)
- Data Enablement (6)
- Data Visualization (6)
- Database Performance (6)
- Oracle Enterprise Manager (6)
- Orchestrator (6)
- RocksDB (6)
- Serverless (6)
- Azure Data Factory (5)
- Azure Synapse Analytics (5)
- Covid-19 (5)
- Disaster Recovery (5)
- Generative AI (5)
- Google BigQuery (5)
- Mariadb (5)
- Microsoft (5)
- Scala (5)
- Windows (5)
- Xtrabackup (5)
- Airflow (4)
- Analytics (4)
- Apex (4)
- Cloud Security (4)
- Cloud Spanner (4)
- CockroachDB (4)
- Data Management (4)
- Data Pipeline (4)
- Data Security (4)
- Data Strategy (4)
- Database Administrator (4)
- Database Management (4)
- Database Migration (4)
- Dataflow (4)
- Fusion Middleware (4)
- Google (4)
- Oracle Autonomous Database (Adb) (4)
- Oracle Cloud (4)
- Prometheus (4)
- Redhat (4)
- Slob (4)
- Ssl (4)
- Terraform (4)
- Amazon Relational Database Service (Rds) (3)
- Apache Kafka (3)
- Apexexport (3)
- Aurora (3)
- Business Intelligence (3)
- Cloud Armor (3)
- Cloud Database (3)
- Cloud FinOps (3)
- Cosmos Db (3)
- Data Analytics (3)
- Data Integration (3)
- Database Monitoring (3)
- Database Troubleshooting (3)
- Database Upgrade (3)
- Databases (3)
- Dataops (3)
- Digital Transformation (3)
- ERP (3)
- Google Chrome (3)
- Google Cloud Sql (3)
- Google Workspace (3)
- Graphite (3)
- Heterogeneous Database Migration (3)
- Liquibase (3)
- Oracle Data Guard (3)
- Oracle Live Sql (3)
- Oracle Rac (3)
- Perl (3)
- Rdbms (3)
- Remote Teams (3)
- S3 (3)
- SAP (3)
- Tensorflow (3)
- Adf (2)
- Adop (2)
- Amazon Data Migration Service (2)
- Amazon Ec2 (2)
- Amazon S3 (2)
- Apache Flink (2)
- Ashdump (2)
- Atp (2)
- Autonomous (2)
- Awr Data Mining (2)
- Cloud Cost Optimization (2)
- Cloud Data Fusion (2)
- Cloud Hosting (2)
- Cloud Infrastructure (2)
- Cloud Shell (2)
- Cloud Sql (2)
- Conferences (2)
- Cosmosdb (2)
- Cost Management (2)
- Cyber Security (2)
- Data Analysis (2)
- Data Discovery (2)
- Data Engineering (2)
- Data Migration (2)
- Data Modeling (2)
- Data Quality (2)
- Data Streaming (2)
- Data Warehouse (2)
- Database Consulting (2)
- Database Migrations (2)
- Dataguard (2)
- Docker-Composer (2)
- Enterprise Data Platform (EDP) (2)
- Etl (2)
- Events (2)
- Gemini (2)
- Health Check (2)
- Infrastructure As Code (2)
- Innodb Cluster (2)
- Innodb File Structure (2)
- Innodb Group Replication (2)
- NLP (2)
- Neo4J (2)
- Nosql (2)
- Open Source Database (2)
- Oracle Datase (2)
- Oracle Extended Manager (Oem) (2)
- Oracle Flashback (2)
- Oracle Forms (2)
- Oracle Installation (2)
- Oracle Io Testing (2)
- Podcast (2)
- Power Bi (2)
- Redshift (2)
- Remote DBA (2)
- Remote Sre (2)
- SAP HANA Cloud (2)
- Single Sign-On (2)
- Webinars (2)
- X5 (2)
- Actifio (1)
- Adf Custom Email (1)
- Adrci (1)
- Advanced Data Services (1)
- Afd (1)
- Ahf (1)
- Alloydb (1)
- Amazon (1)
- Amazon Athena (1)
- Amazon Aurora Backtrack (1)
- Amazon Efs (1)
- Amazon Redshift (1)
- Amazon Sagemaker (1)
- Amazon Vpc Flow Logs (1)
- Analysis (1)
- Analytical Models (1)
- Anisble (1)
- Anthos (1)
- Apache (1)
- Apache Nifi (1)
- Apache Spark (1)
- Application Migration (1)
- Ash (1)
- Asmlib (1)
- Atlas CLI (1)
- Awr Mining (1)
- Aws Lake Formation (1)
- Azure Data Lake (1)
- Azure Data Lake Analytics (1)
- Azure Data Lake Store (1)
- Azure Data Migration Service (1)
- Azure OpenAI (1)
- Azure Sql Data Warehouse (1)
- Batches In Cassandra (1)
- Business Insights (1)
- Chown (1)
- Chrome Security (1)
- Cloud Browser (1)
- Cloud Build (1)
- Cloud Consulting (1)
- Cloud Data Warehouse (1)
- Cloud Database Management (1)
- Cloud Dataproc (1)
- Cloud Foundry (1)
- Cloud Manager (1)
- Cloud Networking (1)
- Cloud SQL Replica (1)
- Cloud Scheduler (1)
- Cloud Services (1)
- Cloud Strategies (1)
- Compliance (1)
- Conversational AI (1)
- DAX (1)
- Data Analytics Platform (1)
- Data Box (1)
- Data Classification (1)
- Data Cleansing (1)
- Data Encryption (1)
- Data Estate (1)
- Data Flow Management (1)
- Data Insights (1)
- Data Integrity (1)
- Data Lake (1)
- Data Leader (1)
- Data Lifecycle Management (1)
- Data Lineage (1)
- Data Masking (1)
- Data Mesh (1)
- Data Migration Assistant (1)
- Data Migration Service (1)
- Data Mining (1)
- Data Monetization (1)
- Data Policy (1)
- Data Profiling (1)
- Data Protection (1)
- Data Retention (1)
- Data Safe (1)
- Data Sheets (1)
- Data Summit (1)
- Data Vault (1)
- Data Warehouse Modernization (1)
- Database Auditing (1)
- Database Consultant (1)
- Database Link (1)
- Database Modernization (1)
- Database Provisioning (1)
- Database Provisioning Failed (1)
- Database Replication (1)
- Database Scaling (1)
- Database Schemas (1)
- Database Security (1)
- Databricks (1)
- Datascape 59 (1)
- DeepSeek (1)
- Duet AI (1)
- Edp (1)
- Gcp Compute (1)
- Gcp-Spanner (1)
- Global Analytics (1)
- Google Analytics (1)
- Google Cloud Architecture Framework (1)
- Google Cloud Data Services (1)
- Google Cloud Partner (1)
- Google Cloud Spanner (1)
- Google Cloud VMware Engine (1)
- Google Compute Engine (1)
- Google Dataflow (1)
- Google Datalab (1)
- Google Grab And Go (1)
- Graph Algorithms (1)
- Graph Databases (1)
- Graph Inferences (1)
- Graph Theory (1)
- GraphQL (1)
- Healthcheck (1)
- Information (1)
- Infrastructure As A Code (1)
- Innobackupex (1)
- Innodb Concurrency (1)
- Innodb Flush Method (1)
- It Industry (1)
- Kubeflow (1)
- LMSYS Chatbot Arena (1)
- Linux Host Monitoring (1)
- Linux Storage Appliance (1)
- Looker (1)
- MMLU (1)
- Managed Services (1)
- Migrate (1)
- Migrating Ssis Catalog (1)
- Migration Checklist (1)
- MongoDB Atlas (1)
- MongoDB Compass (1)
- Newsroom (1)
- Nifi (1)
- OPEX (1)
- ORAPKI (1)
- Odbcs (1)
- Odbs (1)
- On-Premises (1)
- Ora-01852 (1)
- Ora-7445 (1)
- Oracle Cursor (1)
- Oracle Database Appliance (1)
- Oracle Database Se2 (1)
- Oracle Database Standard Edition 2 (1)
- Oracle Database Upgrade (1)
- Oracle Database@Google Cloud (1)
- Oracle Exadata Smart Scan (1)
- Oracle Licensing (1)
- Oracle Linux Virtualization Manager (1)
- Oracle Oda (1)
- Oracle Openworld (1)
- Oracle Parallelism (1)
- Oracle RMAN (1)
- Oracle Rdbms (1)
- Oracle Real Application Clusters (1)
- Oracle Reports (1)
- Oracle Security (1)
- Oracle Wallet (1)
- Perfomrance (1)
- Performance Schema (1)
- Policy (1)
- Prompt Engineering (1)
- Public Cloud (1)
- Pythian News (1)
- Rdb (1)
- Replication Compatibility (1)
- Replication Error (1)
- Retail (1)
- Scaling Ir (1)
- Securing Sql Server (1)
- Security Compliance (1)
- Serverless Computing (1)
- Sso (1)
- Tenserflow (1)
- Teradata (1)
- Vertex AI (1)
- Vertica (1)
- Videos (1)
- Workspace Security (1)
- Xbstream (1)
- May 2025 (1)
- March 2025 (2)
- February 2025 (1)
- January 2025 (2)
- December 2024 (1)
- October 2024 (2)
- September 2024 (7)
- August 2024 (4)
- July 2024 (2)
- June 2024 (6)
- May 2024 (3)
- April 2024 (2)
- February 2024 (1)
- January 2024 (11)
- December 2023 (10)
- November 2023 (11)
- October 2023 (10)
- September 2023 (8)
- August 2023 (6)
- July 2023 (2)
- June 2023 (13)
- May 2023 (4)
- April 2023 (6)
- March 2023 (10)
- February 2023 (6)
- January 2023 (5)
- December 2022 (10)
- November 2022 (10)
- October 2022 (10)
- September 2022 (13)
- August 2022 (16)
- July 2022 (12)
- June 2022 (13)
- May 2022 (11)
- April 2022 (4)
- March 2022 (5)
- February 2022 (4)
- January 2022 (14)
- December 2021 (16)
- November 2021 (11)
- October 2021 (6)
- September 2021 (11)
- August 2021 (6)
- July 2021 (9)
- June 2021 (4)
- May 2021 (8)
- April 2021 (16)
- March 2021 (16)
- February 2021 (6)
- January 2021 (12)
- December 2020 (12)
- November 2020 (17)
- October 2020 (11)
- September 2020 (10)
- August 2020 (11)
- July 2020 (13)
- June 2020 (6)
- May 2020 (9)
- April 2020 (18)
- March 2020 (21)
- February 2020 (13)
- January 2020 (15)
- December 2019 (10)
- November 2019 (11)
- October 2019 (12)
- September 2019 (16)
- August 2019 (15)
- July 2019 (10)
- June 2019 (16)
- May 2019 (20)
- April 2019 (21)
- March 2019 (14)
- February 2019 (18)
- January 2019 (18)
- December 2018 (5)
- November 2018 (16)
- October 2018 (12)
- September 2018 (20)
- August 2018 (27)
- July 2018 (31)
- June 2018 (34)
- May 2018 (28)
- April 2018 (27)
- March 2018 (17)
- February 2018 (8)
- January 2018 (20)
- December 2017 (14)
- November 2017 (4)
- October 2017 (1)
- September 2017 (3)
- August 2017 (5)
- July 2017 (4)
- June 2017 (2)
- May 2017 (7)
- April 2017 (7)
- March 2017 (8)
- February 2017 (8)
- January 2017 (5)
- December 2016 (3)
- November 2016 (4)
- October 2016 (8)
- September 2016 (9)
- August 2016 (10)
- July 2016 (9)
- June 2016 (8)
- May 2016 (13)
- April 2016 (16)
- March 2016 (13)
- February 2016 (11)
- January 2016 (6)
- December 2015 (11)
- November 2015 (11)
- October 2015 (5)
- September 2015 (16)
- August 2015 (4)
- July 2015 (1)
- June 2015 (3)
- May 2015 (6)
- April 2015 (5)
- March 2015 (5)
- February 2015 (4)
- January 2015 (3)
- December 2014 (7)
- October 2014 (4)
- September 2014 (6)
- August 2014 (6)
- July 2014 (16)
- June 2014 (7)
- May 2014 (6)
- April 2014 (5)
- March 2014 (4)
- February 2014 (10)
- January 2014 (6)
- December 2013 (8)
- November 2013 (12)
- October 2013 (9)
- September 2013 (6)
- August 2013 (7)
- July 2013 (9)
- June 2013 (7)
- May 2013 (7)
- April 2013 (4)
- March 2013 (7)
- February 2013 (4)
- January 2013 (4)
- December 2012 (6)
- November 2012 (8)
- October 2012 (9)
- September 2012 (3)
- August 2012 (5)
- July 2012 (5)
- June 2012 (7)
- May 2012 (11)
- April 2012 (1)
- March 2012 (8)
- February 2012 (1)
- January 2012 (6)
- December 2011 (8)
- November 2011 (5)
- October 2011 (9)
- September 2011 (6)
- August 2011 (4)
- July 2011 (1)
- June 2011 (1)
- May 2011 (5)
- April 2011 (2)
- February 2011 (2)
- January 2011 (2)
- December 2010 (1)
- November 2010 (7)
- October 2010 (3)
- September 2010 (8)
- August 2010 (2)
- July 2010 (4)
- June 2010 (7)
- May 2010 (2)
- April 2010 (1)
- March 2010 (3)
- February 2010 (3)
- January 2010 (2)
- November 2009 (6)
- October 2009 (6)
- August 2009 (3)
- July 2009 (3)
- June 2009 (3)
- May 2009 (2)
- April 2009 (8)
- March 2009 (6)
- February 2009 (4)
- January 2009 (3)
- November 2008 (3)
- October 2008 (7)
- September 2008 (6)
- August 2008 (9)
- July 2008 (9)
- June 2008 (9)
- May 2008 (9)
- April 2008 (8)
- March 2008 (4)
- February 2008 (3)
- January 2008 (3)
- December 2007 (2)
- November 2007 (7)
- October 2007 (1)
- August 2007 (4)
- July 2007 (3)
- June 2007 (8)
- May 2007 (4)
- April 2007 (2)
- March 2007 (2)
- February 2007 (5)
- January 2007 (8)
- December 2006 (1)
- November 2006 (3)
- October 2006 (4)
- September 2006 (3)
- July 2006 (1)
- May 2006 (2)
- April 2006 (1)
- July 2005 (1)
No Comments Yet
Let us know what you think