Running Dynamic Code Quality Checks on Flyway Databases: Table Smells
How to extend the range of SQL code analysis, during database development, to include dynamic analysis of the database metadata. This will allow regular checks for problems with the design of your tables and indexes ("table smells") that can affect database performance and data integrity.
What is dynamic code analysis?
When you’re doing a routine build of a database, it is very useful to run a static code analysis. This is a SQL syntax check for mistakes or problems in the source code used to build or alter a database, which could reduce the performance and reliability of that database. Static code analysis will detect many common ‘code smells’ in your databases, but on its own it isn’t enough, because it will miss many of the mistakes or deficiencies that cause performance problems in a live database. You must also access the database metadata, through a live database connection, to check for missing indexes, duplicate indexes, and poorly designed tables, including tables that have no unique constraints at all, and tables that have no primary key (called ‘heaps’). These dynamic checks are best done using SQL to access the metadata functions.
You’ve all got favorite SQL scripts to find these sorts of problems, or ‘table smells’, and I have mine. The PowerShell automation I’ll demonstrate in this article will automatically run my SQL ‘metadata sniffer’ script on a Flyway-managed SQL Server database. I like to save the report in a JSON file because it is more easily processed by PowerShell. This article will demonstrate how to do that.
Why do we need dynamic code analysis?
If you do a regular full build as part of your database development cycle, you can be pretty sure that the result will be what the code intended. If, however, the database is being continuously migrated between versions, then this won’t necessarily be the case. For example, a fresh build of a database will have all constraints enabled. However, for an existing database that you are migrating, you may find out that, at some point, a developer disabled all constraints for a table, or for all tables, to do a data import, and then forgot to switch them back on. That sort of change could linger in the migrated database, undetected by Flyway or by static code analysis, and can sometimes make its way into migrations run on the production database.
To get a report of all the ‘table smells’ you’ve forgotten about in designing your database, or that have crept into a previous version of a migration, you need to run a dynamic analysis of the live database. This sort of dynamic code quality check is particularly important with a Flyway migration. If you don’t do it and, in our example, constraints aren’t switched on, then performance tests will be puzzlingly slow for a migrated database compared to a fresh build of the same version. Worse, if a trigger is switched off, say during debugging, and isn’t switched back on, then a process may fail, and data can get lost or mangled. I could do on: please believe me, this sort of test is like a fire alarm. It is valuable even if the alarm never goes off!
Running code quality checks in a Flyway development
What I’ll be doing is creating a script block task ($ExecuteTableSmellReport
) that runs a set of code quality checks, using various metadata functions, and produces a ‘table smells’ report, in JSON format. You can run this as a standalone task, but it can also slot into the PowerShell framework that I use to do Flyway development with Redgate Deploy.
There are two problems in demonstrating how to do the various chores in building and scripting databases. The first is that every development and deployment system for databases I’ve experienced or come across are different. If there is a single yellow brick road to stress-free database deployment out there, I haven’t found it. The second problem is that any build system can get complex unless you actively resist it. To get around both these problems, I’ve used, in these articles on Flyway, a rather unconventional approach to scripting that is more akin to Lego modelling. I use script blocks to represent each task and chain them in an array to define a process. In this way you can adapt it to the way that you prefer to work and that suits your team, business and application. If you’re thinking of using Flyway, this system will get you airborne.
Which table smells are reported?
The idea is that every version of the developing database should have an easily accessible report on any issues to do with tables and their indexing. As each database version is immutable, it only needs one Table Smells report, done once. I find it a good memory-jogger. There is nothing worse than having a heap that works perfectly well with test data but slows to a crawl when the data pours in, once the database is in production. This will tell you if a table has one or more of the following issues that need investigation or might raise eyebrows. Some of these won’t be seen in a newly built table but can creep into any existing database that is being successively migrated from version to version, rather than being built from source.
This report will tell you if a table…
- is a wide table (set this to the number of columns you consider to be ‘wide’)
- is an undocumented table (no Extended property explaining what the table is for)
- is a Heap (An unordered table, which in SQL Server means a table without a clustered index)
- Has a
GUID
in a clustered Index (performance) - Has no Primary Key (no obvious way of retrieving even a single row)
- Has a disabled Foreign Key (will cause performance problems)
- Has untrusted FK (won’t be used in indexes)
- Has a foreign key that has no supporting index (it generally helps performance)
- Is unrelated to any other table (an abandoned feature?)
- No candidate key (no unique constraint on column(s))
- Has no index at all (High performance-risk-effectively write-only once it grows in size)
- Has disabled Index(es)
- Has leftover fake index(es). A ‘hypothetical index’ is used in debugging and such an index can be neither considered nor used by the query optimizer
- Can’t be indexed (an index can be created on a table only if there is a column that isn’t a string of more than 900 bytes.)
- Has disabled constraint(s) (was that intentional?)
- Has untrusted constraint(s) (won’t be used in indexes)
- Has
ANSI
_NULLs
set toOFF
(can cause problems in SQL server) - Has a column collation different from the database (Did you mean to do that?)
- Has a surprisingly low Fill Factor (can affect performance)
- Is not referenced by any procedure, view or function (is it an abandoned feature?)
- Has a deprecated LOB datatype (used back when we wore flares and had mullet hairstyles)
- Has unintelligible column names (probably done to try to make it look more scientific)
- Has non-compliant column names (unnecessary, and can complicate development)
- Has a trigger that hasn’t got
NOCOUNT
ON
(can result in cluttering the message stream) - Has a disabled trigger (needs investigating. Can happen by accident)
Generating database code quality reports
The $ExecuteTableSmellReport
script block task that runs these SQL checks and generates the report is included in a PowerShell file called DatabaseBuildAndMigrateTasks.ps1. It contains a host of other tasks, as described in my previous article Running SQL Code Analysis during Flyway Migrations, along with a helper cmdlet that I’ll describe shortly, called Process-FlywayTasks
, which makes it much simpler to execute the chain of tasks you need, before or after you run a Flyway migration.
You can find this file in my GitHub repo and once you have it, you can include it at the start of your script that connects to the database and runs the list of required tasks. The simplest way to do this is to put it in the same directory as your Flyway migration scripts, and then pull it in with code at the start of each script, like this (I’ve included a sample script called FlywayCodeSmells.ps1 in the same GitHub directory):
1 2 3 4 5 6 7 8 9 10 11 12 13 |
try { $executablepath = [System.IO.Path]::GetDirectoryName($myInvocation.MyCommand.Definition) } catch { $executablepath = '' } #didn't like that so remove it if ($executablepath -eq '') { $executablepath = "$(If ($psISE) # null if at the commandline { Split-Path -Path $psISE.CurrentFile.FullPath } Else { $global:PSScriptRoot })" } if ([string]::IsNullOrEmpty($ExecutablePath)) { $ExecutablePath = $pwd } .("$executablepath\DatabaseBuildAndMigrateTasks.ps1") |
Each task writes to the hash table that is passed between them and will let you know the directories that it uses. It also tells you about errors, exceptions and warnings.
An ad-hoc code quality report
Purely to test out the report, we can just supply the parameter set that we need to locate the database we want to check, supply our credentials, and so on, on the command line. Of course, doing this isn’t a good idea; you really don’t want passwords, User IDs, server names or database names in PowerShell scripts unnecessarily.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 |
<#Purely to test it out, you can execute it this way ... #> $DatabaseDetails=@{ 'server'='TheServer'; #the name of your sql server 'database'='TheDatabase'; #the name of the database 'version'='TheVersionNumber'; #the version 'project'='TheProjectName'; #the name of your project 'uid'='MyUserID' #optional 'pwd'='MyPassword' #only if you use a uid 'locations'=@{}; # for reporting file locations used 'problems'=@{}; # for reporting any problems 'warnings'=@{}} # for reporting any warnings $ExecuteTableSmellReport.Invoke($DatabaseDetails) $DatabaseDetails.problems.ExecuteTableSmellReport |
The result should be a TableIssues.json report, saved in ..TheProjectName\TheVersionNumber\Reports. It will be immediately apparent that here you have a task that can be easily adapted to provide any SQL-based report, particularly if it produces a JSON output. This report is to get you started: you can adapt it to your own purposes.
Generating a code quality report during a Flyway migration
Here is a version that runs after a Flyway migrate:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 |
<#You can also do it directly after a flyway migrate like this ... #> $DatabaseDetails = @{ 'server' = 'TheServer'; #the name of your sql server 'database' = 'TheDatabase'; #the name of the database 'version' = 'TheVersionNumber'; #the version 'project' = 'TheProjectName'; #the name of your project 'uid' = 'MyUserID' #optional 'pwd' = 'MyPassword' #only if you use a uid 'locations' = @{ }; # for reporting file locations used 'problems' = @{ }; # for reporting any problems 'warnings' = @{ } } # for reporting any warnings $FormatTheBasicFlywayParameters.Invoke($DatabaseDetails) #so you can run flyway try { Flyway migrate $DatabaseDetails.FlyWayArgs } catch { $ErrorMessage = $_.Exception.Message $FailedItem = $_.Exception.ItemName $DatabaseDetails.Problems.exceptions += "Flyway failed with $FailedItem : $ErrorMessage" } if ($DatabaseDetails.Problems.Count() -eq 0) { $ExecuteTableSmellReport.Invoke($DatabaseDetails) $DatabaseDetails.problems.ExecuteTableSmellReport } |
Saving the parameter set securely
To avoid supply having to supply these credentials every time, and in an insecure way, we instead use the $FetchAnyRequiredPasswords
task to fetch and save the password from the secure user area, and the $FetchOrSaveDetailsOfParameterSet
task to save a named parameter set for each database, again saving the details on disk in the user area. I’ve described how the latter works in a previous article.
To execute this task, along with other tasks, we can now use code like this:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 |
<# with this system, you can access already-saved parameters. The first time that you use this you need to provide the parameters in a hashtable like this. The system will save the details under the name you give, so only do this the once. $DatabaseDetails = @{ 'name' = 'MyName'; 'server'='MyServer'; 'database'='Database'; uid='myid'; 'Project' = 'pubs'; } #> #I've Already saved mine, so now I can do this… $DatabaseDetails = @{ 'name' = 'MyDatabase'; 'Project' = 'pubs'; } <#You can then get the $databaseDetails array filled in by executing $FetchOrSaveDetailsOfParameterSet You can inspect, save or edit the JSON parameters directly at $($env:USERPROFILE)\Documents\Deploy\$project and just use them by starting out with a hashtable with the name of the parameter set and the name of the flyway project. #> @( $FetchOrSaveDetailsOfParameterSet, # get the details, initialise $FetchAnyRequiredPasswords, #deal with passwords $GetCurrentVersion, #access the database to work out the current version $ExecuteTableSmellReport) | foreach{ #do each task if ($DatabaseDetails.Problems.Count -eq 0) #abandon on first error { if ($_.Ast.Extent.Text -imatch '(?<=# ?\$)([\w]{5,80})') { $TaskName = $matches[0] } #get the name of the scriptblock task else { $TaskName = 'unknown' } try # try executing the script block { $WhatWasReturned += $_.Invoke($DatabaseDetails) } catch #if it hit an exception { # handle the exception $ErrorMessage = $_.Exception.Message $FailedItem = $_.Exception.ItemName $TheFailure=$_ # Extra debugging information Write-Verbose "For some reason $Taskname failed. $FailedItem : $ErrorMessage" } write-verbose "Executed $TaskName" } } #print out any errors and warnings. if ($DatabaseDetails.Problems.Count -gt 0) #list out every problem and which task failed { $DatabaseDetails.Problems.GetEnumerator() | Foreach{ Write-warning "Problem! $($_.Key)---------"; $_.Value } | foreach { write-warning "`t$_" } } if ($DatabaseDetails.Warnings.Count -gt 0) #list out exery warning and which task failed { $DatabaseDetails.Warning.GetEnumerator() | Foreach{ Write-warning "$($_.Key)---------"; $_.Value } | foreach { write-warning "`t$_"} } |
Using the Process-FlywayTasks helper cmdlet
This can all be done much more simply by executing the Process-FlywayTasks
cmdlet that is provided as a helper function in the task file (DatabaseBuildAndMigrateTasks.ps1) .
1 2 3 4 5 6 |
Process-FlywayTasks @{ <a id="post-4231413-_Hlk68884429"></a>'name' = 'MyDatabase'; 'Project' = 'pubs'; } @($FetchOrSaveDetailsOfParameterSet, # get the details, initialize $FetchAnyRequiredPasswords, #deal with passwords $GetCurrentVersion, #access the database to work out the current version $ExecuteTableSmellReport) |
Or, if you need to access the hash table afterwards you can do it a slightly more complicated way that preserves the hash table but is otherwise the same. You first create the $DatabaseDetails
hash table, so that the reports can be referenced after the tasks have executed.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 |
$DatabaseDetails =@{ 'name' = 'MyDatabase'; 'Project' = 'pubs'; } Process-FlywayTasks <a id="post-4231413-_Hlk68884556"></a>$DatabaseDetails @( $FetchOrSaveDetailsOfParameterSet, # get the details, initialize $FetchAnyRequiredPasswords, #deal with passwords $GetCurrentVersion, #access the database to work out the current version $ExecuteTableSmellReport) #You can now view the report $Report=$DatabaseDetails.Locations.ExecuteTableSmellReport if ( $Report-ne $null) {$TheReport=Get-Content -Path $Report -raw|ConvertFrom-JSON $TheReport|foreach{$Table=$_.TableName; $_.Problems }| Select @{label="Table";expression={$table}}, @{label="Problem";expression={$_.problem}} } |
Table Problem ----- ------- dbo.flyway_schema_history Undocumented table dbo.flyway_schema_history unrelated to any other table dbo.flyway_schema_history not referenced by procedure, view or function dbo.stores not referenced by procedure, view or function dbo.discounts not referenced by procedure, view or function dbo.pub_info not referenced by procedure, view or function dbo.roysched not referenced by procedure, view or function dbo.sales not referenced by procedure, view or function
The Table Smell Report task
We’ve seen the report it produces, and all that remains to explain is the code that executes the ‘table smells’ task. It uses SQLCMD, so the first thing you must do before using the task is to provide the alias for it. I use SQLCMD because it is quick, has some wonderful ‘extra’ features for doing complicated things, and because it requires no extra libraries. It will be immediately apparent that this sort of task can be adapted to all sort of SQL-based reports, particularly those that have JSON output.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 |
<#This scriptblock executes SQL that produces a report in XML or JSON from the database #> $ExecuteTableSmellReport = { Param ($param1) # $ExecuteTableSmellReport - parameter is a hashtable $problems = @() @('server', 'database', 'version', 'project') | foreach{ if ($param1.$_ -eq $null) { write-error "no value for '$($_)'" } } if ($param1.EscapedProject -eq $null) #check that escapedValues are in place { $EscapedValues = $param1.GetEnumerator() | where { $_.Name -in ('server', 'Database', 'Project') } | foreach{ @{ "Escaped$($_.Name)" = ($_.Value.Split([IO.Path]::GetInvalidFileNameChars()) -join '_') } } $EscapedValues | foreach{ $param1 += $_ } } $MyDatabasePath = "$($env:USERPROFILE)\Documents\GitHub\$( $param1.EscapedProject)\$($param1.Version)\Reports" if (-not (Test-Path -PathType Container $MyDatabasePath)) { # does the path to the reports directory exist? # not there, so we create the directory $null = New-Item -ItemType Directory -Force $MyDatabasePath; } $MyOutputReport = "$MyDatabasePath\TableIssues.JSON" #the alias must be set to the path of your installed version of SQL Compare Set-Alias SQLCmd "$($env:ProgramFiles)\Microsoft SQL Server\Client SDK\ODBC\130\Tools\Binn\sqlcmd.exe" -Scope local #is that alias correct? if (!(test-path ((Get-alias -Name SQLCmd).definition) -PathType Leaf)) { $Problems += 'The alias for SQLCMD is not set correctly yet' } $query = @' SET NOCOUNT ON /** summary: > This query finds the following table smells 1/ is a Wide table (set this to what you consider to be wide) 2/ is a Heap 3/ is an undocumented table 4/ Has no Primary Key 5/ Has ANSI NULLs set to OFF 6/ Has no index at all 7/ No candidate key (unique constraint on column(s)) 8/ Has disabled Index(es) 9/ has leftover fake index(es) 10/ has a column collation different from the database 11/ Has a surprisingly low Fill-Factor 12/ Has disabled constraint(s)' 13/ Has untrusted constraint(s)' 14/ Has a disabled Foreign Key' 15/ Has untrusted FK' 16/ Has unrelated to any other table' 17/ Has a deprecated LOB datatype 18/ Has unintelligible column names' 19/ Has a foreign key that has no index' 20/ Has a GUID in a clustered Index 21/ Has non-compliant column names' 22/ Has a trigger that hasn't got NOCOUNT ON' 23/ Is not referenced by any procedure, view or function' 24/ Has a disabled trigger' 25/ Can't be indexed' Revisions: - Author: Phil Factor Version: 1.1 Modifications: - added tests as suggested by comments to blog Date: 30 Mar 2016 - Author: Phil Factor Version: 1.2 Modifications: - tidying, added five more smells Date: 10 July 2020 - Author: Phil Factor Version: 1.3 Modifications: - re-engineered it for JSON output Date: 26 March 2021 returns: > single result of table name, and list of problems **/ declare @TableSmells table (object_id INT, problem VARCHAR(200)) INSERT INTO @TableSmells (object_id, problem) SELECT object_id, 'wide (more than 15 columns)' AS Problem FROM sys.tables /* see whether the table has more than 15 columns */ WHERE max_column_id_used > 15 UNION ALL SELECT DISTINCT sys.tables.object_id, 'heap' FROM sys.indexes /* see whether the table is a heap */ INNER JOIN sys.tables ON sys.tables.object_id = sys.indexes.object_id WHERE sys.indexes.type = 0 UNION ALL SELECT s.object_id, 'Undocumented table' FROM sys.tables AS s /* it has no extended properties */ LEFT OUTER JOIN sys.extended_properties AS ep ON s.object_id = ep.major_id AND minor_id = 0 WHERE ep.value IS NULL UNION ALL SELECT sys.tables.object_id, 'No primary key' FROM sys.tables /* see whether the table has a primary key */ WHERE ObjectProperty(object_id, 'TableHasPrimaryKey') = 0 UNION ALL SELECT sys.tables.object_id, 'has ANSI NULLs set to OFF' FROM sys.tables /* see whether the table has ansii NULLs off*/ WHERE ObjectPropertyEx(object_id, 'IsAnsiNullsOn') = 0 UNION ALL SELECT sys.tables.object_id, 'No index at all' FROM sys.tables /* see whether the table has any index */ WHERE ObjectProperty(object_id, 'TableHasIndex') = 0 UNION ALL SELECT sys.tables.object_id, 'No candidate key' FROM sys.tables /* if no unique constraint then it isn't relational */ WHERE ObjectProperty(object_id, 'TableHasUniqueCnst') = 0 AND ObjectProperty(object_id, 'TableHasPrimaryKey') = 0 UNION ALL SELECT DISTINCT object_id, 'disabled Index(es)' FROM sys.indexes /* don't leave these lying around */ WHERE is_disabled = 1 UNION ALL SELECT DISTINCT object_id, 'leftover fake index(es)' FROM sys.indexes /* don't leave these lying around */ WHERE is_hypothetical = 1 UNION ALL SELECT c.object_id, 'has a column ''' + c.name + ''' that has a collation ''' + collation_name + ''' different from the database' FROM sys.columns AS c WHERE Coalesce(collation_name, '') <> DatabasePropertyEx(Db_Id(), 'Collation') UNION ALL SELECT DISTINCT object_id, 'surprisingly low Fill-Factor' FROM sys.indexes /* a fill factor of less than 80 raises eyebrows */ WHERE fill_factor <> 0 AND fill_factor < 80 AND is_disabled = 0 AND is_hypothetical = 0 UNION ALL SELECT DISTINCT parent_object_id, 'disabled constraint(s)' FROM sys.check_constraints /* hmm. i wonder why */ WHERE is_disabled = 1 UNION ALL SELECT DISTINCT parent_object_id, 'untrusted constraint(s)' FROM sys.check_constraints /* ETL gone bad? */ WHERE is_not_trusted = 1 UNION ALL SELECT DISTINCT parent_object_id, 'disabled FK' FROM sys.foreign_keys /* build script gone bad? */ WHERE is_disabled = 1 UNION ALL SELECT DISTINCT parent_object_id, 'untrusted FK' FROM sys.foreign_keys /* Why do you have untrusted FKs? Constraint was enabled without checking existing rows; therefore, the constraint may not hold for all rows. */ WHERE is_not_trusted = 1 UNION ALL SELECT object_id, 'unrelated to any other table' FROM sys.tables /* found a simpler way! */ WHERE ObjectPropertyEx(object_id, 'TableHasForeignKey') = 0 AND ObjectPropertyEx(object_id, 'TableHasForeignRef') = 0 UNION ALL SELECT object_id, 'deprecated LOB datatype' FROM sys.tables /* found a simpler way! */ WHERE ObjectPropertyEx(object_id, 'TableHasTextImage') = 1 UNION ALL SELECT DISTINCT object_id, 'unintelligible column names' FROM sys.columns /* column names with no letters in them */ WHERE name COLLATE Latin1_General_CI_AI NOT LIKE '%[A-Z]%' COLLATE Latin1_General_CI_AI UNION ALL SELECT keys.parent_object_id, 'foreign key ' + keys.name + ' that has no supporting index' FROM sys.foreign_keys AS keys INNER JOIN sys.foreign_key_columns AS TheColumns ON keys.object_id = constraint_object_id LEFT OUTER JOIN sys.index_columns AS ic ON ic.object_id = TheColumns.parent_object_id AND ic.column_id = TheColumns.parent_column_id AND TheColumns.constraint_column_id = ic.key_ordinal WHERE ic.object_id IS NULL UNION ALL SELECT Ic.object_id, Col_Name(Ic.object_id, Ic.column_id) + ' is a GUID in a clustered index' /* GUID in a clustered IX */ FROM sys.index_columns AS Ic INNER JOIN sys.tables AS tables ON tables.object_id = Ic.object_id INNER JOIN sys.columns AS c ON c.object_id = Ic.object_id AND c.column_id = Ic.column_id INNER JOIN sys.types AS t ON t.system_type_id = c.system_type_id INNER JOIN sys.indexes AS i ON i.object_id = Ic.object_id AND i.index_id = Ic.index_id WHERE t.name = 'uniqueidentifier' AND i.type_desc = 'CLUSTERED' UNION ALL SELECT DISTINCT object_id, 'non-compliant column names' FROM sys.columns /* column names that need delimiters*/ WHERE name COLLATE Latin1_General_CI_AI LIKE '%[^_@$#A-Z0-9]%' COLLATE Latin1_General_CI_AI UNION ALL /* Triggers lacking `SET NOCOUNT ON`, which can cause unexpected results WHEN USING OUTPUT */ SELECT ta.object_id, 'This table''s trigger, ' + Object_Name(tr.object_id) + ', has''nt got NOCOUNT ON' FROM sys.tables AS ta /* see whether the table has any index */ INNER JOIN sys.triggers AS tr ON tr.parent_id = ta.object_id INNER JOIN sys.sql_modules AS mo ON tr.object_id = mo.object_id WHERE definition NOT LIKE '%set nocount on%' UNION ALL /* table not referenced by any routine */ SELECT sys.tables.object_id, 'not referenced by procedure, view or function' FROM sys.tables /* found a simpler way! */ LEFT OUTER JOIN sys.sql_expression_dependencies ON referenced_id = sys.tables.object_id WHERE referenced_id IS NULL UNION ALL SELECT DISTINCT parent_id, 'has a disabled trigger' FROM sys.triggers WHERE is_disabled = 1 AND parent_id > 0 UNION ALL SELECT sys.tables.object_id, 'can''t be indexed' FROM sys.tables /* see whether the table has a primary key */ WHERE ObjectProperty(object_id, 'IsIndexable') = 0 DECLARE @json NVARCHAR(MAX) SELECT @json = (SELECT TableName, problem from (SELECT DISTINCT Object_Schema_Name(Object_ID) + '.' + Object_Name(Object_ID) AS TableName,object_id, Count(*) AS smells FROM @TableSmells GROUP BY Object_ID)f(TableName,Object_id, Smells) INNER JOIN @TableSmells AS problems ON f.object_id=problems.object_id ORDER BY smells desc FOR JSON AUTO) SELECT @Json '@ if (!([string]::IsNullOrEmpty($param1.uid)) -and ([string]::IsNullOrEmpty($param1.pwd))) { $problems += 'No password is specified' } If (!(Test-Path -PathType Leaf $MyOutputReport) -and ($problems.Count -eq 0)) { if (!([string]::IsNullOrEmpty($param1.uid))) { $MyJSON = sqlcmd -S "$($param1.server)" -d "$($param1.database)" ` -Q `"$query`" -U $($param1.uid) -P $($param1.pwd) -o $MyOutputReport -u -y0 $arguments = "$($param1.server) -d $($param1.database) -U $($param1.uid) -P $($param1.pwd) -o $MyOutputReport" } else { $MyJSON = sqlcmd -S "$($param1.server)" -d "$($param1.database)" -Q `"$query`" -E -o $MyOutputReport -u -y0 $arguments = "$($param1.server) -d $($param1.database) -o $MyOutputReport" } if (!($?)) { #report a problem and send back the args for diagnosis (hint, only for script development) $Problems += "sqlcmd failed with code $LASTEXITCODE, $Myversions, with parameters $arguments" } $possibleError = Get-Content -Path $MyOutputReport -raw if ($PossibleError -like '*Sqlcmd: Error*') { $Problems += $possibleError; Remove-Item $MyOutputReport; } } if ($problems.Count -gt 0) { $Param1.Problems.'ExecuteTableSmellReport' += $problems; } else { $Param1.Locations.'ExecuteTableSmellReport' += $MyOutputReport; } } |
Conclusions
Although it is, hopefully, useful to have a report about Table Smells, this article was also aimed at showing how one could go about creating any task that got a JSON report from a SQL query. This represents many possibilities for tasks that are designed to make checks on versions of databases, including running integration tests and unit tests. You’d probably want to pull in a whole directory of SQL-based integration and unit tests, and execute them one after another, with a standard JSON result.
Now, with this sort of task provided for to use along with a Flyway migration, you now have the basis for the build/migration itself together with the added scripts that give you integration with existing release systems as well as the basic routine quality reports and the tests.
The system may seem complicated compared with doing it ‘by hand’, but when you factor the time, the boredom and the inherent inaccuracy of the manual approach, and the horrible possibility that it just won’t get done routinely because of the pain, you’ll see why I’ve adopted the automated approach. Daily build and release? Yeah. Why not?