diff --git a/dbatools.psd1 b/dbatools.psd1
index 130addf41b..e6bdf59e18 100644
--- a/dbatools.psd1
+++ b/dbatools.psd1
@@ -11,7 +11,7 @@
RootModule = 'dbatools.psm1'
# Version number of this module.
- ModuleVersion = '0.8.3.5'
+ ModuleVersion = '0.8.4.0'
# ID used to uniquely identify this module
GUID = '9d139310-ce45-41ce-8e8b-d76335aa1789'
@@ -110,7 +110,7 @@
'Reset-SqlAdmin',
'Watch-SqlDbLogin',
'Expand-SqlTLogResponsibly',
- 'Show-SqlMigrationConstraint',
+ 'Test-SqlMigrationConstraint',
'Get-SqlRegisteredServerName',
'Test-SqlNetworkLatency',
'Find-SqlDuplicateIndex',
@@ -122,7 +122,8 @@
'Set-SqlTempDbConfiguration',
'Test-SqlTempDbConfiguration',
'Repair-SqlOrphanUser',
- 'Remove-SqlOrphanUser'
+ 'Remove-SqlOrphanUser',
+ 'Find-SqlUnusedIndex'
)
# Cmdlets to export from this module
diff --git a/dbatools.psm1 b/dbatools.psm1
index a71d4e13c9..5801aa03b3 100644
--- a/dbatools.psm1
+++ b/dbatools.psm1
@@ -11,6 +11,7 @@ Set-Alias -Name Reset-SqlSaPassword -Value Reset-SqlAdmin
Set-Alias -Name Copy-SqlUserDefinedMessage -Value Copy-SqlCustomError
Set-Alias -Name Copy-SqlJobServer -Value Copy-SqlServerAgent
Set-Alias -Name Restore-HallengrenBackup -Value Restore-SqlBackupFromDirectory
+Set-Alias -Name Test-SqlMigrationConstraint -Value Show-SqlMigrationConstraint
# Strictmode coming when I've got time.
# Set-StrictMode -Version Latest
diff --git a/functions/Find-SqlUnusedIndex.ps1 b/functions/Find-SqlUnusedIndex.ps1
new file mode 100644
index 0000000000..87ec3fa432
--- /dev/null
+++ b/functions/Find-SqlUnusedIndex.ps1
@@ -0,0 +1,284 @@
+Function Find-SqlUnusedIndex
+{
+<#
+.SYNOPSIS
+Find Unused indexes
+
+.DESCRIPTION
+This command will help you to find Unused indexes on a database or a list of databases
+
+Also tells how much space you can save by dropping the index.
+We show the type of compression so you can make a more considered decision.
+For now only supported for CLUSTERED and NONCLUSTERED indexes
+
+You can select the indexes you want to drop on the gridview and by click OK the drop statement will be generated.
+
+Output:
+ TableName
+ IndexName
+ KeyCols
+ IncludedCols
+ IndexSizeMB
+ IndexType
+ CompressionDesc (When 2008+)
+ NumberRows
+ IsDisabled
+ IsFiltered (When 2008+)
+
+.PARAMETER SqlServer
+The SQL Server instance.
+
+.PARAMETER SqlCredential
+Allows you to login to servers using SQL Logins as opposed to Windows Auth/Integrated/Trusted. To use:
+
+$scred = Get-Credential, then pass $scred object to the -SqlCredential parameter.
+
+Windows Authentication will be used if SqlCredential is not specified. SQL Server does not accept Windows credentials being passed as credentials. To connect as a different Windows user, run PowerShell as that user.
+
+.PARAMETER FileName
+The file to write to.
+
+.PARAMETER NoClobber
+Do not overwrite file
+
+.PARAMETER Append
+Append to file
+
+.NOTES
+Original Author: Aaron Nelson (@SQLvariant), SQLvariant.com
+dbatools PowerShell module (https://dbatools.io, clemaire@gmail.com)
+Copyright (C) 2016 Chrissy LeMaire
+
+This program is free software: you can redistribute it and/or modify
+it under the terms of the GNU General Public License as published by
+the Free Software Foundation, either version 3 of the License, or
+(at your option) any later version.
+
+This program is distributed in the hope that it will be useful,
+but WITHOUT ANY WARRANTY; without even the implied warranty of
+MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
+GNU General Public License for more details.
+
+You should have received a copy of the GNU General Public License
+along with this program. If not, see .
+
+.LINK
+https://dbatools.io/Find-SqlUnusedIndex
+
+.EXAMPLE
+Find-SqlUnusedIndex -SqlServer sql2005 -FileName C:\temp\sql2005-UnusedIndexes.sql
+
+Exports SQL for the Unused indexes in server "sql2005" choosen on grid-view and writes them to the file "C:\temp\sql2005-UnusedIndexes.sql"
+
+.EXAMPLE
+Find-SqlUnusedIndex -SqlServer sqlserver2016 -SqlCredential $cred
+
+Will find exact Unused indexes on all user databases present on sqlserver2016 will be verified using SQL credentials.
+
+.EXAMPLE
+Find-SqlUnusedIndex -SqlServer sqlserver2016 -Databases db1, db2
+
+Will find exact Unused indexes on both db1 and db2 databases
+
+.EXAMPLE
+Find-SqlUnusedIndex -SqlServer sqlserver2016
+
+Will find exact Unused indexes on all user databases
+
+#>
+ [CmdletBinding(SupportsShouldProcess = $true)]
+ Param (
+ [parameter(Mandatory = $true, ValueFromPipeline = $true)]
+ [Alias("ServerInstance", "SqlInstance")]
+ [object[]]$SqlServer,
+ [object]$SqlCredential,
+ [Alias("OutFile", "Path")]
+ [string]$FilePath,
+ [switch]$NoClobber,
+ [switch]$Append
+ )
+ DynamicParam { if ($SqlServer) { return Get-ParamSqlDatabases -SqlServer $SqlServer -SqlCredential $SqlCredential } }
+
+ BEGIN
+ {
+
+ # Support Compression 2008+
+ $CompletelyUnusedQuery = "SELECT DB_NAME(database_id) AS 'DatabaseName',
+ s.name AS 'SchemaName',
+ t.name AS 'TableName',
+ i.object_id ,
+ i.name AS 'IndexName',
+ i.index_id,
+ i.type_desc ,
+ user_seeks ,
+ user_scans ,
+ user_lookups ,
+ user_updates ,
+ last_user_seek ,
+ last_user_scan ,
+ last_user_lookup ,
+ last_user_update ,
+ system_seeks ,
+ system_scans ,
+ system_lookups ,
+ system_updates ,
+ last_system_seek ,
+ last_system_scan ,
+ last_system_lookup ,
+ last_system_update
+ FROM SYS.TABLES T
+ JOIN SYS.SCHEMAS S
+ ON T.schema_id = s.schema_id
+ JOIN SYS.indexes i
+ ON i.object_id = t.object_id
+ LEFT OUTER JOIN sys.dm_db_index_usage_stats iu
+ ON iu.object_id = i.object_id
+ AND iu.index_id = i.index_id
+ WHERE iu.database_id = DB_ID()
+ AND OBJECTPROPERTY(i.[object_id], 'IsMSShipped') = 0
+ AND user_seeks = 0
+ AND user_scans = 0
+ AND user_lookups = 0
+ AND i.type_desc NOT IN ('HEAP', 'CLUSTERED COLUMNSTORE')"
+
+ if ($FilePath.Length -gt 0)
+ {
+ $directory = Split-Path $FilePath
+ $exists = Test-Path $directory
+
+ if ($exists -eq $false)
+ {
+ throw "Parent directory $directory does not exist"
+ }
+ }
+
+ Write-Output "Attempting to connect to Sql Server.."
+ $sourceserver = Connect-SqlServer -SqlServer $SqlServer -SqlCredential $SqlCredential
+ }
+
+ PROCESS
+ {
+
+ if ($sourceserver.versionMajor -lt 9)
+ {
+ throw "This function does not support versions lower than SQL Server 2005 (v9)"
+ }
+
+ # Convert from RuntimeDefinedParameter object to regular array
+ $databases = $psboundparameters.Databases
+
+ if ($pipedatabase.Length -gt 0)
+ {
+ $Source = $pipedatabase[0].parent.name
+ $databases = $pipedatabase.name
+ }
+
+ if ($databases.Count -eq 0)
+ {
+ $databases = ($sourceserver.Databases | Where-Object {$_.isSystemObject -eq 0 -and $_.Status -ne "Offline"}).Name
+ }
+
+ if ($databases.Count -gt 0)
+ {
+ foreach ($db in $databases)
+ {
+ try
+ {
+ Write-Output "Getting indexes from database '$db'"
+
+ $query = $CompletelyUnusedQuery
+
+ $UnusedIndex = $sourceserver.Databases[$db].ExecuteWithResults($query)
+
+ $scriptGenerated = $false
+
+ if ($UnusedIndex.Tables[0].Rows.Count -gt 0)
+ {
+ $indexesToDrop = $UnusedIndex.Tables[0] | Out-GridView -Title "Unused Indexes on $($db) database - Choose indexes to generate DROP script" -PassThru
+
+ #When only 1 line selected, the count does not work
+ if ($indexesToDrop.Count -gt 0 -or !([string]::IsNullOrEmpty($indexesToDrop)))
+ {
+ #reset to #Yes
+ $result = 0
+
+ if ($UnusedIndex.Tables[0].Rows.Count -eq $indexesToDrop.Count)
+ {
+ $title = "Indexes to drop on databases '$db':"
+ $message = "You will generate drop statements to all indexes.`r`nPerhaps you want to keep at least one.`r`nDo you wish to generate the script anyway? (Y/N)"
+ $yes = New-Object System.Management.Automation.Host.ChoiceDescription "&Yes", "Will continue"
+ $no = New-Object System.Management.Automation.Host.ChoiceDescription "&No", "Will exit"
+ $options = [System.Management.Automation.Host.ChoiceDescription[]]($yes, $no)
+ $result = $host.ui.PromptForChoice($title, $message, $options, 0)
+ }
+
+ if ($result -eq 0) #default OR answer = YES
+ {
+ $sqlDropScript = "/*`r`n"
+ $sqlDropScript += "`tScript generated @ $(Get-Date -format "yyyy-MM-dd HH:mm:ss.ms")`r`n"
+ $sqlDropScript += "`tDatabase: $($db)`r`n"
+ $sqlDropScript += "`tConfirm that you have choosen the right indexes before execute the drop script`r`n"
+ $sqlDropScript += "*/`r`n"
+
+ foreach ($index in $indexesToDrop)
+ {
+ if ($FilePath.Length -gt 0)
+ {
+ Write-Output "Exporting $($index.TableName).$($index.IndexName)"
+ }
+
+ $sqlDropScript += "USE [$($index.DatabaseName)]`r`n"
+ $sqlDropScript += "GO`r`n"
+ $sqlDropScript += "IF EXISTS (SELECT 1 FROM sys.indexes WHERE [object_id] = OBJECT_ID('$($index.TableName)') AND name = '$($index.IndexName)')`r`n"
+ $sqlDropScript += " DROP INDEX $($index.TableName).$($index.IndexName)`r`n"
+ $sqlDropScript += "GO`r`n`r`n"
+ }
+
+ if ($FilePath.Length -gt 0)
+ {
+ $sqlDropScript | Out-File -FilePath $FilePath -Append:$Append -NoClobber:$NoClobber
+ }
+ else
+ {
+ Write-Output $sqlDropScript
+ }
+
+ $scriptGenerated = $true
+ }
+ else #answer = no
+ {
+ Write-Warning "Script will not be generated for database '$db'"
+ }
+ }
+ }
+ else
+ {
+ Write-Output "No Unused indexes found!"
+ }
+ }
+ catch
+ {
+ throw $_
+ }
+ }
+
+ if ($scriptGenerated)
+ {
+ Write-Warning "Confirm the generated script before execute!"
+ }
+ if ($FilePath.Length -gt 0)
+ {
+ Write-Output "Script generated to $FilePath"
+ }
+ }
+ else
+ {
+ Write-Output "There are no databases to analyse."
+ }
+ }
+
+ END
+ {
+ $sourceserver.ConnectionContext.Disconnect()
+ }
+}
\ No newline at end of file
diff --git a/functions/Get-DiskSpace.ps1 b/functions/Get-DiskSpace.ps1
index 125e452b30..aebafd5dba 100644
--- a/functions/Get-DiskSpace.ps1
+++ b/functions/Get-DiskSpace.ps1
@@ -70,7 +70,7 @@ Returns a custom object filled with information for server1, server2 and server3
try
{
- $ipaddr = (Test-Connection $computername -count 1).Ipv4Address
+ $ipaddr = (Test-Connection $server -count 1).Ipv4Address | Select-Object -First 1
$disks = Get-WmiObject -ComputerName $ipaddr -Query $query | Sort-Object -Property Name
}
catch
diff --git a/functions/Repair-SqlOrphanUser.ps1 b/functions/Repair-SqlOrphanUser.ps1
index 4784f3e181..6ffacf0b9c 100644
--- a/functions/Repair-SqlOrphanUser.ps1
+++ b/functions/Repair-SqlOrphanUser.ps1
@@ -11,7 +11,7 @@ If the matching login exists it must be:
.Enabled
.Not a system object
.Not locked
- .Have the same name that login
+ .Have the same name that user
You can drop users that does not have their matching login by especifing the parameter -RemoveNotExisting This will be made by calling Remove-SqlOrphanUser function.
@@ -68,12 +68,12 @@ Repair-SqlOrphanUser -SqlServer sqlserver2014a -Databases db1, db2
Will find and repair all orphan users on both db1 and db2 databases
.EXAMPLE
-Remove-SqlOrphanUser -SqlServer sqlserver2014a -Databases db1 -Users OrphanUser
+Repair-SqlOrphanUser -SqlServer sqlserver2014a -Databases db1 -Users OrphanUser
Will find and repair user 'OrphanUser' on 'db1' database
.EXAMPLE
-Remove-SqlOrphanUser -SqlServer sqlserver2014a -Users OrphanUser
+Repair-SqlOrphanUser -SqlServer sqlserver2014a -Users OrphanUser
Will find and repair user 'OrphanUser' on all databases
diff --git a/functions/Show-SqlMigrationConstraint.ps1 b/functions/Show-SqlMigrationConstraint.ps1
index 18dce93abe..8ddbd7037e 100644
--- a/functions/Show-SqlMigrationConstraint.ps1
+++ b/functions/Show-SqlMigrationConstraint.ps1
@@ -1,4 +1,4 @@
-Function Show-SqlMigrationConstraint
+Function Test-SqlMigrationConstraint
{
<#
.SYNOPSIS
@@ -56,10 +56,10 @@ You should have received a copy of the GNU General Public License
along with this program. If not, see .
.LINK
-https://dbatools.io/Show-SqlMigrationConstraint
+https://dbatools.io/Test-SqlMigrationConstraint
.EXAMPLE
-Show-SqlMigrationConstraint -Source sqlserver2014a -Destination sqlcluster
+Test-SqlMigrationConstraint -Source sqlserver2014a -Destination sqlcluster
Description
@@ -67,7 +67,7 @@ All databases will be verified for features in use that can't be supported on th
.EXAMPLE
-Show-SqlMigrationConstraint -Source sqlserver2014a -Destination sqlcluster -SqlCredential $cred
+Test-SqlMigrationConstraint -Source sqlserver2014a -Destination sqlcluster -SqlCredential $cred
Description
@@ -75,7 +75,7 @@ All databases will be verified for features in use that can't be supported on th
and Windows credentials for sqlcluster.
.EXAMPLE
-Show-SqlMigrationConstraint -Source sqlserver2014a -Destination sqlcluster -Databases db1
+Test-SqlMigrationConstraint -Source sqlserver2014a -Destination sqlcluster -Databases db1
Only db1 database will be verified for features in use that can't be supported on the destination server
#>
diff --git a/functions/Show-SqlWhoIsActive.ps1 b/functions/Show-SqlWhoIsActive.ps1
index 5ea639a594..d77d315867 100644
--- a/functions/Show-SqlWhoIsActive.ps1
+++ b/functions/Show-SqlWhoIsActive.ps1
@@ -323,6 +323,28 @@ Similar to running sp_WhoIsActive @get_outer_command = 1, @find_block_leaders =
return $database
}
+ function Get-WindowTitle
+ {
+ $title = "sp_WhoIsActive "
+ foreach ($param in $passedparams)
+ {
+ $sqlparam = $paramdictionary[$param]
+ $value = $localparams[$param]
+
+ switch ($value)
+ {
+ $true { $value = 1 }
+ $false { $value = 0 }
+ }
+
+ $title = "$title $sqlparam = $value, "
+ }
+
+
+ $title = $title.TrimEnd(", ")
+ return $title
+ }
+
Function Invoke-SpWhoisActive
{
$sqlconnection = New-Object System.Data.SqlClient.SqlConnection
@@ -338,7 +360,7 @@ Similar to running sp_WhoIsActive @get_outer_command = 1, @find_block_leaders =
$sqlcommand.CommandType = "StoredProcedure"
$sqlcommand.CommandText = "dbo.sp_WhoIsActive"
$sqlcommand.Connection = $sqlconnection
-
+
foreach ($param in $passedparams)
{
$sqlparam = $paramdictionary[$param]
@@ -460,13 +482,15 @@ Similar to running sp_WhoIsActive @get_outer_command = 1, @find_block_leaders =
if ($OutputAs -eq "DataTable")
{
- return $datatable
+ $datatable.Tables
}
else
{
+ $windowtitle = Get-WindowTitle
+
foreach ($table in $datatable.Tables)
{
- $table | Out-GridView -Title "sp_WhoIsActive"
+ $table | Out-GridView -Title $windowtitle
}
}
}