From beb9f04f32a86bf8f6ab5f2938e2572698b45f3f Mon Sep 17 00:00:00 2001 From: John McCall Date: Tue, 24 Jan 2023 10:55:36 -0500 Subject: [PATCH] sp_helpme - add incl col (#267) * remove accident file * add included cols for index output * update copyright date * Updated bundled installer * follow column naming convention * Updated bundled installer * remove appveyor ci * exclude lint rule * Updated bundled installer * clean up docs * only return result set if rows * improve unit test independence from tsqlt schema * Updated bundled installer * improve unit tests * fix typo * fix test * ignore lint for autogen file * skip ci for artifact * fix db context * pluralize col to match existing * Updated bundled installer [skip ci] * tsqllint cant peek inside dynamic sql * Updated bundled installer [skip ci] * fix ssl issues * fix ssl in unit tests * fix sp_doc artifact ssl issue Co-authored-by: lowlydba --- .github/workflows/artifacts.yml | 2 +- .github/workflows/lint.yml | 2 + .github/workflows/sqlserver-unit.yml | 6 +-- appveyor/appveyor.yml | 47 ----------------- appveyor/install_dependencies.ps1 | 29 ----------- appveyor/install_tsqlt.ps1 | 71 ------------------------- appveyor/run_pester_tests.ps1 | 49 ----------------- appveyor/start_sqlserver.ps1 | 16 ------ docs/README.md | 12 +---- install_dba-multitool.sql | 61 ++++++++++++++++++++-- sp_doc.sql | 2 +- sp_estindex.sql | 2 +- sp_helpme.sql | 55 +++++++++++++++++++- sp_sizeoptimiser.sql | 2 +- tests/sp_doc.Tests.ps1 | 7 ++- tests/sp_estindex.Tests.ps1 | 7 ++- tests/sp_helpme.Tests.ps1 | 7 ++- tests/sp_helpme.Tests.sql | 78 +++++++++++++++++++++------- tests/sp_sizeoptimiser.Tests.ps1 | 7 ++- 19 files changed, 190 insertions(+), 272 deletions(-) delete mode 100644 appveyor/appveyor.yml delete mode 100644 appveyor/install_dependencies.ps1 delete mode 100644 appveyor/install_tsqlt.ps1 delete mode 100644 appveyor/run_pester_tests.ps1 delete mode 100644 appveyor/start_sqlserver.ps1 diff --git a/.github/workflows/artifacts.yml b/.github/workflows/artifacts.yml index e61f0e60..fb392c08 100644 --- a/.github/workflows/artifacts.yml +++ b/.github/workflows/artifacts.yml @@ -42,5 +42,5 @@ jobs: - name: Commit bundled installer script uses: stefanzweifel/git-auto-commit-action@v4.16.0 with: - commit_message: Updated bundled installer + commit_message: Updated bundled installer [skip ci] file_pattern: ${{ env.INSTALLER_FILE }} diff --git a/.github/workflows/lint.yml b/.github/workflows/lint.yml index 3587acb1..d802a5e1 100644 --- a/.github/workflows/lint.yml +++ b/.github/workflows/lint.yml @@ -8,6 +8,8 @@ on: branches: - main pull_request: + paths-ignore: + - install_dba-multitool.sql jobs: build: diff --git a/.github/workflows/sqlserver-unit.yml b/.github/workflows/sqlserver-unit.yml index 5cc116dd..2ae56e78 100644 --- a/.github/workflows/sqlserver-unit.yml +++ b/.github/workflows/sqlserver-unit.yml @@ -80,11 +80,11 @@ jobs: - name: Update SqlServer Module run: | Install-Module SqlServer -AllowClobber -AllowPreRelease -Force - + - name: Install multitool run: | foreach ($script in (Get-ChildItem -Path "." -Filter "sp_*.sql").Name) { - Invoke-Sqlcmd -ServerInstance $Env:SQLINSTANCE -Database $Env:DATABASE -InputFile $script + Invoke-Sqlcmd -InputFile $script -ConnectionString "Data Source=$Env:SQLINSTANCE;Initial Catalog=$Env:DATABASE;Integrated Security=True;TrustServerCertificate=true" } - name: Run Pester tests with SQLCover @@ -105,7 +105,7 @@ jobs: run: | Write-Output "Generating '$Env:SAMPLE_DATABASE' markdown sample." $Query = "EXEC sp_doc @DatabaseName = '$Env:SAMPLE_DATABASE';" - Invoke-SqlCmd -ServerInstance $Env:SQLINSTANCE -Database $Env:DATABASE -Query $Query -As DataRows | Select-Object -ExpandProperty 'value' | Out-File "$($Env:SAMPLE_DATABASE)-$($Env:SQL_VERSION).md" + Invoke-SqlCmd -Query $Query -As DataRows -ConnectionString "Data Source=$Env:SQLINSTANCE;Initial Catalog=$Env:DATABASE;Integrated Security=True;TrustServerCertificate=true" | Select-Object -ExpandProperty 'value' | Out-File "$($Env:SAMPLE_DATABASE)-$($Env:SQL_VERSION).md" - name: Upload sp_doc sample artifact uses: actions/upload-artifact@v3 diff --git a/appveyor/appveyor.yml b/appveyor/appveyor.yml deleted file mode 100644 index 9a9be2ee..00000000 --- a/appveyor/appveyor.yml +++ /dev/null @@ -1,47 +0,0 @@ -version: 1.6.{build} - -pull_requests: - do_not_increment_build_number: false -max_jobs: 2 -build: false -matrix: - fast_finish: true - -environment: - SQLINSTANCE: "localhost" - DATABASE: "tsqlt" - access_token: - secure: "E5I+i+CQyj9EHusDrPSQKHRXmzmpTujYAoFxlvJjvSRSEQHHzqTBIFR1VuPbwLMi" - APPVEYOR_RDP_PASSWORD: Np^VNSzJI5#OmRdUNqro2T9UVkCdZ - INSTALLER_FILE: "install_dba-multitool.sql" - - matrix: - - APPVEYOR_BUILD_WORKER_IMAGE: Visual Studio 2017 - MSSQL: SQL2016 - DB_INSTANCE: localhost\SQL2016 - LATEST: False - AzureSQL: False - - - APPVEYOR_BUILD_WORKER_IMAGE: Visual Studio 2015 - MSSQL: SQL2014 - DB_INSTANCE: localhost\SQL2014 - LATEST: False - AzureSQL: False - -clone_script: - - git config --global credential.helper store - - ps: Add-Content "$HOME\.git-credentials" "https://$($env:access_token):x-oauth-basic@github.com`n" -NoNewLine - - git config --global user.email "appveyor@lowlydba.com" - - git config --global user.name "Appveyor" - - git config --global core.safecrlf false - - git clone -q --single-branch --branch=%APPVEYOR_PULL_REQUEST_HEAD_REPO_BRANCH% https://github.com/LowlyDBA/dba-multitool.git %APPVEYOR_BUILD_FOLDER% - - cd %APPVEYOR_BUILD_FOLDER% - -install: - - ps: .\appveyor\install_dependencies.ps1 - - ps: .\appveyor\start_sqlserver.ps1 - - ps: .\appveyor\install_tsqlt.ps1 - # - ps: $blockRdp = $true; iex ((new-object net.webclient).DownloadString('https://raw.githubusercontent.com/appveyor/ci/master/scripts/enable-rdp.ps1')) - -test_script: - - ps: .\appveyor\run_pester_tests.ps1 diff --git a/appveyor/install_dependencies.ps1 b/appveyor/install_dependencies.ps1 deleted file mode 100644 index 67ff7884..00000000 --- a/appveyor/install_dependencies.ps1 +++ /dev/null @@ -1,29 +0,0 @@ -#PSScriptAnalyzer rule excludes -[Diagnostics.CodeAnalysis.SuppressMessageAttribute('PSAvoidUsingWriteHost', '')] - -param( - $Color = "Green" -) - -Write-Host "Installing dependencies..." -ForegroundColor $Color - -# DbaTools -if (!(Get-Module -ListAvailable -Name DbaTools)) { - $DbaToolsJob = Start-Job -ScriptBlock { Install-Module DbaTools -Force -AllowClobber } -} - -# Pester -if (!(Get-InstalledModule -Name Pester -MaximumVersion 5.1.9 -ErrorAction SilentlyContinue)) { - Install-Module Pester -Force -AllowClobber -WarningAction SilentlyContinue -SkipPublisherCheck -MaximumVersion 5.1.9 -} - -if (!(Get-Module -Name Pester | Where-Object { $PSItem.Version -lt 5.1.0 })) { - if (Get-Module -Name Pester) { - Remove-Module Pester -Force - } - Import-Module Pester -MaximumVersion 5.1.9 -Force -} - -If ($DbaToolsJob) { - Wait-Job $DbaToolsJob.Id | Out-Null -} diff --git a/appveyor/install_tsqlt.ps1 b/appveyor/install_tsqlt.ps1 deleted file mode 100644 index 1ef9d1c9..00000000 --- a/appveyor/install_tsqlt.ps1 +++ /dev/null @@ -1,71 +0,0 @@ -#PSScriptAnalyzer rule excludes -[Diagnostics.CodeAnalysis.SuppressMessageAttribute('PSAvoidUsingWriteHost', '')] -[Diagnostics.CodeAnalysis.SuppressMessageAttribute('PSAvoidUsingConvertToSecureStringWithPlainText', '')] - -param( - [Parameter()] - [String]$SqlInstance = $env:DB_INSTANCE, - [String]$Database = $env:DATABASE, - [String]$Color = "Green", - [string]$User = $env:AZURE_SQL_USER, - [string]$Pass = $env:AZURE_SQL_PASS, - [bool]$IsAzureSQL = [System.Convert]::ToBoolean($env:AzureSQL) -) - -Write-Host "Downloading and installing tSQLt..." -ForegroundColor $Color - -$DownloadUrl = "http://tsqlt.org/download/tsqlt/?version=" -$TempPath = [System.IO.Path]::GetTempPath() -$ZipFile = Join-Path $TempPath "tSQLt.zip" -$ZipFolder = Join-Path $TempPath "tSQLt" -$InstallFile = Join-Path $ZipFolder "tSQLt.class.sql" -$SetupFile = Join-Path $ZipFolder "PrepareServer.sql" -$CLRSecurityQuery = " -/* Turn off CLR Strict for 2017+ fix */ -IF EXISTS (SELECT 1 FROM sys.configurations WHERE name = 'clr strict security') -BEGIN - EXEC sp_configure 'show advanced options', 1; - RECONFIGURE; - - EXEC sp_configure 'clr strict security', 0; - RECONFIGURE; -END -GO" - -$Hash = @{ - SqlInstance = $SqlInstance - Database = $Database - EnableException = $true -} - -# Cant use latest for AzureSQL yet -# https://github.com/LowlyDBA/dba-multitool/issues/165 -If ($IsAzureSQL) { - $Version = "1-0-5873-27393" - $DownloadUrl = $DownloadUrl + $Version - - # Azure creds - $SecPass = ConvertTo-SecureString -String $Pass -AsPlainText -Force - $Credential = New-Object -TypeName System.Management.Automation.PSCredential -ArgumentList $User, $SecPass - $Hash.add("SqlCredential", $Credential) -} - -# Download -Try { - Invoke-WebRequest -Uri $DownloadUrl -OutFile $ZipFile -ErrorAction Stop -UseBasicParsing - Expand-Archive -Path $ZipFile -DestinationPath $ZipFolder -Force -} - -Catch { - Write-Error -Message "Error downloading tSQLt - try manually fetching from $DownloadUrl" -} - -# Prep -If (-not $IsAzureSQL) { - New-DbaDatabase -SqlInstance $SqlInstance -Database $Database -RecoveryModel Simple | Out-Null - Invoke-Command -ScriptBlock { sqlcmd -S $SqlInstance -d $Database -i $SetupFile } | Out-Null - Invoke-DbaQuery @Hash -Query $CLRSecurityQuery -} - -# Install -Invoke-DbaQuery @Hash -File $InstallFile -Verbose diff --git a/appveyor/run_pester_tests.ps1 b/appveyor/run_pester_tests.ps1 deleted file mode 100644 index 577a90be..00000000 --- a/appveyor/run_pester_tests.ps1 +++ /dev/null @@ -1,49 +0,0 @@ -using namespace System.IO.Path - -#PSScriptAnalyzer rule excludes -[Diagnostics.CodeAnalysis.SuppressMessageAttribute('PSAvoidUsingWriteHost', '')] -[Diagnostics.CodeAnalysis.SuppressMessageAttribute('PSUseShouldProcessForStateChangingFunctions', '')] -[Diagnostics.CodeAnalysis.SuppressMessageAttribute('PSAvoidGlobalVars', '')] -param( - [Parameter()] - [switch]$LocalTest, - [string]$CoverageXMLPath = $env:COV_REPORT, - [string]$SqlInstance = $env:DB_INSTANCE, - [string]$Database = $env:DATABASE, - [bool]$IsAzureSQL = [System.Convert]::ToBoolean($env:AzureSQL), - [string]$User = $env:AZURE_SQL_USER, - [string]$Pass = $env:AZURE_SQL_PASS, - [System.ConsoleColor]$Color = "Green", - [switch]$CodeCoverage -) - -$ErrorActionPreference = "Stop" -$TestFiles = Get-ChildItem -Path .\tests\*.Tests.ps1 -$FailedTests = 0 - -# Install multitool -Get-ChildItem -Path ".\" -Filter "sp_*.sql" | Get-Content | Out-File $Env:INSTALLER_FILE -Encoding ascii -Invoke-DbaQuery -SqlInstance $SqlInstance -Database $Database -File $Env:INSTALLER_FILE - -# Install and loadl SqlServer module to prevent SQLPS loading -Install-Module SqlServer -Force -AllowClobber -Import-Module SqlServer - -# Run Tests -ForEach ($file in $TestFiles) { - Add-AppveyorTest -Name $file.BaseName -Framework NUnit -Filename $file.FullName -Outcome Running - - $PesterResult = Invoke-Pester -Path $file.FullName -Output Detailed -PassThru - $Outcome = "Passed" - If ($PesterResult.FailedCount -gt 0) { - $Outcome = "Failed" - $FailedTests ++ - } - - Update-AppveyorTest -Name $file.BaseName -Framework NUnit -FileName $file.FullName -Outcome $Outcome -Duration $PesterResult.UserDuration.Milliseconds -} - -# Check for failures -If ($FailedTests -gt 0) { - Throw "$FailedTests tests failed." -} diff --git a/appveyor/start_sqlserver.ps1 b/appveyor/start_sqlserver.ps1 deleted file mode 100644 index 13dd54e8..00000000 --- a/appveyor/start_sqlserver.ps1 +++ /dev/null @@ -1,16 +0,0 @@ -#PSScriptAnalyzer rule excludes -[Diagnostics.CodeAnalysis.SuppressMessageAttribute('PSAvoidUsingWriteHost', '')] - -param( - [Parameter()] - [string]$Color = "Green" -) - -Write-Host "Starting SQL Server" -ForegroundColor $Color - -$Instance = $env:MSSQL; -Start-Service "MSSQL`$$Instance"; - -# Tweak appveyor's instance settings -Set-DbaMaxMemory -SqlInstance "localhost" | Out-Null -Set-DbaMaxDop -SqlInstance "localhost" -MaxDop 1 | Out-Null diff --git a/docs/README.md b/docs/README.md index 2e2345e4..cbc636ec 100644 --- a/docs/README.md +++ b/docs/README.md @@ -14,10 +14,6 @@ optimizing storage, on-the-fly documentation, general administrative needs, and more. Each script relies solely on T-SQL to ensure it is secure, requires no third-party software, and can be installed in seconds. -All open source, all free to use under the MIT license. - -Check the below list for technical documentation on each script. - ## Scripts To quickly install/update all the scripts, use install_dba-multitool.sql @@ -34,7 +30,7 @@ For detailed instructions and documentation, see [dba-multitool.org](https://dba ## Compatibility -Tested against versions that are still in the standard support lifecycle. +Only support for versions that are still in [mainstream][mainstream] support is guaranteed. | Version | Tested | | ------- | :----: | @@ -57,17 +53,13 @@ Tested against versions that are still in the standard support lifecycle. *Icon made by [mangsaabguru](https://www.flaticon.com/authors/mangsaabguru) from [www.flaticon.com](https://www.flaticon.com/)* -[appveyor]: https://ci.appveyor.com/project/LowlyDBA/dba-multitool -[azure-badge]: https://img.shields.io/badge/Azure%20SQL-vCurrent-blue?logo=data:image/svg+xml;base64,PHN2ZyBkYXRhLXNsdWctaWQ9InNxbC1kYXRhYmFzZS1ibHVlIiB4bWxucz0iaHR0cDovL3d3dy53My5vcmcvMjAwMC9zdmciIHZpZXdCb3g9IjAgMCA0OSA0OSI+DQogIDxwYXRoIGQ9Im02LjQwNDIxIDcuNDA0NDJ2MzQuMTk1NzhjMCAzLjUyNDMgNy44ODk2OSA2LjQ3NzIgMTcuNjgwMzkgNi40Nzcydi00MC42NzI5OHoiIGZpbGw9IiM4MDgwODAiLz4NCiAgPHBhdGggZD0ibTIzLjg5NDYgNDguMDc3NGguMjg1MmM5Ljc5MDcgMCAxNy42ODA0LTIuODU3NiAxNy42ODA0LTYuNDc3MnYtMzQuMTk1NzhoLTE3Ljk2NTZ6IiBmaWxsPSIjODA4MDgwIi8+DQogIDxwYXRoIGQ9Im0yMy43MDQzIDQ4LjA3NzloLjI4NTJjOS44ODU4IDAgMTcuOTY1Ni0yLjg1NzYgMTcuOTY1Ni02LjQ3NzJ2LTM0LjI5MTAxaC0xOC4xNTU3eiIgZmlsbD0iIzgwODA4MCIvPg0KICA8cGF0aCBkPSJtNDEuODU4NCA3LjQwNTUzYzAgMy41MjQzNy03Ljg4OTcgNi40NzcxNy0xNy42ODA1IDYuNDc3MTctOS43OTA3IDAtMTcuNjgwMzktMi44NTc2LTE3LjY4MDM5LTYuNDc3MTcgMC0zLjYxOTYgNy44ODk2OS02LjQ3NzE4NSAxNy42ODAzOS02LjQ3NzE4NSA5Ljc5MDggMCAxNy42ODA1IDIuOTUyODM1IDE3LjY4MDUgNi40NzcxODV6IiBmaWxsPSIjZmZmIi8+PHBhdGggZD0ibTM4LjI0ODEgNy4wMjM4YzAgMi4zODEzMi02LjI3MzcgNC4yODY0LTE0LjA2ODMgNC4yODY0cy0xNC4wNjgzLTEuOTA1MDgtMTQuMDY4My00LjI4NjQgNi4yNzM3LTQuMjg2MzcgMTQuMDY4My00LjI4NjM3IDE0LjA2ODMgMS45MDUwNSAxNC4wNjgzIDQuMjg2Mzd6IiBmaWxsPSIjODA4MDgwIi8+DQogIDxwYXRoIGQ9Im0zNS4zMDEzIDkuNTk1NjNjMS44MDYxLS43NjIwMiAyLjk0NjgtMS42MTkzIDIuOTQ2OC0yLjU3MTgzIDAtMi4zODEzMi02LjI3MzctNC4yODYzNy0xNC4wNjgzLTQuMjg2MzdzLTE0LjA2ODMgMS45MDUwNS0xNC4wNjgzIDQuMjg2MzdjMCAuOTUyNTMgMS4xNDA3IDEuOTA1MDYgMi45NDY3IDIuNTcxODMgMi41NjY1LTEuMDQ3NzggNi42NTQtMS42MTkzIDExLjEyMTYtMS42MTkzczguNTU1LjY2Njc3IDExLjEyMTUgMS42MTkzeiIgZmlsbD0iIzgwODA4MCIvPg0KICA8ZyBmaWxsPSIjZmZmIj4NCiAgICA8cGF0aCBkPSJtMTguNDc1MiAzMS4xMjJjMCAxLjA0NzgtLjM4MDMgMS45MDUxLTEuMTQwNyAyLjQ3NjYtLjc2MDUuNTcxNS0xLjgwNjEuODU3My0zLjIzMTkuODU3My0xLjE0MDcgMC0yLjA5MTMtLjE5MDUtMi44NTE3LS42NjY4di0yLjQ3NjZjLjg1NTUuNzYyMSAxLjkwMTEgMS4xNDMxIDIuOTQ2NyAxLjE0MzEuNDc1MyAwIC45NTA2LS4wOTUzIDEuMjM1OC0uMjg1OC4yODUxLS4xOTA1LjM4MDItLjQ3NjIuMzgwMi0uODU3MyAwLS4zODEtLjA5NTEtLjY2NjctLjM4MDItLjg1NzItLjI4NTItLjI4NTgtLjg1NTUtLjU3MTUtMS43MTEtLjk1MjYtMS43MTExLS43NjItMi41NjY2LTEuOTA1LTIuNTY2Ni0zLjIzODYgMC0xLjA0NzcuMzgwMy0xLjgwOTggMS4xNDA3LTIuMzgxMy43NjA1LS41NzE1IDEuNzExLS45NTI1IDIuOTQ2Ny0uOTUyNSAxLjA0NTcgMCAxLjk5NjIuMTkwNSAyLjc1NjcuNDc2M3YyLjM4MTNjLS43NjA1LS40NzYzLTEuNjE2LS43NjItMi41NjY1LS43NjItLjQ3NTMgMC0uODU1NS4wOTUyLTEuMTQwNy4yODU3cy0uMzgwMi40NzYzLS4zODAyLjg1NzMuMDk1LjY2NjguMzgwMi44NTczYy4xOTAxLjE5MDUuNjY1NC40NzYyIDEuNDI1OC44NTcyIDEuMDQ1Ni40NzYzIDEuODA2MS45NTI2IDIuMjgxNCAxLjUyNDEuMjg1MS4zODEuNDc1My45NTI1LjQ3NTMgMS43MTQ1eiIvPjxwYXRoIGQ9Im0yNy44ODY4IDI4Ljc0MTJjMC0xLjE0My0uMjg1Mi0yLjAwMDMtLjc2MDQtMi42NjcxLS40NzUzLS42NjY3LTEuMTQwNy0uOTUyNS0xLjk5NjItLjk1MjVzLTEuNjE2LjI4NTgtMi4wOTEzLjk1MjVjLS41NzAzLjY2NjgtLjc2MDQgMS41MjQxLS43NjA0IDIuNjY3MSAwIDEuMDQ3OC4yODUyIDIuMDAwMy43NjA0IDIuNjY3MS40NzUzLjY2NjggMS4yMzU4Ljk1MjUgMi4wOTEzLjk1MjVzMS41MjA5LS4yODU3IDIuMDkxMi0uOTUyNWMuMzgwMi0uNjY2OC42NjU0LTEuNTI0MS42NjU0LTIuNjY3MXptMi42NjE2LS4wOTUyYzAgMS4zMzM1LS4yODUyIDIuNDc2NS0uODU1NSAzLjQyOTEtLjU3MDQuOTUyNS0xLjQyNTkgMS42MTkzLTIuNTY2NSAyLjAwMDNsMy4yMzE5IDMuMDQ4MWgtMy4yMzE5bC0yLjI4MTQtMi41NzE5Yy0uOTUwNiAwLTEuOTAxMS0uMjg1Ny0yLjY2MTYtLjc2Mi0uNzYwNC0uNDc2My0xLjQyNTgtMS4xNDMtMS44MDYtMi4wMDAzLS40NzUzLS44NTczLS42NjU0LTEuODA5OC0uNjY1NC0yLjg1NzYgMC0xLjE0My4xOTAxLTIuMTkwOC42NjU0LTMuMTQzMy40NzUzLS45NTI2IDEuMTQwNi0xLjYxOTMgMS45OTYyLTIuMDk1Ni44NTU1LS40NzYzIDEuODA2LS43NjIgMi45NDY3LS43NjIgMS4wNDU2IDAgMS45OTYyLjE5MDUgMi43NTY2LjY2NjguODU1NS40NzYyIDEuNDI1OSAxLjE0MyAxLjkwMTEgMi4wMDAzLjM4MDMuOTUyNS41NzA0IDEuOTA1LjU3MDQgMy4wNDgxeiIvPjxwYXRoIGQ9Im0zOS4xMDM2IDM0LjI2NTNoLTYuNzQ5di0xMS4xNDQ2aDIuNTY2NnY5LjE0NDNoNC4xODI0eiIvPg0KICA8L2c+DQo8L3N2Zz4NCg== -[codecov]: https://codecov.io/gh/LowlyDBA/dba-multitool [contrib]: ../.github/CONTRIBUTING.md [dbatools]: https://dbatools.io [issue]: https://github.com/LowlyDBA/dba-multitool/issues [license]: ../LICENSE -[lint]: https://github.com/LowlyDBA/dba-multitool/actions?query=workflow%3A%22Lint+Code+Base%22 +[mainstream]: https://learn.microsoft.com/en-us/sql/sql-server/end-of-support/sql-server-end-of-support-overview?view=sql-server-ver16#lifecycle-dates [slack]: https://sqlcommunity.slack.com/archives/C026Y2YCM9N [sp_doc]: https://dba-multitool.org/sp_doc [sp_estindex]: https://dba-multitool.org/sp_estindex [sp_helpme]: https://dba-multitool.org/sp_helpme [sp_sizeoptimiser]: https://dba-multitool.org/sp_sizeoptimiser -[sqlserver-badge]: https://img.shields.io/badge/SQL%20Server-2012--2019-blue?logo=microsoft-sql-server diff --git a/install_dba-multitool.sql b/install_dba-multitool.sql index 36647ed2..88ab8e8c 100644 --- a/install_dba-multitool.sql +++ b/install_dba-multitool.sql @@ -90,7 +90,7 @@ Version: 20211223 MIT License -Copyright (c) 2022 John McCall +Copyright (c) 2023 John McCall Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal in the Software without restriction, including without limitation @@ -2356,7 +2356,7 @@ Version: 20220124 MIT License -Copyright (c) 2022 John McCall +Copyright (c) 2023 John McCall Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal in the Software without restriction, including without limitation @@ -3205,11 +3205,11 @@ sp_helpme - A drop-in modern alternative to sp_help. Part of the DBA MultiTool http://dba-multitool.org -Version: 20220124 +Version: 20230108 MIT License -Copyright (c) 2022 John McCall +Copyright (c) 2023 John McCall Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal in the Software without restriction, including without limitation @@ -3570,7 +3570,58 @@ BEGIN IF @SysObj_Type IN ('S ','U ') BEGIN EXEC sys.sp_objectfilegroup @ObjID; + + /* Begin custom included columns for sp_helpindex */ + CREATE TABLE #sp_helpindex ( + index_name SYSNAME COLLATE database_default + ,index_description VARCHAR(210) + ,index_keys NVARCHAR(2126) COLLATE database_default --Length (16*max_identifierLength)+(15*2)+(16*3) + ,index_includes NVARCHAR(MAX) --Length (1023*max_identifierLength)+(15*2)+(16*3) is > 4000 + ); + INSERT INTO #sp_helpindex (index_name, index_description, index_keys) EXEC sys.sp_helpindex @ObjectName; + + IF EXISTS (SELECT 1 FROM #sp_helpindex) + BEGIN + SET @SQLString = N' + WITH includedColumns AS ( + SELECT DISTINCT i2.name AS index_name + , LTRIM(STUFF(( + SELECT '', '' + c.name + FROM sys.indexes i + INNER JOIN ' + QUOTENAME(DB_NAME()) + '.sys.index_columns ic ON i.index_id = ic.index_id + INNER JOIN ' + QUOTENAME(DB_NAME()) + '.sys.columns c ON c.column_id = ic.column_id + WHERE i.object_id = @ObjID + AND ic.object_id = @ObjID + AND c.object_id = @ObjID + AND ic.is_included_column = 1 + AND i2.index_id = i.index_id + FOR XML PATH(''''), TYPE).value(''.'', ''NVARCHAR(MAX)''), 1, 1, '''')) AS included + FROM ' + QUOTENAME(DB_NAME()) + '.sys.indexes i2 + INNER JOIN #sp_helpindex sp ON sp.index_name COLLATE database_default = i2.name + INNER JOIN ' + QUOTENAME(DB_NAME()) + '.sys.index_columns ic ON i2.index_id = ic.index_id + WHERE i2.object_id = @ObjID + AND ic.object_id = @ObjID + AND ic.is_included_column = 1 + ) + UPDATE sp + SET sp.index_includes = ic.included + FROM #sp_helpindex sp + INNER JOIN includedColumns ic ON sp.index_name COLLATE database_default = ic.index_name;'; + SET @ParmDefinition = N'@ObjID INT'; + + EXEC sp_executesql @SQLString + ,@ParmDefinition + ,@ObjID; + END + + IF EXISTS (SELECT 1 FROM #sp_helpindex) + BEGIN + SELECT index_name, index_description, index_keys, index_includes + FROM #sp_helpindex; + END + /* End custom included columns for sp_helpindex */ + EXEC sys.sp_helpconstraint @ObjectName,'nomsg'; SET @SQLString = N'SELECT @HasDepen = COUNT(1) @@ -3753,7 +3804,7 @@ Version: 20220818 MIT License -Copyright (c) 2022 John McCall +Copyright (c) 2023 John McCall Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal in the Software without restriction, including without limitation diff --git a/sp_doc.sql b/sp_doc.sql index bcbcafac..f36efd47 100644 --- a/sp_doc.sql +++ b/sp_doc.sql @@ -90,7 +90,7 @@ Version: 20211223 MIT License -Copyright (c) 2022 John McCall +Copyright (c) 2023 John McCall Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal in the Software without restriction, including without limitation diff --git a/sp_estindex.sql b/sp_estindex.sql index e7e447db..1da615f0 100644 --- a/sp_estindex.sql +++ b/sp_estindex.sql @@ -112,7 +112,7 @@ Version: 20220124 MIT License -Copyright (c) 2022 John McCall +Copyright (c) 2023 John McCall Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal in the Software without restriction, including without limitation diff --git a/sp_helpme.sql b/sp_helpme.sql index 7072f6bc..081d09ff 100644 --- a/sp_helpme.sql +++ b/sp_helpme.sql @@ -56,11 +56,11 @@ sp_helpme - A drop-in modern alternative to sp_help. Part of the DBA MultiTool http://dba-multitool.org -Version: 20220124 +Version: 20230108 MIT License -Copyright (c) 2022 John McCall +Copyright (c) 2023 John McCall Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal in the Software without restriction, including without limitation @@ -421,7 +421,58 @@ BEGIN IF @SysObj_Type IN ('S ','U ') BEGIN EXEC sys.sp_objectfilegroup @ObjID; + + /* Begin custom included columns for sp_helpindex */ + CREATE TABLE #sp_helpindex ( + index_name SYSNAME COLLATE database_default + ,index_description VARCHAR(210) + ,index_keys NVARCHAR(2126) COLLATE database_default --Length (16*max_identifierLength)+(15*2)+(16*3) + ,index_includes NVARCHAR(MAX) --Length (1023*max_identifierLength)+(15*2)+(16*3) is > 4000 + ); + INSERT INTO #sp_helpindex (index_name, index_description, index_keys) EXEC sys.sp_helpindex @ObjectName; + + IF EXISTS (SELECT 1 FROM #sp_helpindex) + BEGIN + SET @SQLString = N' + WITH includedColumns AS ( + SELECT DISTINCT i2.name AS index_name + , LTRIM(STUFF(( + SELECT '', '' + c.name + FROM sys.indexes i + INNER JOIN ' + QUOTENAME(DB_NAME()) + '.sys.index_columns ic ON i.index_id = ic.index_id + INNER JOIN ' + QUOTENAME(DB_NAME()) + '.sys.columns c ON c.column_id = ic.column_id + WHERE i.object_id = @ObjID + AND ic.object_id = @ObjID + AND c.object_id = @ObjID + AND ic.is_included_column = 1 + AND i2.index_id = i.index_id + FOR XML PATH(''''), TYPE).value(''.'', ''NVARCHAR(MAX)''), 1, 1, '''')) AS included + FROM ' + QUOTENAME(DB_NAME()) + '.sys.indexes i2 + INNER JOIN #sp_helpindex sp ON sp.index_name COLLATE database_default = i2.name + INNER JOIN ' + QUOTENAME(DB_NAME()) + '.sys.index_columns ic ON i2.index_id = ic.index_id + WHERE i2.object_id = @ObjID + AND ic.object_id = @ObjID + AND ic.is_included_column = 1 + ) + UPDATE sp + SET sp.index_includes = ic.included + FROM #sp_helpindex sp + INNER JOIN includedColumns ic ON sp.index_name COLLATE database_default = ic.index_name;'; + SET @ParmDefinition = N'@ObjID INT'; + + EXEC sp_executesql @SQLString + ,@ParmDefinition + ,@ObjID; + END + + IF EXISTS (SELECT 1 FROM #sp_helpindex) + BEGIN + SELECT index_name, index_description, index_keys, index_includes + FROM #sp_helpindex; + END + /* End custom included columns for sp_helpindex */ + EXEC sys.sp_helpconstraint @ObjectName,'nomsg'; SET @SQLString = N'SELECT @HasDepen = COUNT(1) diff --git a/sp_sizeoptimiser.sql b/sp_sizeoptimiser.sql index 8c4acd81..8e2b9edb 100644 --- a/sp_sizeoptimiser.sql +++ b/sp_sizeoptimiser.sql @@ -128,7 +128,7 @@ Version: 20220818 MIT License -Copyright (c) 2022 John McCall +Copyright (c) 2023 John McCall Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal in the Software without restriction, including without limitation diff --git a/tests/sp_doc.Tests.ps1 b/tests/sp_doc.Tests.ps1 index f3821cf4..0ba7c68d 100644 --- a/tests/sp_doc.Tests.ps1 +++ b/tests/sp_doc.Tests.ps1 @@ -15,18 +15,17 @@ Describe "sp_doc" { $queryTimeout = 300 $Hash = @{ - ServerInstance = $env:SQLINSTANCE - Database = $env:DATABASE + ConnectionString = "Data Source=$env:SQLINSTANCE;Initial Catalog=$env:DATABASE;Integrated Security=True;TrustServerCertificate=true" Verbose = $true } # Install tests ForEach ($File in Get-ChildItem -Path $testPath -Filter $testInstallScript) { - Invoke-SqlCmd @Hash -InputFile $File.FullName + Invoke-Sqlcmd @Hash -InputFile $File.FullName } } It "All tests" { - { Invoke-SqlCmd @Hash -Query $runTestQuery -QueryTimeout $queryTimeout } | Should -Not -Throw -Because "tSQLt unit tests must pass" + { Invoke-Sqlcmd @Hash -Query $runTestQuery -QueryTimeout $queryTimeout } | Should -Not -Throw -Because "tSQLt unit tests must pass" } } } diff --git a/tests/sp_estindex.Tests.ps1 b/tests/sp_estindex.Tests.ps1 index 7d4bc995..ecdd2712 100644 --- a/tests/sp_estindex.Tests.ps1 +++ b/tests/sp_estindex.Tests.ps1 @@ -15,18 +15,17 @@ Describe "sp_estindex" { $queryTimeout = 300 $Hash = @{ - ServerInstance = $env:SQLINSTANCE - Database = $env:DATABASE + ConnectionString = "Data Source=$env:SQLINSTANCE;Initial Catalog=$env:DATABASE;Integrated Security=True;TrustServerCertificate=true" Verbose = $true } # Install tests ForEach ($File in Get-ChildItem -Path $testPath -Filter $testInstallScript) { - Invoke-SqlCmd @Hash -InputFile $File.FullName + Invoke-Sqlcmd @Hash -InputFile $File.FullName } } It "All tests" { - { Invoke-SqlCmd @Hash -Query $runTestQuery -QueryTimeout $queryTimeout } | Should -Not -Throw -Because "tSQLt unit tests must pass" + { Invoke-Sqlcmd @Hash -Query $runTestQuery -QueryTimeout $queryTimeout } | Should -Not -Throw -Because "tSQLt unit tests must pass" } } } diff --git a/tests/sp_helpme.Tests.ps1 b/tests/sp_helpme.Tests.ps1 index 5b819be5..ade72dd0 100644 --- a/tests/sp_helpme.Tests.ps1 +++ b/tests/sp_helpme.Tests.ps1 @@ -15,18 +15,17 @@ Describe "sp_helpme" { $queryTimeout = 300 $Hash = @{ - ServerInstance = $env:SQLINSTANCE - Database = $env:DATABASE + ConnectionString = "Data Source=$env:SQLINSTANCE;Initial Catalog=$env:DATABASE;Integrated Security=True;TrustServerCertificate=true" Verbose = $true } # Install tests ForEach ($File in Get-ChildItem -Path $testPath -Filter $testInstallScript) { - Invoke-SqlCmd @Hash -InputFile $File.FullName + Invoke-Sqlcmd @Hash -InputFile $File.FullName } } It "All tests" { - { Invoke-SqlCmd @Hash -Query $runTestQuery -QueryTimeout $queryTimeout } | Should -Not -Throw -Because "tSQLt unit tests must pass" + { Invoke-Sqlcmd @Hash -Query $runTestQuery -QueryTimeout $queryTimeout } | Should -Not -Throw -Because "tSQLt unit tests must pass" } } } diff --git a/tests/sp_helpme.Tests.sql b/tests/sp_helpme.Tests.sql index ba31cdfa..97ec59d9 100644 --- a/tests/sp_helpme.Tests.sql +++ b/tests/sp_helpme.Tests.sql @@ -78,12 +78,52 @@ AS BEGIN DECLARE @EngineEdition TINYINT = CAST(SERVERPROPERTY('EngineEdition') AS TINYINT); - ---Build ---Assume tSQLt's table tSQLt.CaptureOutputLog always exists -DECLARE @Table SYSNAME = 'tSQLt.CaptureOutputLog'; DECLARE @epname SYSNAME = 'Description'; -DECLARE @cmd NVARCHAR(MAX) = N'EXEC [sp_helpme] ''' + @Table + ''', ''' + @epname + ''';'; +DECLARE @schemaName SYSNAME = 'dbo'; +DECLARE @TableName SYSNAME = 'sp_help_table_test'; +DECLARE @qualifiedTable SYSNAME = @schemaName + '.' + @TableName; + +-- Build test objects +-- Add table +CREATE TABLE [dbo].[sp_help_table_test] ( + [PersonID] [int] NOT NULL, + [FullName] [nvarchar](50) NOT NULL, + [PreferredName] [nvarchar](50) NOT NULL, + [SearchName] [nvarchar](101) NOT NULL, + [IsPermittedToLogon] [bit] NOT NULL, + [LogonName] [nvarchar](50) NULL, + [IsExternalLogonProvider] [bit] NOT NULL, + [HashedPassword] [varbinary](max) NULL, + [IsSystemUser] [bit] NOT NULL, + [IsEmployee] [bit] NOT NULL, + [IsSalesperson] [bit] NOT NULL, + [UserPreferences] [nvarchar](max) NULL, + [PhoneNumber] [nvarchar](20) NULL, + [FaxNumber] [nvarchar](20) NULL, + [EmailAddress] [nvarchar](256) NULL, + [Photo] [varbinary](max) NULL, + [CustomFields] [nvarchar](max) NULL, + [OtherLanguages] [nvarchar](max) NULL, + [LastEditedBy] [int] NOT NULL, + [ValidFrom] [datetime2](7) NOT NULL, + [ValidTo] [datetime2](7) NOT NULL +); + +-- Add index +CREATE NONCLUSTERED INDEX [sp_help_table_test_index] ON [dbo].[sp_help_table_test] +( + [PersonID] ASC, + [FullName] ASC, + [PreferredName] ASC, + [PhoneNumber] ASC +) +INCLUDE([LogonName],[IsExternalLogonProvider],[HashedPassword]); + +-- Add EP +EXEC sys.sp_addextendedproperty @name=@epname, @value=N'People known to the application (staff, customer contacts, supplier contacts)' , @level0type=N'SCHEMA',@level0name=@schemaName, @level1type=N'TABLE',@level1name=@TableName; + +-- Run test +DECLARE @cmd NVARCHAR(MAX) = N'EXEC [sp_helpme] ''' + @qualifiedTable + ''', ''' + @epname + ''';'; CREATE TABLE #Expected ( [name] SYSNAME NOT NULL @@ -94,10 +134,10 @@ CREATE TABLE #Expected ( ,[ExtendedProperty] SQL_VARIANT NULL ); -INSERT INTO #Expected +INSERT INTO #Expected ([name], [owner], [object_type], [create_datetime], [modify_datetime], [ExtendedProperty]) SELECT [Name] = o.name, - [Owner] = user_name(ObjectProperty(object_id, 'ownerid')), + [Owner] = USER_NAME(ObjectProperty(object_id, 'ownerid')), [Type] = LOWER(REPLACE(o.type_desc, '_', ' ')), [Created_datetime] = o.create_date, [Modify_datetime] = o.modify_date, @@ -106,21 +146,19 @@ SELECT LEFT JOIN sys.extended_properties ep ON ep.major_id = o.[object_id] AND ep.[name] = @epname AND ep.minor_id = 0 - AND ep.class = 1 - WHERE o.name = 'CaptureOutputLog'; + AND ep.class = 1 + WHERE o.name = @TableName; +-- Actual results +SELECT TOP 0 [name], [owner], [object_type], [create_datetime], [modify_datetime], [ExtendedProperty] +INTO #Actual +FROM #Expected; -CREATE TABLE #Actual ( - [name] SYSNAME NOT NULL - ,[owner] NVARCHAR(20) NOT NULL - ,[object_type] NVARCHAR(100) NOT NULL - ,[create_datetime] DATETIME NOT NULL - ,[modify_datetime] DATETIME NOT NULL - ,[ExtendedProperty] SQL_VARIANT NULL -); -INSERT INTO #Actual +INSERT INTO #Actual ([name], [owner], [object_type], [create_datetime], [modify_datetime], [ExtendedProperty]) EXEC tSQLt.ResultSetFilter 1, @cmd; +UPDATE #Actual SET ExtendedProperty = CONVERT(NVARCHAR(4000), ExtendedProperty); + --Assert EXEC tSQLt.AssertEqualsTable #Expected, #Actual; @@ -223,7 +261,7 @@ FROM sys.all_objects o LEFT JOIN sys.extended_properties ep ON ep.major_id = o.[object_id] AND ep.[name] = @epname AND ep.minor_id = 0 - AND ep.class = 1 + AND ep.class = 1 WHERE o.name = @TableName; CREATE TABLE #Actual ( @@ -313,4 +351,4 @@ GO /************************************ End sp_helpme tests -*************************************/ \ No newline at end of file +*************************************/ diff --git a/tests/sp_sizeoptimiser.Tests.ps1 b/tests/sp_sizeoptimiser.Tests.ps1 index 36becfdd..9ffc5df1 100644 --- a/tests/sp_sizeoptimiser.Tests.ps1 +++ b/tests/sp_sizeoptimiser.Tests.ps1 @@ -15,18 +15,17 @@ Describe "sp_sizeoptimiser" { $queryTimeout = 300 $Hash = @{ - ServerInstance = $env:SQLINSTANCE - Database = $env:DATABASE + ConnectionString = "Data Source=$env:SQLINSTANCE;Initial Catalog=$env:DATABASE;Integrated Security=True;TrustServerCertificate=true" Verbose = $true } # Install tests ForEach ($File in Get-ChildItem -Path $testPath -Filter $testInstallScript) { - Invoke-SqlCmd @Hash -InputFile $File.FullName + Invoke-Sqlcmd @Hash -InputFile $File.FullName } } It "All tests" { - { Invoke-SqlCmd @Hash -Query $runTestQuery -QueryTimeout $queryTimeout } | Should -Not -Throw -Because "tSQLt unit tests must pass" + { Invoke-Sqlcmd @Hash -Query $runTestQuery -QueryTimeout $queryTimeout } | Should -Not -Throw -Because "tSQLt unit tests must pass" } } }