Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Get-DbaHelpIndex - Bad joins based on Index Name instead of Index ID when Indexes in same DB named the same #9447 #9473

Merged
merged 4 commits into from
Oct 5, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
14 changes: 7 additions & 7 deletions public/Get-DbaHelpIndex.ps1
Original file line number Diff line number Diff line change
Expand Up @@ -404,17 +404,17 @@ function Get-DbaHelpIndex {
name AS IndexName ,
STUFF((SELECT N', ' + ColumnName
FROM cteIndex ci2
WHERE ci2.name = ci.name
WHERE ci2.name = ci.name AND ci2.object_id=ci.object_id
AND ci2.is_included_column = 0
GROUP BY ci2.index_column_id ,
ci2.ColumnName
ORDER BY ci2.index_column_id
FOR XML PATH(N'') ,
TYPE).value(N'.[1]', N'nvarchar(1000)'), 1,
2, N'') AS KeyColumns ,
ISNULL(STUFF((SELECT N', ' + ColumnName
ISNULL(STUFF((SELECT N', ' + ColumnName
FROM cteIndex ci3
WHERE ci3.name = ci.name
WHERE ci3.name = ci.name AND ci3.object_id=ci.object_id
AND ci3.is_included_column = 1
GROUP BY ci3.index_column_id ,
ci3.ColumnName
Expand Down Expand Up @@ -801,17 +801,17 @@ function Get-DbaHelpIndex {
name AS IndexName ,
STUFF((SELECT N', ' + ColumnName
FROM cteIndex ci2
WHERE ci2.name = ci.name
WHERE ci2.name = ci.name and ci2.object_id=ci.object_id
AND ci2.is_included_column = 0
GROUP BY ci2.index_column_id ,
ci2.ColumnName
ORDER BY ci2.index_column_id
FOR XML PATH(N'') ,
TYPE).value(N'.[1]', N'nvarchar(1000)'), 1,
2, N'') AS KeyColumns ,
ISNULL(STUFF((SELECT N', ' + ColumnName
ISNULL(STUFF((SELECT N', ' + ColumnName
FROM cteIndex ci3
WHERE ci3.name = ci.name
WHERE ci3.name = ci.name and ci3.object_id=ci.object_id
AND ci3.is_included_column = 1
GROUP BY ci3.index_column_id ,
ci3.ColumnName
Expand Down Expand Up @@ -1103,4 +1103,4 @@ function Get-DbaHelpIndex {
}
}
}
}
}
31 changes: 24 additions & 7 deletions tests/Get-DbaHelpIndex.Tests.ps1
Original file line number Diff line number Diff line change
Expand Up @@ -2,13 +2,14 @@ $CommandName = $MyInvocation.MyCommand.Name.Replace(".Tests.ps1", "")
Write-Host -Object "Running $PSCommandPath" -ForegroundColor Cyan
. "$PSScriptRoot\constants.ps1"

Write-host -Object "${script:instance2}" -ForegroundColor Cyan
Describe "$CommandName Unit Tests" -Tag 'UnitTests' {
Context "Validate parameters" {
[object[]]$params = (Get-Command $CommandName).Parameters.Keys | Where-Object {$_ -notin ('whatif', 'confirm')}
[object[]]$params = (Get-Command $CommandName).Parameters.Keys | Where-Object { $_ -notin ('whatif', 'confirm') }
[object[]]$knownParameters = 'SqlInstance', 'SqlCredential', 'Database', 'ExcludeDatabase', 'InputObject', 'ObjectName', 'IncludeStats', 'IncludeDataTypes', 'Raw', 'IncludeFragmentation', 'EnableException'
$knownParameters += [System.Management.Automation.PSCmdlet]::CommonParameters
It "Should only contain our specific parameters" {
(@(Compare-Object -ReferenceObject ($knownParameters | Where-Object {$_}) -DifferenceObject $params).Count ) | Should Be 0
(@(Compare-Object -ReferenceObject ($knownParameters | Where-Object { $_ }) -DifferenceObject $params).Count ) | Should Be 0
}
}
}
Expand All @@ -22,12 +23,16 @@ Describe "$CommandName Integration Tests" -Tags "IntegrationTests" {
$server.Query("Insert into test values ('value1',1),('value2',2)", $dbname)
$server.Query("create statistics dbatools_stats on test (col2)", $dbname)
$server.Query("select * from test", $dbname)
$server.Query("create table t1(c1 int,c2 int,c3 int,c4 int)", $dbname)
$server.Query("create nonclustered index idx_1 on t1(c1) include(c3)", $dbname)
$server.Query("create table t2(c1 int,c2 int,c3 int,c4 int)", $dbname)
$server.Query("create nonclustered index idx_1 on t2(c1,c2) include(c3,c4)", $dbname)
}
AfterAll {
$null = Get-DbaDatabase -SqlInstance $script:instance2 -Database $dbname | Remove-DbaDatabase -Confirm:$false
}
Context "Command works for indexes" {
$results = Get-DbaHelpIndex -SqlInstance $script:instance2 -Database $dbname
$results = Get-DbaHelpIndex -SqlInstance $script:instance2 -Database $dbname -ObjectName Test
It 'Results should be returned' {
$results | Should Not BeNullOrEmpty
}
Expand All @@ -42,7 +47,7 @@ Describe "$CommandName Integration Tests" -Tags "IntegrationTests" {
}
}
Context "Command works when including statistics" {
$results = Get-DbaHelpIndex -SqlInstance $script:instance2 -Database $dbname -IncludeStats | Where-Object {$_.Statistics}
$results = Get-DbaHelpIndex -SqlInstance $script:instance2 -Database $dbname -ObjectName Test -IncludeStats | Where-Object { $_.Statistics }
It 'Results should be returned' {
$results | Should Not BeNullOrEmpty
}
Expand All @@ -51,7 +56,7 @@ Describe "$CommandName Integration Tests" -Tags "IntegrationTests" {
}
}
Context "Command output includes data types" {
$results = Get-DbaHelpIndex -SqlInstance $script:instance2 -Database $dbname -IncludeDataTypes
$results = Get-DbaHelpIndex -SqlInstance $script:instance2 -Database $dbname -ObjectName Test -IncludeDataTypes
It 'Results should be returned' {
$results | Should Not BeNullOrEmpty
}
Expand All @@ -60,7 +65,7 @@ Describe "$CommandName Integration Tests" -Tags "IntegrationTests" {
}
}
Context "Formatting is correct" {
$results = Get-DbaHelpIndex -SqlInstance $script:instance2 -Database $dbname -IncludeFragmentation
$results = Get-DbaHelpIndex -SqlInstance $script:instance2 -Database $dbname -ObjectName Test -IncludeFragmentation
It 'Formatted as strings' {
$results.IndexReads | Should BeOfType 'String'
$results.IndexUpdates | Should BeOfType 'String'
Expand All @@ -72,7 +77,7 @@ Describe "$CommandName Integration Tests" -Tags "IntegrationTests" {
}
}
Context "Formatting is correct for raw" {
$results = Get-DbaHelpIndex -SqlInstance $script:instance2 -Database $dbname -raw -IncludeFragmentation
$results = Get-DbaHelpIndex -SqlInstance $script:instance2 -Database $dbname -ObjectName Test -raw -IncludeFragmentation
It 'Formatted as Long' {
$results.IndexReads | Should BeOfType 'Long'
$results.IndexUpdates | Should BeOfType 'Long'
Expand All @@ -84,4 +89,16 @@ Describe "$CommandName Integration Tests" -Tags "IntegrationTests" {
$results.IndexFragInPercent | Should BeOfType 'Double'
}
}
Context "Result is correct for tables having the indexes with the same names" {
$results = Get-DbaHelpIndex -SqlInstance $script:instance2 -Database $dbname
It 'Table t1 has correct index key columns and included columns' {
$results.where({ $_.object -eq '[dbo].[t1]' }).KeyColumns | Should -be 'c1'
$results.where({ $_.object -eq '[dbo].[t1]' }).IncludeColumns | Should -be 'c3'
}
It 'Table t2 has correct index key columns and included columns' {
$results.where({ $_.object -eq '[dbo].[t2]' }).KeyColumns | Should -be 'c1, c2'
$results.where({ $_.object -eq '[dbo].[t2]' }).IncludeColumns | Should -be 'c3, c4'
}

}
}
Loading