├── .gitignore ├── AzureSQLDataSyncHealthChecker.ps1 ├── CONTRIBUTING.md ├── LICENSE ├── PRIVACY ├── README.md └── SECURITY.md /.gitignore: -------------------------------------------------------------------------------- 1 | ## Ignore Visual Studio temporary files, build results, and 2 | ## files generated by popular Visual Studio add-ons. 3 | ## 4 | ## Get latest from https://github.com/github/gitignore/blob/master/VisualStudio.gitignore 5 | 6 | # User-specific files 7 | *.suo 8 | *.user 9 | *.userosscache 10 | *.sln.docstates 11 | 12 | # User-specific files (MonoDevelop/Xamarin Studio) 13 | *.userprefs 14 | 15 | # Build results 16 | [Dd]ebug/ 17 | [Dd]ebugPublic/ 18 | [Rr]elease/ 19 | [Rr]eleases/ 20 | x64/ 21 | x86/ 22 | bld/ 23 | [Bb]in/ 24 | [Oo]bj/ 25 | [Ll]og/ 26 | 27 | # Visual Studio 2015/2017 cache/options directory 28 | .vs/ 29 | # Uncomment if you have tasks that create the project's static files in wwwroot 30 | #wwwroot/ 31 | 32 | # Visual Studio 2017 auto generated files 33 | Generated\ Files/ 34 | 35 | # MSTest test Results 36 | [Tt]est[Rr]esult*/ 37 | [Bb]uild[Ll]og.* 38 | 39 | # NUNIT 40 | *.VisualState.xml 41 | TestResult.xml 42 | 43 | # Build Results of an ATL Project 44 | [Dd]ebugPS/ 45 | [Rr]eleasePS/ 46 | dlldata.c 47 | 48 | # Benchmark Results 49 | BenchmarkDotNet.Artifacts/ 50 | 51 | # .NET Core 52 | project.lock.json 53 | project.fragment.lock.json 54 | artifacts/ 55 | **/Properties/launchSettings.json 56 | 57 | # StyleCop 58 | StyleCopReport.xml 59 | 60 | # Files built by Visual Studio 61 | *_i.c 62 | *_p.c 63 | *_i.h 64 | *.ilk 65 | *.meta 66 | *.obj 67 | *.iobj 68 | *.pch 69 | *.pdb 70 | *.ipdb 71 | *.pgc 72 | *.pgd 73 | *.rsp 74 | *.sbr 75 | *.tlb 76 | *.tli 77 | *.tlh 78 | *.tmp 79 | *.tmp_proj 80 | *.log 81 | *.vspscc 82 | *.vssscc 83 | .builds 84 | *.pidb 85 | *.svclog 86 | *.scc 87 | 88 | # Chutzpah Test files 89 | _Chutzpah* 90 | 91 | # Visual C++ cache files 92 | ipch/ 93 | *.aps 94 | *.ncb 95 | *.opendb 96 | *.opensdf 97 | *.sdf 98 | *.cachefile 99 | *.VC.db 100 | *.VC.VC.opendb 101 | 102 | # Visual Studio profiler 103 | *.psess 104 | *.vsp 105 | *.vspx 106 | *.sap 107 | 108 | # Visual Studio Trace Files 109 | *.e2e 110 | 111 | # TFS 2012 Local Workspace 112 | $tf/ 113 | 114 | # Guidance Automation Toolkit 115 | *.gpState 116 | 117 | # ReSharper is a .NET coding add-in 118 | _ReSharper*/ 119 | *.[Rr]e[Ss]harper 120 | *.DotSettings.user 121 | 122 | # JustCode is a .NET coding add-in 123 | .JustCode 124 | 125 | # TeamCity is a build add-in 126 | _TeamCity* 127 | 128 | # DotCover is a Code Coverage Tool 129 | *.dotCover 130 | 131 | # AxoCover is a Code Coverage Tool 132 | .axoCover/* 133 | !.axoCover/settings.json 134 | 135 | # Visual Studio code coverage results 136 | *.coverage 137 | *.coveragexml 138 | 139 | # NCrunch 140 | _NCrunch_* 141 | .*crunch*.local.xml 142 | nCrunchTemp_* 143 | 144 | # MightyMoose 145 | *.mm.* 146 | AutoTest.Net/ 147 | 148 | # Web workbench (sass) 149 | .sass-cache/ 150 | 151 | # Installshield output folder 152 | [Ee]xpress/ 153 | 154 | # DocProject is a documentation generator add-in 155 | DocProject/buildhelp/ 156 | DocProject/Help/*.HxT 157 | DocProject/Help/*.HxC 158 | DocProject/Help/*.hhc 159 | DocProject/Help/*.hhk 160 | DocProject/Help/*.hhp 161 | DocProject/Help/Html2 162 | DocProject/Help/html 163 | 164 | # Click-Once directory 165 | publish/ 166 | 167 | # Publish Web Output 168 | *.[Pp]ublish.xml 169 | *.azurePubxml 170 | # Note: Comment the next line if you want to checkin your web deploy settings, 171 | # but database connection strings (with potential passwords) will be unencrypted 172 | *.pubxml 173 | *.publishproj 174 | 175 | # Microsoft Azure Web App publish settings. Comment the next line if you want to 176 | # checkin your Azure Web App publish settings, but sensitive information contained 177 | # in these scripts will be unencrypted 178 | PublishScripts/ 179 | 180 | # NuGet Packages 181 | *.nupkg 182 | # The packages folder can be ignored because of Package Restore 183 | **/[Pp]ackages/* 184 | # except build/, which is used as an MSBuild target. 185 | !**/[Pp]ackages/build/ 186 | # Uncomment if necessary however generally it will be regenerated when needed 187 | #!**/[Pp]ackages/repositories.config 188 | # NuGet v3's project.json files produces more ignorable files 189 | *.nuget.props 190 | *.nuget.targets 191 | 192 | # Microsoft Azure Build Output 193 | csx/ 194 | *.build.csdef 195 | 196 | # Microsoft Azure Emulator 197 | ecf/ 198 | rcf/ 199 | 200 | # Windows Store app package directories and files 201 | AppPackages/ 202 | BundleArtifacts/ 203 | Package.StoreAssociation.xml 204 | _pkginfo.txt 205 | *.appx 206 | 207 | # Visual Studio cache files 208 | # files ending in .cache can be ignored 209 | *.[Cc]ache 210 | # but keep track of directories ending in .cache 211 | !*.[Cc]ache/ 212 | 213 | # Others 214 | ClientBin/ 215 | ~$* 216 | *~ 217 | *.dbmdl 218 | *.dbproj.schemaview 219 | *.jfm 220 | *.pfx 221 | *.publishsettings 222 | orleans.codegen.cs 223 | 224 | # Including strong name files can present a security risk 225 | # (https://github.com/github/gitignore/pull/2483#issue-259490424) 226 | #*.snk 227 | 228 | # Since there are multiple workflows, uncomment next line to ignore bower_components 229 | # (https://github.com/github/gitignore/pull/1529#issuecomment-104372622) 230 | #bower_components/ 231 | 232 | # RIA/Silverlight projects 233 | Generated_Code/ 234 | 235 | # Backup & report files from converting an old project file 236 | # to a newer Visual Studio version. Backup files are not needed, 237 | # because we have git ;-) 238 | _UpgradeReport_Files/ 239 | Backup*/ 240 | UpgradeLog*.XML 241 | UpgradeLog*.htm 242 | ServiceFabricBackup/ 243 | *.rptproj.bak 244 | 245 | # SQL Server files 246 | *.mdf 247 | *.ldf 248 | *.ndf 249 | 250 | # Business Intelligence projects 251 | *.rdl.data 252 | *.bim.layout 253 | *.bim_*.settings 254 | *.rptproj.rsuser 255 | 256 | # Microsoft Fakes 257 | FakesAssemblies/ 258 | 259 | # GhostDoc plugin setting file 260 | *.GhostDoc.xml 261 | 262 | # Node.js Tools for Visual Studio 263 | .ntvs_analysis.dat 264 | node_modules/ 265 | 266 | # Visual Studio 6 build log 267 | *.plg 268 | 269 | # Visual Studio 6 workspace options file 270 | *.opt 271 | 272 | # Visual Studio 6 auto-generated workspace file (contains which files were open etc.) 273 | *.vbw 274 | 275 | # Visual Studio LightSwitch build output 276 | **/*.HTMLClient/GeneratedArtifacts 277 | **/*.DesktopClient/GeneratedArtifacts 278 | **/*.DesktopClient/ModelManifest.xml 279 | **/*.Server/GeneratedArtifacts 280 | **/*.Server/ModelManifest.xml 281 | _Pvt_Extensions 282 | 283 | # Paket dependency manager 284 | .paket/paket.exe 285 | paket-files/ 286 | 287 | # FAKE - F# Make 288 | .fake/ 289 | 290 | # JetBrains Rider 291 | .idea/ 292 | *.sln.iml 293 | 294 | # CodeRush 295 | .cr/ 296 | 297 | # Python Tools for Visual Studio (PTVS) 298 | __pycache__/ 299 | *.pyc 300 | 301 | # Cake - Uncomment if you are using it 302 | # tools/** 303 | # !tools/packages.config 304 | 305 | # Tabs Studio 306 | *.tss 307 | 308 | # Telerik's JustMock configuration file 309 | *.jmconfig 310 | 311 | # BizTalk build output 312 | *.btp.cs 313 | *.btm.cs 314 | *.odx.cs 315 | *.xsd.cs 316 | 317 | # OpenCover UI analysis results 318 | OpenCover/ 319 | 320 | # Azure Stream Analytics local run output 321 | ASALocalRun/ 322 | 323 | # MSBuild Binary and Structured Log 324 | *.binlog 325 | 326 | # NVidia Nsight GPU debugger configuration file 327 | *.nvuser 328 | 329 | # MFractors (Xamarin productivity tool) working folder 330 | .mfractor/ 331 | -------------------------------------------------------------------------------- /AzureSQLDataSyncHealthChecker.ps1: -------------------------------------------------------------------------------- 1 | #Copyright (c) Microsoft Corporation. 2 | #Licensed under the MIT license. 3 | 4 | #Azure SQL Data Sync Health Checker 5 | 6 | #THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 7 | #FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, 8 | #WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. 9 | 10 | ## Databases and credentials 11 | # Sync metadata database credentials (Only SQL Authentication is supported) 12 | $SyncDbServer = '.database.windows.net' 13 | $SyncDbDatabase = '' 14 | $SyncDbUser = '' 15 | $SyncDbPassword = '' 16 | 17 | # Hub credentials (Only SQL Authentication is supported) 18 | $HubServer = '.database.windows.net' 19 | $HubDatabase = '' 20 | $HubUser = '' 21 | $HubPassword = '' 22 | 23 | # Member credentials (Azure SQL DB or SQL Server) 24 | $MemberServer = '' 25 | $MemberDatabase = '' 26 | $MemberUser = '' 27 | $MemberPassword = '' 28 | # set MemberUseWindowsAuthentication to $true in case you wish to use integrated Windows authentication (MemberUser and MemberPassword will be ignored) 29 | $MemberUseWindowsAuthentication = $false 30 | 31 | ## Optional parameters (default values will be used if ommited) 32 | 33 | ## Health checks 34 | $HealthChecksEnabled = $true #Set as $true (default) or $false 35 | 36 | ## Monitoring 37 | $MonitoringMode = 'AUTO' #Set as AUTO (default), ENABLED or DISABLED 38 | $MonitoringIntervalInSeconds = 20 39 | $MonitoringDurationInMinutes = 1 40 | 41 | ## Tracking Record Validations 42 | $ExtendedValidationsTableFilter = @('All') #Set as "All" or the tables you need using '[dbo].[TableName1]','[dbo].[TableName2]' 43 | $ExtendedValidationsEnabledForHub = $true #Set as $true (default) or $false 44 | $ExtendedValidationsEnabledForMember = $true #Set as $true (default) or $false 45 | $ExtendedValidationsCommandTimeout = 900 #seconds (default) 46 | 47 | ## Other 48 | $SendAnonymousUsageData = $true #Set as $true (default) or $false 49 | $DumpMetadataSchemasForSyncGroup = '' #leave empty for automatic detection 50 | $DumpMetadataObjectsForTable = '' #needs to be formatted like [SchemaName].[TableName] 51 | 52 | ##################################################################################################### 53 | # Parameter region when Invoke-Command -ScriptBlock is used 54 | $parameters = $args[0] 55 | if ($null -ne $parameters) { 56 | ## Databases and credentials 57 | # Sync metadata database credentials (Only SQL Authentication is supported) 58 | $SyncDbServer = $parameters['SyncDbServer'] 59 | $SyncDbDatabase = $parameters['SyncDbDatabase'] 60 | $SyncDbUser = $parameters['SyncDbUser'] 61 | $SyncDbPassword = $parameters['SyncDbPassword'] 62 | 63 | # Hub credentials (Only SQL Authentication is supported) 64 | $HubServer = $parameters['HubServer'] 65 | $HubDatabase = $parameters['HubDatabase'] 66 | $HubUser = $parameters['HubUser'] 67 | $HubPassword = $parameters['HubPassword'] 68 | 69 | # Member credentials (Azure SQL DB or SQL Server) 70 | $MemberServer = $parameters['MemberServer'] 71 | $MemberDatabase = $parameters['MemberDatabase'] 72 | $MemberUser = $parameters['MemberUser'] 73 | $MemberPassword = $parameters['MemberPassword'] 74 | # set MemberUseWindowsAuthentication to $true in case you wish to use integrated Windows authentication (MemberUser and MemberPassword will be ignored) 75 | $MemberUseWindowsAuthentication = $false 76 | if ($parameters['MemberUseWindowsAuthentication']) { 77 | $MemberUseWindowsAuthentication = $parameters['MemberUseWindowsAuthentication'] 78 | } 79 | 80 | ## Health checks 81 | $HealthChecksEnabled = $true #Set as $true or $false 82 | if ($null -ne $parameters['HealthChecksEnabled']) { 83 | $HealthChecksEnabled = $parameters['HealthChecksEnabled'] 84 | } 85 | 86 | ## Monitoring 87 | if ($null -ne $parameters['MonitoringMode']) { 88 | $MonitoringMode = $parameters['MonitoringMode'] 89 | } 90 | 91 | if ($null -ne $parameters['MonitoringIntervalInSeconds']) { 92 | $MonitoringIntervalInSeconds = $parameters['MonitoringIntervalInSeconds'] 93 | } 94 | 95 | if ($null -ne $parameters['MonitoringDurationInMinutes']) { 96 | $MonitoringDurationInMinutes = $parameters['MonitoringDurationInMinutes'] 97 | } 98 | 99 | ## Tracking Record Validations 100 | # Set as "All" to validate all tables 101 | # or pick the tables you need using '[dbo].[TableName1]','[dbo].[TableName2]' 102 | $ExtendedValidationsTableFilter = @('All') 103 | if ($null -ne $parameters['ExtendedValidationsTableFilter']) { 104 | $ExtendedValidationsTableFilter = $parameters['ExtendedValidationsTableFilter'] 105 | } 106 | 107 | if ($null -ne $parameters['ExtendedValidationsEnabledForHub']) { 108 | $ExtendedValidationsEnabledForHub = $parameters['ExtendedValidationsEnabledForHub'] 109 | } 110 | 111 | if ($null -ne $parameters['ExtendedValidationsEnabledForMember']) { 112 | $ExtendedValidationsEnabledForMember = $parameters['ExtendedValidationsEnabledForMember'] 113 | } 114 | 115 | if ($null -ne $parameters['ExtendedValidationsCommandTimeout']) { 116 | $ExtendedValidationsCommandTimeout = $parameters['ExtendedValidationsCommandTimeout'] 117 | } 118 | 119 | ## Other 120 | if ($null -ne $parameters['SendAnonymousUsageData']) { 121 | $SendAnonymousUsageData = $parameters['SendAnonymousUsageData'] 122 | } 123 | 124 | if ($null -ne $parameters['DumpMetadataSchemasForSyncGroup']) { 125 | $DumpMetadataSchemasForSyncGroup = $parameters['DumpMetadataSchemasForSyncGroup'] 126 | } 127 | 128 | if ($null -ne $parameters['DumpMetadataObjectsForTable']) { 129 | $DumpMetadataObjectsForTable = $parameters['DumpMetadataObjectsForTable'] 130 | } 131 | } 132 | ##################################################################################################### 133 | 134 | $cmdTimeout = 300 135 | 136 | function ValidateTablesVSLocalSchema([Array] $userTables) { 137 | Try { 138 | if ($userTables.Count -eq 0) { 139 | $msg = "WARNING: member schema with 0 tables was detected, maybe related to provisioning issues." 140 | Write-Host $msg -Foreground Red 141 | [void]$errorSummary.AppendLine() 142 | [void]$errorSummary.AppendLine($msg) 143 | } 144 | else { 145 | Write-Host Schema has $userTables.Count tables 146 | } 147 | 148 | foreach ($userTable in $userTables) { 149 | $TablePKList = New-Object System.Collections.ArrayList 150 | 151 | $query = "SELECT 152 | c.name 'ColumnName', 153 | t.Name 'Datatype', 154 | c.max_length 'MaxLength', 155 | c.is_nullable 'IsNullable', 156 | c.is_computed 'IsComputed', 157 | c.default_object_id 'DefaultObjectId' 158 | FROM sys.columns c 159 | INNER JOIN sys.types t ON c.user_type_id = t.user_type_id 160 | WHERE c.object_id = OBJECT_ID('" + $userTable + "')" 161 | 162 | $MemberCommand.CommandText = $query 163 | $result = $MemberCommand.ExecuteReader() 164 | $datatable = new-object 'System.Data.DataTable' 165 | $datatable.Load($result) 166 | 167 | foreach ($userColumn in $datatable) { 168 | $sbCol = New-Object -TypeName "System.Text.StringBuilder" 169 | $schemaObj = $global:scope_config_data.SqlSyncProviderScopeConfiguration.Adapter | Where-Object GlobalName -eq $userTable 170 | $schemaColumn = $schemaObj.Col | Where-Object Name -eq $userColumn.ColumnName 171 | if (!$schemaColumn) { 172 | if (($userColumn.IsNullable -eq $false) -and ($userColumn.IsComputed -eq $false) -and ($userColumn.DefaultObjectId -eq 0) ) { 173 | $msg = "WARNING: " + $userTable + ".[" + $userColumn.ColumnName + "] is not included in the sync group but is NOT NULLABLE, not a computed column or has a default value!" 174 | Write-Host $msg -Foreground Red 175 | [void]$errorSummary.AppendLine($msg) 176 | } 177 | continue 178 | } 179 | 180 | [void]$sbCol.Append($userTable + ".[" + $userColumn.ColumnName + "] " + $schemaColumn.param) 181 | 182 | if ($schemaColumn.pk) { 183 | [void]$sbCol.Append(" PrimaryKey ") 184 | [void]$TablePKList.Add($schemaColumn.name) 185 | } 186 | 187 | if ($schemaColumn.type -ne $userColumn.Datatype) { 188 | [void]$sbCol.Append(' Type(' + $schemaColumn.type + '):NOK ') 189 | $msg = "WARNING: " + $userTable + ".[" + $userColumn.ColumnName + "] has a different datatype! (table:" + $userColumn.Datatype + " VS scope:" + $schemaColumn.type + ")" 190 | Write-Host $msg -Foreground Red 191 | [void]$errorSummary.AppendLine($msg) 192 | } 193 | else { 194 | [void]$sbCol.Append(' Type(' + $schemaColumn.type + '):OK ') 195 | } 196 | 197 | $colMaxLen = $userColumn.MaxLength 198 | 199 | if ($schemaColumn.type -eq 'nvarchar' -or $schemaColumn.type -eq 'nchar') { $colMaxLen = $colMaxLen / 2 } 200 | 201 | if ($userColumn.MaxLength -eq -1 -and ($schemaColumn.type -eq 'nvarchar' -or $schemaColumn.type -eq 'nchar' -or $schemaColumn.type -eq 'varbinary' -or $schemaColumn.type -eq 'varchar' -or $schemaColumn.type -eq 'nvarchar')) { $colMaxLen = 'max' } 202 | 203 | if ($schemaColumn.size -ne $colMaxLen) { 204 | [void]$sbCol.Append(' Size(' + $schemaColumn.size + '):NOK ') 205 | $msg = "WARNING: " + $userTable + ".[" + $userColumn.ColumnName + "] has a different data size!(table:" + $colMaxLen + " VS scope:" + $schemaColumn.size + ")" 206 | Write-Host $msg -Foreground Red 207 | [void]$errorSummary.AppendLine($msg) 208 | } 209 | else { 210 | [void]$sbCol.Append(' Size(' + $schemaColumn.size + '):OK ') 211 | } 212 | 213 | if ($schemaColumn.null) { 214 | if ($schemaColumn.null -ne $userColumn.IsNullable) { 215 | [void]$sbCol.Append(' Nullable(' + $schemaColumn.null + '):NOK ') 216 | $msg = "WARNING: " + $userTable + ".[" + $userColumn.ColumnName + "] has a different IsNullable! (table:" + $userColumn.IsNullable + " VS scope:" + $schemaColumn.null + ")" 217 | Write-Host $msg -Foreground Red 218 | [void]$errorSummary.AppendLine($msg) 219 | } 220 | else { 221 | [void]$sbCol.Append(' Nullable(' + $schemaColumn.null + '):OK ') 222 | } 223 | } 224 | 225 | $sbColString = $sbCol.ToString() 226 | if ($sbColString -match 'NOK') { Write-Host $sbColString -ForegroundColor Red } else { Write-Host $sbColString -ForegroundColor Green } 227 | 228 | } 229 | 230 | if ($ExtendedValidationsEnabled -and (($ExtendedValidationsTableFilter -contains 'All') -or ($ExtendedValidationsTableFilter -contains $userTable))) { 231 | ValidateTrackingRecords $userTable $TablePKList 232 | } 233 | } 234 | } 235 | Catch { 236 | Write-Host ValidateTablesVSLocalSchema exception: 237 | Write-Host $_.Exception.Message -ForegroundColor Red 238 | } 239 | } 240 | 241 | function ShowRowCountAndFragmentation([Array] $userTables) { 242 | Try { 243 | $tablesList = New-Object System.Collections.ArrayList 244 | 245 | foreach ($item in $userTables) { 246 | $tablesList.Add($item) > $null 247 | $tablesList.Add('[DataSync].[' + ($item.Replace("[", "").Replace("]", "").Split('.')[1]) + '_dss_tracking]') > $null 248 | } 249 | 250 | $tablesListStr = "'$($tablesList -join "','")'" 251 | 252 | Write-Host "Row Counts:" 253 | $query = "SELECT 254 | '['+s.name+'].['+ t.name+']' as TableName, 255 | p.rows AS RowCounts, 256 | CAST(ROUND(((SUM(a.total_pages) * 8) / 1024.00), 2) AS NUMERIC(36, 2)) AS TotalSpaceMB, 257 | CAST(ROUND(((SUM(a.used_pages) * 8) / 1024.00), 2) AS NUMERIC(36, 2)) AS UsedSpaceMB, 258 | CAST(ROUND(((SUM(a.total_pages) - SUM(a.used_pages)) * 8) / 1024.00, 2) AS NUMERIC(36, 2)) AS UnusedSpaceMB 259 | FROM sys.tables t 260 | INNER JOIN sys.indexes i ON t.OBJECT_ID = i.object_id 261 | INNER JOIN sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id 262 | INNER JOIN sys.allocation_units a ON p.partition_id = a.container_id 263 | LEFT OUTER JOIN sys.schemas s ON t.schema_id = s.schema_id 264 | WHERE '['+s.name+'].['+ t.name+']' IN (" + $tablesListStr + ") 265 | GROUP BY t.Name, s.Name, p.Rows 266 | ORDER BY '['+s.name+'].['+ t.name+']'" 267 | 268 | $MemberCommand.CommandTimeout = $cmdTimeout 269 | $MemberCommand.CommandText = $query 270 | $result = $MemberCommand.ExecuteReader() 271 | $datatable = new-object 'System.Data.DataTable' 272 | $datatable.Load($result) 273 | if ($datatable.Rows.Count -gt 0) { 274 | $datatable | Format-Table -Wrap -AutoSize | Out-String -Width 4096 275 | } 276 | 277 | Write-Host "Fragmentation:" 278 | $query = "SELECT '['+s.[name]+'].['+ t.[name]+']' as TableName, i.[name] as [IndexName], 279 | CONVERT(DECIMAL(10,2),idxstats.avg_fragmentation_in_percent) as FragmentationPercent, 280 | idxstats.page_count AS [PageCount] 281 | FROM sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL, NULL, NULL) AS idxstats 282 | INNER JOIN sys.tables t on t.[object_id] = idxstats.[object_id] 283 | INNER JOIN sys.schemas s on t.[schema_id] = s.[schema_id] 284 | INNER JOIN sys.indexes AS i ON i.[object_id] = idxstats.[object_id] AND idxstats.index_id = i.index_id 285 | WHERE '['+s.name+'].['+ t.name+']' IN (" + $tablesListStr + ") 286 | AND idxstats.database_id = DB_ID() AND idxstats.avg_fragmentation_in_percent >= 5 287 | ORDER BY idxstats.avg_fragmentation_in_percent desc" 288 | 289 | $MemberCommand.CommandText = $query 290 | $result = $MemberCommand.ExecuteReader() 291 | $datatable = new-object 'System.Data.DataTable' 292 | $datatable.Load($result) 293 | if ($datatable.Rows.Count -gt 0) { 294 | $datatable | Format-Table -Wrap -AutoSize | Out-String -Width 4096 295 | } 296 | else { 297 | Write-Host "- No relevant fragmentation (>5%) detected" -ForegroundColor Green 298 | Write-Host 299 | } 300 | } 301 | Catch { 302 | Write-Host ShowRowCountAndFragmentation exception: 303 | Write-Host $_.Exception.Message -ForegroundColor Red 304 | } 305 | } 306 | 307 | function ValidateTablesVSSyncDbSchema($SyncDbScopes) { 308 | Try { 309 | foreach ($SyncDbScope in $SyncDbScopes) { 310 | Write-Host 'Validating Table(s) VS SyncDB for' $SyncDbScope.SyncGroupName':' -Foreground White 311 | $ValidateTablesVSSyncDbSchemaIssuesFound = $false 312 | $syncdbscopeobj = ([xml]$SyncDbScope.SchemaDescription).DssSyncScopeDescription.TableDescriptionCollection.DssTableDescription 313 | $syncGroupSchemaTables = $syncdbscopeobj | Select-Object -ExpandProperty QuotedTableName 314 | 315 | foreach ($syncGroupSchemaTable in $syncGroupSchemaTables) { 316 | $syncGroupSchemaColumns = $syncdbscopeobj | Where-Object { $_.QuotedTableName -eq $syncGroupSchemaTable } | Select-Object -ExpandProperty ColumnsToSync 317 | 318 | $query = "SELECT 319 | c.name 'ColumnName', 320 | t.Name 'Datatype', 321 | c.max_length 'MaxLength', 322 | c.is_nullable 'IsNullable' 323 | FROM sys.columns c 324 | INNER JOIN sys.types t ON c.user_type_id = t.user_type_id 325 | WHERE c.object_id = OBJECT_ID('" + $syncGroupSchemaTable + "')" 326 | 327 | $MemberCommand.CommandText = $query 328 | $result = $MemberCommand.ExecuteReader() 329 | $datatable = new-object 'System.Data.DataTable' 330 | $datatable.Load($result) 331 | 332 | if ($datatable.Rows.Count -eq 0) { 333 | $ValidateTablesVSSyncDbSchemaIssuesFound = $true 334 | $msg = "WARNING: " + $syncGroupSchemaTable + " does not exist in the database but exist in the sync group schema." 335 | Write-Host $msg -Foreground Red 336 | [void]$errorSummary.AppendLine($msg) 337 | } 338 | else { 339 | foreach ($syncGroupSchemaColumn in $syncGroupSchemaColumns.DssColumnDescription) { 340 | $scopeCol = $datatable | Where-Object ColumnName -eq $syncGroupSchemaColumn.Name 341 | if (!$scopeCol) { 342 | $ValidateTablesVSSyncDbSchemaIssuesFound = $true 343 | $msg = "WARNING: " + $syncGroupSchemaTable + ".[" + $syncGroupSchemaColumn.Name + "] is missing in this database but exist in sync group schema, maybe preventing provisioning/re-provisioning!" 344 | Write-Host $msg -Foreground Red 345 | [void]$errorSummary.AppendLine($msg) 346 | } 347 | else { 348 | if ($syncGroupSchemaColumn.DataType -ne $scopeCol.Datatype) { 349 | $ValidateTablesVSSyncDbSchemaIssuesFound = $true 350 | $msg = "WARNING: " + $syncGroupSchemaTable + ".[" + $syncGroupSchemaColumn.Name + "] has a different datatype! (" + $syncGroupSchemaColumn.DataType + " VS " + $scopeCol.Datatype + ")" 351 | Write-Host $msg -Foreground Red 352 | [void]$errorSummary.AppendLine($msg) 353 | } 354 | else { 355 | $colMaxLen = $scopeCol.MaxLength 356 | if ($syncGroupSchemaColumn.DataType -eq 'nvarchar' -or $syncGroupSchemaColumn.DataType -eq 'nchar') { $colMaxLen = $colMaxLen / 2 } 357 | if ($scopeCol.MaxLength -eq -1 -and ($syncGroupSchemaColumn.DataType -eq 'nvarchar' -or $syncGroupSchemaColumn.DataType -eq 'nchar' -or $syncGroupSchemaColumn.DataType -eq 'varbinary' -or $syncGroupSchemaColumn.DataType -eq 'varchar' -or $syncGroupSchemaColumn.DataType -eq 'nvarchar')) { $colMaxLen = 'max' } 358 | 359 | if ($syncGroupSchemaColumn.DataSize -ne $colMaxLen) { 360 | $ValidateTablesVSSyncDbSchemaIssuesFound = $true 361 | $msg = "WARNING: " + $syncGroupSchemaTable + ".[" + $syncGroupSchemaColumn.Name + "] has a different data size! (" + $syncGroupSchemaColumn.DataSize + " VS " + $scopeCol.MaxLength + ")" 362 | Write-Host $msg -Foreground Red 363 | [void]$errorSummary.AppendLine($msg) 364 | } 365 | } 366 | } 367 | } 368 | } 369 | } 370 | if (!$ValidateTablesVSSyncDbSchemaIssuesFound) { 371 | Write-Host '- No issues detected for' $SyncDbScope.SyncGroupName -Foreground Green 372 | } 373 | } 374 | } 375 | Catch { 376 | Write-Host ValidateTablesVSSyncDbSchema exception: 377 | Write-Host $_.Exception.Message -ForegroundColor Red 378 | } 379 | } 380 | 381 | function ValidateTrackingRecords([String] $table, [Array] $tablePKList) { 382 | Try { 383 | Write-Host "Running ValidateTrackingRecords for" $table "..." -Foreground Green 384 | $tableNameWithoutSchema = ($table.Replace("[", "").Replace("]", "").Split('.'))[1] 385 | 386 | $sbQuery = New-Object -TypeName "System.Text.StringBuilder" 387 | $sbDeleteQuery = New-Object -TypeName "System.Text.StringBuilder" 388 | 389 | [void]$sbQuery.Append("SELECT COUNT(*) AS C FROM DataSync.[") 390 | [void]$sbQuery.Append($tableNameWithoutSchema) 391 | [void]$sbQuery.Append("_dss_tracking] t WITH (NOLOCK) WHERE sync_row_is_tombstone=0 AND NOT EXISTS (SELECT * FROM ") 392 | [void]$sbQuery.Append($table) 393 | [void]$sbQuery.Append(" s WITH (NOLOCK) WHERE ") 394 | 395 | [void]$sbDeleteQuery.Append("DELETE DataSync.[") 396 | [void]$sbDeleteQuery.Append($tableNameWithoutSchema) 397 | [void]$sbDeleteQuery.Append("_dss_tracking] FROM DataSync.[") 398 | [void]$sbDeleteQuery.Append($tableNameWithoutSchema) 399 | [void]$sbDeleteQuery.Append("_dss_tracking] t WHERE sync_row_is_tombstone=0 AND NOT EXISTS (SELECT * FROM ") 400 | [void]$sbDeleteQuery.Append($table) 401 | [void]$sbDeleteQuery.Append(" s WHERE ") 402 | 403 | for ($i = 0; $i -lt $tablePKList.Length; $i++) { 404 | if ($i -gt 0) { 405 | [void]$sbQuery.Append(" AND ") 406 | [void]$sbDeleteQuery.Append(" AND ") 407 | } 408 | [void]$sbQuery.Append("t." + $tablePKList[$i] + " = s." + $tablePKList[$i] ) 409 | [void]$sbDeleteQuery.Append("t." + $tablePKList[$i] + " = s." + $tablePKList[$i] ) 410 | } 411 | [void]$sbQuery.Append(")") 412 | [void]$sbDeleteQuery.Append(")") 413 | 414 | $previousMemberCommandTimeout = $MemberCommand.CommandTimeout 415 | $MemberCommand.CommandTimeout = $ExtendedValidationsCommandTimeout 416 | $MemberCommand.CommandText = $sbQuery.ToString() 417 | $result = $MemberCommand.ExecuteReader() 418 | $datatable = new-object 'System.Data.DataTable' 419 | $datatable.Load($result) 420 | $count = $datatable | Select-Object C -ExpandProperty C 421 | $MemberCommand.CommandTimeout = $previousMemberCommandTimeout 422 | 423 | if ($count -ne 0) { 424 | $msg = "WARNING: Tracking Records for Table " + $table + " may have " + $count + " invalid records!" 425 | Write-Host $msg -Foreground Red 426 | Write-Host $sbDeleteQuery.ToString() -Foreground Yellow 427 | [void]$errorSummary.AppendLine() 428 | [void]$errorSummary.AppendLine($msg) 429 | [void]$errorSummary.AppendLine($sbDeleteQuery.ToString()) 430 | } 431 | else { 432 | $msg = "No issues detected in Tracking Records for Table " + $table 433 | Write-Host $msg -Foreground Green 434 | } 435 | 436 | } 437 | Catch { 438 | Write-Host "Error at ValidateTrackingRecords" $table -Foreground Red 439 | Write-Host $_.Exception.Message -ForegroundColor Red 440 | } 441 | } 442 | 443 | function ValidateTrackingTable($table) { 444 | Try { 445 | if (![string]::IsNullOrEmpty($table)) { 446 | [void]$allTrackingTableList.Add($table) 447 | } 448 | 449 | $query = "SELECT COUNT(*) AS C FROM INFORMATION_SCHEMA.TABLES WHERE '['+TABLE_SCHEMA+'].['+ TABLE_NAME + ']' = '" + $table + "'" 450 | 451 | $MemberCommand.CommandText = $query 452 | $result = $MemberCommand.ExecuteReader() 453 | $datatable = new-object 'System.Data.DataTable' 454 | $datatable.Load($result) 455 | $count = $datatable | Select-Object C -ExpandProperty C 456 | 457 | if ($count -eq 1) { 458 | Write-Host "Tracking Table " $table "exists" -Foreground Green 459 | } 460 | 461 | if ($count -eq 0) { 462 | $msg = "WARNING: Tracking Table " + $table + " IS MISSING!" 463 | Write-Host $msg -Foreground Red 464 | [void]$errorSummary.AppendLine($msg) 465 | } 466 | } 467 | Catch { 468 | Write-Host "Error at ValidateTrackingTable" $table -Foreground Red 469 | Write-Host $_.Exception.Message -ForegroundColor Red 470 | } 471 | } 472 | 473 | function ValidateTrigger([String] $trigger) { 474 | Try { 475 | if (![string]::IsNullOrEmpty($trigger)) { 476 | [void]$allTriggersList.Add($trigger) 477 | } 478 | 479 | $query = "SELECT tr.name, tr.is_disabled AS 'Disabled' 480 | FROM sys.triggers tr 481 | INNER JOIN sys.tables t ON tr.parent_id = t.object_id 482 | INNER JOIN sys.schemas s ON t.schema_id = s.schema_id 483 | WHERE '['+s.name+'].['+ tr.name+']' = '" + $trigger + "'" 484 | 485 | $MemberCommand.CommandText = $query 486 | $result = $MemberCommand.ExecuteReader() 487 | $table = new-object 'System.Data.DataTable' 488 | $table.Load($result) 489 | $count = $table.Rows.Count 490 | 491 | if ($count -eq 1) { 492 | if ($table.Rows[0].Disabled -eq 1) { 493 | $msg = "WARNING (DSS035): Trigger " + $trigger + " exists but is DISABLED!" 494 | Write-Host $msg -Foreground Red 495 | [void]$errorSummary.AppendLine($msg) 496 | } 497 | else { 498 | Write-Host "Trigger" $trigger "exists and is enabled." -Foreground Green 499 | } 500 | 501 | $query = "sp_helptext '" + $trigger + "'" 502 | $MemberCommand.CommandText = $query 503 | $result = $MemberCommand.ExecuteReader() 504 | $sphelptextDataTable = new-object 'System.Data.DataTable' 505 | $sphelptextDataTable.Load($result) 506 | 507 | #DumpObject 508 | $tableNameWithoutSchema = ($DumpMetadataObjectsForTable.Replace("[", "").Replace("]", "").Split('.'))[1] + '_dss' 509 | if ($DumpMetadataObjectsForTable -and ($SP.IndexOf($tableNameWithoutSchema) -ne -1)) { 510 | $xmlResult = $sphelptextDataTable.Text 511 | if ($xmlResult -and $canWriteFiles) { 512 | $xmlResult | Out-File -filepath ('.\' + (SanitizeString $Server) + '_' + (SanitizeString $Database) + '_' + (SanitizeString $trigger) + '.txt') 513 | } 514 | } 515 | 516 | #orphan trigger validations 517 | $objectId = ([string[]] $sphelptextDataTable.Text) | Where-Object { $_ -match 'object_id' } | Select-Object -First 1 518 | 519 | if ($objectId) { 520 | $objectId = $objectId.Replace('WHERE [object_id] =', '').Trim() 521 | 522 | $query = "select COUNT(object_id) as C from sys.tables where object_id = " + $objectId 523 | $MemberCommand.CommandText = $query 524 | $result = $MemberCommand.ExecuteReader() 525 | $datatable = new-object 'System.Data.DataTable' 526 | $datatable.Load($result) 527 | if ($datatable.Rows[0].C -eq 0) { 528 | $msg = "WARNING: Table with object_id " + $objectId + " was not found, " + $trigger + " was provisoned using this object_id!" 529 | Write-Host $msg -Foreground Red 530 | [void]$errorSummary.AppendLine($msg) 531 | } 532 | else { 533 | $msg = " - Found table with object_id " + $objectId 534 | Write-Host $msg -Foreground Green 535 | } 536 | 537 | $query = "SELECT [owner_scope_local_id] FROM [DataSync].[provision_marker_dss] WHERE object_id = " + $objectId 538 | $MemberCommand.CommandText = $query 539 | $result = $MemberCommand.ExecuteReader() 540 | $datatable = new-object 'System.Data.DataTable' 541 | $datatable.Load($result) 542 | 543 | if ($datatable.Rows | Where-Object { $_.owner_scope_local_id -eq 0 }) { 544 | $msg = " - Found owner_scope_local_id 0 for object_id " + $objectId 545 | Write-Host $msg -Foreground Green 546 | } 547 | else { 548 | $msg = "WARNING: owner_scope_local_id 0 was not found for object_id " + $objectId 549 | Write-Host $msg -Foreground Red 550 | [void]$errorSummary.AppendLine($msg) 551 | } 552 | 553 | $owner_scope_local_id = ([string[]] $sphelptextDataTable.Text) | Where-Object { $_ -match 'owner_scope_local_id' -and $_ -notmatch '0' } 554 | if ($owner_scope_local_id) { 555 | $owner_scope_local_id = $owner_scope_local_id.Replace('AND [owner_scope_local_id] =', '').Trim() 556 | 557 | if ($datatable.Rows | Where-Object { $_.owner_scope_local_id -eq $owner_scope_local_id }) { 558 | $msg = " - Found owner_scope_local_id " + $owner_scope_local_id + " for object_id " + $objectId 559 | Write-Host $msg -Foreground Green 560 | } 561 | else { 562 | $msg = "WARNING: owner_scope_local_id " + $owner_scope_local_id + " was not found for object_id " + $objectId 563 | Write-Host $msg -Foreground Red 564 | [void]$errorSummary.AppendLine($msg) 565 | } 566 | } 567 | } 568 | } 569 | 570 | if ($count -eq 0) { 571 | $msg = "WARNING (DSS035): Trigger " + $trigger + " IS MISSING!" 572 | Write-Host $msg -Foreground Red 573 | [void]$errorSummary.AppendLine($msg) 574 | } 575 | } 576 | Catch { 577 | Write-Host "Error at ValidateTrigger" $trigger -Foreground Red 578 | Write-Host $_.Exception.Message -ForegroundColor Red 579 | } 580 | } 581 | 582 | function ValidateSP([String] $SP) { 583 | Try { 584 | if (![string]::IsNullOrEmpty($SP)) { 585 | [void]$allSPsList.Add($SP) 586 | } 587 | 588 | $query = "SELECT COUNT(*) AS C FROM sys.procedures p INNER JOIN sys.schemas s ON p.schema_id = s.schema_id WHERE '['+s.name+'].['+ p.name+']' = N'" + $SP + "'" 589 | $MemberCommand.CommandText = $query 590 | $result = $MemberCommand.ExecuteReader() 591 | $table = new-object 'System.Data.DataTable' 592 | $table.Load($result) 593 | $count = $table | Select-Object C -ExpandProperty C 594 | 595 | if ($count -eq 1) { 596 | Write-Host "Procedure" $SP "exists" -Foreground Green 597 | 598 | $query = "sp_helptext '" + $SP + "'" 599 | $MemberCommand.CommandText = $query 600 | $result = $MemberCommand.ExecuteReader() 601 | $sphelptextDataTable = new-object 'System.Data.DataTable' 602 | $sphelptextDataTable.Load($result) 603 | 604 | #DumpObject 605 | $tableNameWithoutSchema = ($DumpMetadataObjectsForTable.Replace("[", "").Replace("]", "").Split('.'))[1] + '_dss' 606 | if ($DumpMetadataObjectsForTable -and ($SP.IndexOf($tableNameWithoutSchema) -ne -1)) { 607 | $xmlResult = $sphelptextDataTable.Text 608 | if ($xmlResult -and $canWriteFiles) { 609 | $xmlResult | Out-File -filepath ('.\' + (SanitizeString $Server) + '_' + (SanitizeString $Database) + '_' + (SanitizeString $SP) + '.txt') 610 | } 611 | } 612 | 613 | #provision marker validations 614 | $objectId = ([string[]] $sphelptextDataTable.Text) | Where-Object { $_ -match 'object_id' } | Select-Object -First 1 615 | 616 | if ($objectId) { 617 | $objectId = $objectId.Replace('WHERE [object_id] =', '').Trim() 618 | 619 | $query = "select COUNT(object_id) as C from sys.tables where object_id = " + $objectId 620 | $MemberCommand.CommandText = $query 621 | $result = $MemberCommand.ExecuteReader() 622 | $datatable = new-object 'System.Data.DataTable' 623 | $datatable.Load($result) 624 | if ($datatable.Rows[0].C -eq 0) { 625 | $msg = "WARNING: Table with object_id " + $objectId + " was not found, " + $SP.Replace('[', '').Replace(']', '') + " was provisoned using this object_id!" 626 | Write-Host $msg -Foreground Red 627 | [void]$errorSummary.AppendLine($msg) 628 | } 629 | else { 630 | $msg = " - Found table with object_id " + $objectId 631 | Write-Host $msg -Foreground Green 632 | } 633 | 634 | $query = "SELECT [owner_scope_local_id] FROM [DataSync].[provision_marker_dss] WHERE object_id = " + $objectId 635 | $MemberCommand.CommandText = $query 636 | $result = $MemberCommand.ExecuteReader() 637 | $datatable = new-object 'System.Data.DataTable' 638 | $datatable.Load($result) 639 | 640 | if ($datatable.Rows | Where-Object { $_.owner_scope_local_id -eq 0 }) { 641 | $msg = " - Found owner_scope_local_id 0 for object_id " + $objectId 642 | Write-Host $msg -Foreground Green 643 | } 644 | else { 645 | $msg = "WARNING: owner_scope_local_id 0 was not found for object_id " + $objectId 646 | Write-Host $msg -Foreground Red 647 | [void]$errorSummary.AppendLine($msg) 648 | } 649 | 650 | $owner_scope_local_id = ([string[]] $sphelptextDataTable.Text) | Where-Object { $_ -match 'owner_scope_local_id' -and $_ -notmatch '0' } 651 | if ($owner_scope_local_id) { 652 | $owner_scope_local_id = $owner_scope_local_id.Replace('AND [owner_scope_local_id] =', '').Trim() 653 | 654 | if ($datatable.Rows | Where-Object { $_.owner_scope_local_id -eq $owner_scope_local_id }) { 655 | $msg = " - Found owner_scope_local_id " + $owner_scope_local_id + " for object_id " + $objectId 656 | Write-Host $msg -Foreground Green 657 | } 658 | else { 659 | $msg = "WARNING: owner_scope_local_id " + $owner_scope_local_id + " was not found for object_id " + $objectId 660 | Write-Host $msg -Foreground Red 661 | [void]$errorSummary.AppendLine($msg) 662 | } 663 | } 664 | } 665 | } 666 | if ($count -eq 0) { 667 | $msg = "WARNING: Procedure " + $SP + " IS MISSING!" 668 | Write-Host $msg -Foreground Red 669 | [void]$errorSummary.AppendLine($msg) 670 | } 671 | } 672 | Catch { 673 | Write-Host "Error at ValidateSP" $SP -Foreground Red 674 | Write-Host $_.Exception.Message -ForegroundColor Red 675 | } 676 | } 677 | 678 | function ValidateBulkType([String] $bulkType, $columns) { 679 | Try { 680 | if (![string]::IsNullOrEmpty($bulkType)) { 681 | [void]$allBulkTypeList.Add($bulkType) 682 | } 683 | 684 | $query = "select tt.name 'Type', 685 | c.name 'ColumnName', 686 | t.Name 'Datatype', 687 | c.max_length 'MaxLength', 688 | c.is_nullable 'IsNullable', 689 | c.column_id 'ColumnId' 690 | from sys.table_types tt 691 | inner join sys.columns c on c.object_id = tt.type_table_object_id 692 | inner join sys.types t ON c.user_type_id = t.user_type_id 693 | where '['+ SCHEMA_NAME(tt.schema_id) +'].['+ tt.name+']' ='" + $bulkType + "'" 694 | 695 | $MemberCommand.CommandText = $query 696 | $result = $MemberCommand.ExecuteReader() 697 | $table = new-object 'System.Data.DataTable' 698 | $table.Load($result) 699 | $count = $table.Rows.Count 700 | 701 | if ($count -gt 0) { 702 | Write-Host "Type" $bulkType "exists" -Foreground Green 703 | foreach ($column in $columns) { 704 | $sbCol = New-Object -TypeName "System.Text.StringBuilder" 705 | $typeColumn = $table.Rows | Where-Object ColumnName -eq $column.name 706 | 707 | if (!$typeColumn) { 708 | $msg = "WARNING: " + $bulkType + ".[" + $column.name + "] does not exit!" 709 | Write-Host $msg -Foreground Red 710 | [void]$errorSummary.AppendLine($msg) 711 | continue 712 | } 713 | 714 | [void]$sbCol.Append("- [" + $column.name + "] " + $column.param) 715 | 716 | if ($column.type -ne $typeColumn.Datatype) { 717 | if ($column.type -eq 'geography' -or $column.type -eq 'geometry') { 718 | [void]$sbCol.Append(' Type(' + $column.type + '):Expected diff ') 719 | } 720 | else { 721 | [void]$sbCol.Append(' Type(' + $column.type + '):NOK ') 722 | $msg = "WARNING: " + $bulkType + ".[" + $column.name + "] has a different datatype! (type:" + $typeColumn.Datatype + " VS scope:" + $column.type + ")" 723 | Write-Host $msg -Foreground Red 724 | [void]$errorSummary.AppendLine($msg) 725 | } 726 | } 727 | else { 728 | [void]$sbCol.Append(' Type(' + $column.type + '):OK ') 729 | } 730 | 731 | $colMaxLen = $typeColumn.MaxLength 732 | 733 | if ($column.type -eq 'nvarchar' -or $column.type -eq 'nchar') { $colMaxLen = $colMaxLen / 2 } 734 | 735 | if ($typeColumn.MaxLength -eq -1 -and ($column.type -eq 'nvarchar' -or $column.type -eq 'nchar' -or $column.type -eq 'varbinary' -or $column.type -eq 'varchar' -or $column.type -eq 'nvarchar')) { $colMaxLen = 'max' } 736 | 737 | if ($column.size -ne $colMaxLen) { 738 | [void]$sbCol.Append(' Size(' + $column.size + '):NOK ') 739 | $msg = "WARNING: " + $bulkType + ".[" + $column.name + "] has a different data size!(type:" + $colMaxLen + " VS scope:" + $column.size + ")" 740 | Write-Host $msg -Foreground Red 741 | [void]$errorSummary.AppendLine($msg) 742 | } 743 | else { 744 | [void]$sbCol.Append(' Size(' + $column.size + '):OK ') 745 | } 746 | 747 | if ($column.null) { 748 | if ($column.null -ne $typeColumn.IsNullable) { 749 | [void]$sbCol.Append(' Nullable(' + $column.null + '):NOK ') 750 | $msg = "WARNING: " + $bulkType + ".[" + $column.name + "] has a different IsNullable! (type:" + $typeColumn.IsNullable + " VS scope:" + $column.null + ")" 751 | Write-Host $msg -Foreground Red 752 | [void]$errorSummary.AppendLine($msg) 753 | } 754 | else { 755 | [void]$sbCol.Append(' Nullable(' + $column.null + '):OK ') 756 | } 757 | } 758 | 759 | $sbColString = $sbCol.ToString() 760 | 761 | if ($sbColString -match 'NOK') { 762 | Write-Host $sbColString -ForegroundColor Red 763 | } 764 | else { 765 | Write-Host $sbColString -ForegroundColor Green 766 | } 767 | } 768 | } 769 | if ($count -eq 0) { 770 | $msg = "WARNING: Type " + $bulkType + " IS MISSING!" 771 | Write-Host $msg -Foreground Red 772 | [void]$errorSummary.AppendLine($msg) 773 | } 774 | 775 | #DumpObject 776 | $tableNameWithoutSchema = ($DumpMetadataObjectsForTable.Replace("[", "").Replace("]", "").Split('.'))[1] + '_dss_BulkType_' 777 | if ($DumpMetadataObjectsForTable -and $bulkType -match $tableNameWithoutSchema -and $canWriteFiles) { 778 | $table | Out-File -filepath ('.\' + (SanitizeString $Server) + '_' + (SanitizeString $Database) + '_' + (SanitizeString $bulkType) + '.txt') 779 | } 780 | } 781 | Catch { 782 | Write-Host "Error at ValidateBulkType" $bulkType -Foreground Red 783 | Write-Host $_.Exception.Message -ForegroundColor Red 784 | } 785 | } 786 | 787 | function DetectTrackingTableLeftovers() { 788 | Try { 789 | $allTrackingTableString = "'$($allTrackingTableList -join "','")'" 790 | $query = "SELECT '['+TABLE_SCHEMA+'].['+ TABLE_NAME + ']' as FullTableName, TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME LIKE '%_dss_tracking' AND '['+TABLE_SCHEMA+'].['+ TABLE_NAME + ']' NOT IN (" + $allTrackingTableString + ")" 791 | $MemberCommand.CommandText = $query 792 | $result = $MemberCommand.ExecuteReader() 793 | $datatable = new-object 'System.Data.DataTable' 794 | $datatable.Load($result) 795 | 796 | if (($datatable.FullTableName).Count -eq 0) { 797 | Write-Host "There are no Tracking Table leftovers" -Foreground Green 798 | } 799 | else { 800 | foreach ($leftover in $datatable) { 801 | Write-Host "WARNING: Tracking Table" $leftover.FullTableName "should be a leftover." -Foreground Yellow 802 | $deleteStatement = "Drop Table " + $leftover.FullTableName + ";" 803 | [void]$runnableScript.AppendLine($deleteStatement) 804 | [void]$runnableScript.AppendLine("GO") 805 | 806 | $leftover.TABLE_NAME = ($leftover.TABLE_NAME -replace "_dss_tracking", "") 807 | $query = "SELECT [object_id] FROM [DataSync].[provision_marker_dss] WHERE [owner_scope_local_id] = 0 and object_name([object_id]) = '" + $leftover.TABLE_NAME + "'" 808 | $MemberCommand.CommandText = $query 809 | $provision_marker_result2 = $MemberCommand.ExecuteReader() 810 | $provision_marker_leftovers2 = new-object 'System.Data.DataTable' 811 | $provision_marker_leftovers2.Load($provision_marker_result2) 812 | 813 | foreach ($provision_marker_leftover2 in $provision_marker_leftovers2) { 814 | $deleteStatement = "DELETE FROM [DataSync].[provision_marker_dss] WHERE [owner_scope_local_id] = 0 and [object_id] = " + $provision_marker_leftover2.object_id + " --" + $leftover.TABLE_NAME 815 | Write-Host "WARNING: [DataSync].[provision_marker_dss] WHERE [owner_scope_local_id] = 0 and [object_id] = " $provision_marker_leftover2.object_id "(" $leftover.TABLE_NAME ") should be a leftover." -Foreground Yellow 816 | [void]$runnableScript.AppendLine($deleteStatement) 817 | [void]$runnableScript.AppendLine("GO") 818 | } 819 | } 820 | } 821 | } 822 | Catch { 823 | Write-Host DetectTrackingTableLeftovers exception: 824 | Write-Host $_.Exception.Message -ForegroundColor Red 825 | } 826 | } 827 | 828 | function DetectTriggerLeftovers() { 829 | Try { 830 | $allTriggersString = "'$($allTriggersList -join "','")'" 831 | $query = "SELECT '['+s.name+'].['+ trig.name+']' 832 | FROM sys.triggers trig 833 | INNER JOIN sys.tables t ON trig.parent_id = t.object_id 834 | INNER JOIN sys.schemas s ON t.schema_id = s.schema_id 835 | WHERE trig.name like '&_dss_&' AND '['+s.name+'].['+ trig.name+']' NOT IN (" + $allTriggersString + ")" 836 | 837 | $MemberCommand.CommandText = $query 838 | $result = $MemberCommand.ExecuteReader() 839 | $datatable = new-object 'System.Data.DataTable' 840 | $datatable.Load($result) 841 | 842 | if (($datatable.Column1).Count -eq 0) { 843 | Write-Host "There are no Trigger leftovers" -Foreground Green 844 | } 845 | else { 846 | foreach ($leftover in $datatable.Column1) { 847 | Write-Host "WARNING: Trigger" $leftover "should be a leftover." -Foreground Yellow 848 | $deleteStatement = "Drop Trigger " + $leftover + ";" 849 | [void]$runnableScript.AppendLine($deleteStatement) 850 | [void]$runnableScript.AppendLine("GO") 851 | } 852 | } 853 | } 854 | Catch { 855 | Write-Host DetectTriggerLeftovers exception: 856 | Write-Host $_.Exception.Message -ForegroundColor Red 857 | } 858 | } 859 | 860 | function DetectProcedureLeftovers() { 861 | Try { 862 | $allSPsString = "'$($allSPsList -join "','")'" 863 | $query = "SELECT '['+s.name+'].['+ p.name+']' 864 | FROM sys.procedures p 865 | INNER JOIN sys.schemas s ON p.schema_id = s.schema_id 866 | WHERE p.name like '%_dss_%' AND '['+s.name+'].['+ p.name+']' NOT IN (" + $allSPsString + ")" 867 | 868 | $MemberCommand.CommandText = $query 869 | $result = $MemberCommand.ExecuteReader() 870 | $datatable = new-object 'System.Data.DataTable' 871 | $datatable.Load($result) 872 | 873 | if (($datatable.Column1).Count -eq 0) { 874 | Write-Host "There are no Procedure leftovers" -Foreground Green 875 | } 876 | else { 877 | foreach ($leftover in $datatable.Column1) { 878 | Write-Host "WARNING: Procedure" $leftover "should be a leftover." -Foreground Yellow 879 | $deleteStatement = "Drop Procedure " + $leftover + ";" 880 | [void]$runnableScript.AppendLine($deleteStatement) 881 | [void]$runnableScript.AppendLine("GO") 882 | } 883 | } 884 | } 885 | Catch { 886 | Write-Host DetectProcedureLeftovers exception: 887 | Write-Host $_.Exception.Message -ForegroundColor Red 888 | } 889 | } 890 | 891 | function DetectBulkTypeLeftovers() { 892 | Try { 893 | $allBulkTypeString = "'$($allBulkTypeList -join "','")'" 894 | $query = "select distinct '['+ SCHEMA_NAME(tt.schema_id) +'].['+ tt.name+']' 'Type' 895 | from sys.table_types tt 896 | inner join sys.columns c on c.object_id = tt.type_table_object_id 897 | inner join sys.types t ON c.user_type_id = t.user_type_id 898 | where SCHEMA_NAME(tt.schema_id) = 'DataSync' and '['+ SCHEMA_NAME(tt.schema_id) +'].['+ tt.name+']' NOT IN (" + $allBulkTypeString + ")" 899 | 900 | $MemberCommand.CommandText = $query 901 | $result = $MemberCommand.ExecuteReader() 902 | $datatable = new-object 'System.Data.DataTable' 903 | $datatable.Load($result) 904 | 905 | if (($datatable.Type).Count -eq 0) { 906 | Write-Host "There are no Bulk Type leftovers" -Foreground Green 907 | } 908 | else { 909 | foreach ($leftover in $datatable.Type) { 910 | Write-Host "WARNING: Bulk Type" $leftover "should be a leftover." -Foreground Yellow 911 | $deleteStatement = "Drop Type " + $leftover + ";" 912 | [void]$runnableScript.AppendLine($deleteStatement) 913 | [void]$runnableScript.AppendLine("GO") 914 | } 915 | } 916 | } 917 | Catch { 918 | Write-Host DetectBulkTypeLeftovers exception: 919 | Write-Host $_.Exception.Message -ForegroundColor Red 920 | } 921 | } 922 | 923 | function ValidateFKDependencies([Array] $userTables) { 924 | Try { 925 | $allTablesFKString = "'$($userTables -join "','")'" 926 | 927 | $query = "SELECT 928 | OBJECT_NAME(fk.parent_object_id) TableName 929 | ,OBJECT_NAME(fk.constraint_object_id) FKName 930 | ,OBJECT_NAME(fk.referenced_object_id) ParentTableName 931 | ,t.name TrackingTableName 932 | FROM sys.foreign_key_columns fk 933 | INNER JOIN sys.tables t2 ON t2.name = OBJECT_NAME(fk.parent_object_id) 934 | INNER JOIN sys.schemas s ON s.schema_id = t2.schema_id 935 | LEFT OUTER JOIN sys.tables t ON t.name like OBJECT_NAME(fk.referenced_object_id)+'_dss_tracking' 936 | WHERE t.name IS NULL AND '['+s.name +'].['+OBJECT_NAME(fk.parent_object_id)+']' IN (" + $allTablesFKString + ")" 937 | 938 | $MemberCommand.CommandText = $query 939 | $result = $MemberCommand.ExecuteReader() 940 | $datatable = new-object 'System.Data.DataTable' 941 | $datatable.Load($result) 942 | 943 | if ($datatable.Rows.Count -gt 0) { 944 | $msg = "WARNING: Missing tables in the sync group due to FK references:" 945 | Write-Host $msg -Foreground Red 946 | [void]$errorSummary.AppendLine() 947 | [void]$errorSummary.AppendLine($msg) 948 | 949 | foreach ($fkrow in $datatable) { 950 | $msg = "- The " + $fkrow.FKName + " in " + $fkrow.TableName + " needs " + $fkrow.ParentTableName 951 | Write-Host $msg -Foreground Yellow 952 | [void]$errorSummary.AppendLine($msg) 953 | } 954 | } 955 | else { 956 | Write-Host "No FKs referencing tables not used in sync group detected" -ForegroundColor Green 957 | } 958 | } 959 | Catch { 960 | Write-Host ValidateFKDependencies exception: 961 | Write-Host $_.Exception.Message -ForegroundColor Red 962 | } 963 | } 964 | 965 | function ValidateProvisionMarker { 966 | Try { 967 | $query = "SELECT COUNT(*) AS C FROM sys.tables WHERE schema_name(schema_id) = 'DataSync' and [name] = 'provision_marker_dss'" 968 | $MemberCommand.CommandText = $query 969 | $result = $MemberCommand.ExecuteReader() 970 | $datatable = new-object 'System.Data.DataTable' 971 | $datatable.Load($result) 972 | $provisionMarkerDSSExists = ($datatable.Rows[0].C -eq 1); 973 | 974 | if (!$provisionMarkerDSSExists) { 975 | $query = "WITH TrackingTablesObjId_CTE (object_id) AS ( 976 | SELECT OBJECT_ID(REPLACE([name], '_dss_tracking', '')) 977 | FROM sys.tables WHERE schema_name(schema_id) = 'DataSync' and [name] like ('%_dss_tracking')) 978 | SELECT '['+OBJECT_SCHEMA_NAME(cte.object_id)+'].['+ OBJECT_NAME(cte.object_id) +']' AS TableName, cte.object_id 979 | FROM TrackingTablesObjId_CTE AS cte WHERE cte.object_id IS NOT NULL" 980 | } 981 | else { 982 | $query = "WITH TrackingTablesObjId_CTE (object_id) AS ( 983 | SELECT OBJECT_ID(REPLACE([name], '_dss_tracking', '')) 984 | FROM sys.tables WHERE schema_name(schema_id) = 'DataSync' and [name] like ('%_dss_tracking')) 985 | SELECT '['+OBJECT_SCHEMA_NAME(cte.object_id)+'].['+ OBJECT_NAME(cte.object_id) +']' AS TableName, cte.object_id 986 | FROM TrackingTablesObjId_CTE AS cte 987 | LEFT OUTER JOIN [DataSync].[provision_marker_dss] marker on marker.owner_scope_local_id = 0 and marker.object_id = cte.object_id 988 | WHERE marker.object_id IS NULL AND cte.object_id IS NOT NULL" 989 | } 990 | 991 | $MemberCommand.CommandText = $query 992 | $result = $MemberCommand.ExecuteReader() 993 | $datatable = new-object 'System.Data.DataTable' 994 | $datatable.Load($result) 995 | 996 | if ($datatable.Rows.Count -gt 0) { 997 | 998 | $msg = "WARNING (DSS034): ValidateProvisionMarker found some possible issues" 999 | Write-Host $msg -Foreground Yellow 1000 | [void]$errorSummary.AppendLine() 1001 | [void]$errorSummary.AppendLine($msg) 1002 | 1003 | $msg = "This can cause the error: Cannot insert the value NULL into column 'provision_timestamp', table '(...).DataSync.provision_marker_dss';" 1004 | Write-Host $msg -Foreground Yellow 1005 | [void]$errorSummary.AppendLine($msg) 1006 | 1007 | foreach ($row in $datatable) { 1008 | if (!$provisionMarkerDSSExists) { 1009 | $msg = "- Tracking table for " + $row.TableName + " exists but provision_marker_dss table does not exist" 1010 | } 1011 | else { 1012 | $msg = "- Tracking table for " + $row.TableName + " exists but there is no provision_marker record with object_id " + $row.object_id 1013 | } 1014 | Write-Host $msg -Foreground Yellow 1015 | [void]$errorSummary.AppendLine($msg) 1016 | } 1017 | } 1018 | else { 1019 | Write-Host "ValidateProvisionMarker did not detect any issue" -ForegroundColor Green 1020 | } 1021 | } 1022 | Catch { 1023 | Write-Host ValidateProvisionMarker exception: 1024 | Write-Host $_.Exception.Message -ForegroundColor Red 1025 | } 1026 | } 1027 | 1028 | function ValidateCircularReferences { 1029 | Try { 1030 | $query = "SELECT OBJECT_SCHEMA_NAME(fk1.parent_object_id) + '.' + OBJECT_NAME(fk1.parent_object_id) Table1, OBJECT_SCHEMA_NAME(fk2.parent_object_id) + '.' + OBJECT_NAME(fk2.parent_object_id) Table2,fk1.name FK1Name, fk2.name FK2Name 1031 | FROM sys.foreign_keys AS fk1 1032 | INNER JOIN sys.foreign_keys AS fk2 ON fk1.parent_object_id = fk2.referenced_object_id AND fk2.parent_object_id = fk1.referenced_object_id 1033 | WHERE fk1.parent_object_id <> fk2.parent_object_id;" 1034 | $MemberCommand.CommandText = $query 1035 | $result = $MemberCommand.ExecuteReader() 1036 | $datatable = new-object 'System.Data.DataTable' 1037 | $datatable.Load($result) 1038 | 1039 | if ($datatable.Rows.Count -gt 0) { 1040 | $msg = "WARNING: ValidateCircularReferences found some circular references in this database:" 1041 | Write-Host $msg -Foreground Yellow 1042 | [void]$errorSummary.AppendLine() 1043 | [void]$errorSummary.AppendLine($msg) 1044 | 1045 | foreach ($row in $datatable) { 1046 | $msg = "- " + $row.Table1 + " | " + $row.Table2 + " | " + $row.FK1Name + " | " + $row.FK2Name 1047 | Write-Host $msg -Foreground Yellow 1048 | [void]$errorSummary.AppendLine($msg) 1049 | } 1050 | [void]$errorSummary.AppendLine() 1051 | } 1052 | else { 1053 | Write-Host "ValidateCircularReferences did not detect any issue" -ForegroundColor Green 1054 | } 1055 | } 1056 | Catch { 1057 | Write-Host ValidateCircularReferences exception: 1058 | Write-Host $_.Exception.Message -ForegroundColor Red 1059 | } 1060 | } 1061 | 1062 | function ValidateTableNames { 1063 | Try { 1064 | $query = "SELECT DISTINCT t1.name AS TableName FROM sys.tables t1 LEFT JOIN sys.tables t2 ON t1.name = t2.name AND t1.object_id <> t2.object_id WHERE (t2.schema_id) IS NOT NULL AND SCHEMA_NAME(t1.schema_id) NOT IN ('dss','TaskHosting')" 1065 | $MemberCommand.CommandText = $query 1066 | $result = $MemberCommand.ExecuteReader() 1067 | $datatable = new-object 'System.Data.DataTable' 1068 | $datatable.Load($result) 1069 | 1070 | if ($datatable.Rows.Count -gt 0) { 1071 | $msg = "INFO: ValidateTableNames found some tables names in multiple schemas in this database:" 1072 | Write-Host $msg -Foreground Yellow 1073 | [void]$errorSummary.AppendLine() 1074 | [void]$errorSummary.AppendLine($msg) 1075 | 1076 | foreach ($row in $datatable) { 1077 | $msg = "- " + $row.TableName + " seems to exist in multiple schemas!" 1078 | Write-Host $msg -Foreground Yellow 1079 | [void]$errorSummary.AppendLine($msg) 1080 | } 1081 | } 1082 | else { 1083 | Write-Host "ValidateTableNames did not detect any issue" -ForegroundColor Green 1084 | } 1085 | } 1086 | Catch { 1087 | Write-Host ValidateTableNames exception: 1088 | Write-Host $_.Exception.Message -ForegroundColor Red 1089 | } 1090 | } 1091 | 1092 | function ValidateObjectNames { 1093 | Try { 1094 | $query = "SELECT table_schema, table_name, column_name 1095 | FROM information_schema.columns 1096 | WHERE table_name LIKE '%.%' OR table_name LIKE '%[[]%' OR table_name LIKE '%]%' 1097 | OR column_name LIKE '%.%' OR column_name LIKE '%[[]%' OR column_name LIKE '%]%'" 1098 | $MemberCommand.CommandText = $query 1099 | $result = $MemberCommand.ExecuteReader() 1100 | $datatable = new-object 'System.Data.DataTable' 1101 | $datatable.Load($result) 1102 | 1103 | if ($datatable.Rows.Count -gt 0) { 1104 | $msg = "WARNING: ValidateObjectNames found some issues:" 1105 | Write-Host $msg -Foreground Yellow 1106 | [void]$errorSummary.AppendLine() 1107 | [void]$errorSummary.AppendLine($msg) 1108 | 1109 | foreach ($row in $datatable) { 1110 | $msg = "- [" + $row.table_schema + "].[" + $row.table_name + "].[" + $row.column_name + "]" 1111 | Write-Host $msg -Foreground Yellow 1112 | [void]$errorSummary.AppendLine($msg) 1113 | } 1114 | } 1115 | else { 1116 | Write-Host "ValidateObjectNames did not detect any issue" -ForegroundColor Green 1117 | } 1118 | } 1119 | Catch { 1120 | Write-Host ValidateObjectNames exception: 1121 | Write-Host $_.Exception.Message -ForegroundColor Red 1122 | } 1123 | } 1124 | 1125 | function DetectProvisioningIssues { 1126 | Try { 1127 | $query = "with TrackingTables as ( 1128 | select REPLACE(name,'_dss_tracking','') as TrackingTableOrigin, name TrackingTable 1129 | from sys.tables 1130 | where SCHEMA_NAME(schema_id) = 'DataSync' AND [name] not in ('schema_info_dss','scope_info_dss','scope_config_dss','provision_marker_dss') 1131 | ) 1132 | select TrackingTable from TrackingTables c 1133 | left outer join sys.tables t on c.TrackingTableOrigin = t.[name] 1134 | where t.[name] is null" 1135 | 1136 | $MemberCommand.CommandText = $query 1137 | $result = $MemberCommand.ExecuteReader() 1138 | $datatable = new-object 'System.Data.DataTable' 1139 | $datatable.Load($result) 1140 | 1141 | foreach ($extraTrackingTable in $datatable) { 1142 | $msg = "WARNING: " + $extraTrackingTable.TrackingTable + " exists but the corresponding user table does not exist! this maybe preventing provisioning/re-provisioning!" 1143 | Write-Host $msg -Foreground Red 1144 | [void]$errorSummary.AppendLine($msg) 1145 | } 1146 | } 1147 | Catch { 1148 | Write-Host DetectProvisioningIssues exception: 1149 | Write-Host $_.Exception.Message -ForegroundColor Red 1150 | } 1151 | } 1152 | 1153 | function DetectComputedColumns { 1154 | Try { 1155 | $query = "SELECT SCHEMA_NAME(T.schema_id) AS SchemaName, T.name AS TableName, C.name AS ColumnName FROM sys.objects AS T JOIN sys.columns AS C ON T.object_id = C.object_id WHERE T.type = 'U' AND C.is_computed = 1;" 1156 | $MemberCommand.CommandText = $query 1157 | $result = $MemberCommand.ExecuteReader() 1158 | $datatable = new-object 'System.Data.DataTable' 1159 | $datatable.Load($result) 1160 | 1161 | if ($datatable.Rows.Count -gt 0) { 1162 | $msg = "INFO: Computed columns detected (only an issue if part of sync schema):" 1163 | Write-Host $msg -Foreground Yellow 1164 | [void]$errorSummary.AppendLine() 1165 | [void]$errorSummary.AppendLine($msg) 1166 | 1167 | foreach ($row in $datatable) { 1168 | $msg = "- [" + $row.SchemaName + "].[" + $row.TableName + "].[" + $row.ColumnName + "]" 1169 | Write-Host $msg -Foreground Yellow 1170 | [void]$errorSummary.AppendLine($msg) 1171 | } 1172 | } 1173 | else { 1174 | Write-Host "DetectComputedColumns did not detect any computed column" -ForegroundColor Green 1175 | } 1176 | } 1177 | Catch { 1178 | Write-Host ValidateObjectNames exception: 1179 | Write-Host $_.Exception.Message -ForegroundColor Red 1180 | } 1181 | } 1182 | 1183 | function GetUIHistory { 1184 | Try { 1185 | $query = "WITH UIHistory_CTE ([completionTime], SyncGroupName,DatabaseName,OperationResult,Seconds,Upload,UploadFailed,Download,DownloadFailed, Error) 1186 | AS 1187 | ( 1188 | SELECT ui.[completionTime], sg.[name] SyncGroupName, ud.[database] DatabaseName, ui.[detailEnumId] OperationResult 1189 | ,CAST (ui.detailStringParameters as XML).value('(/ArrayOfString//string/node())[1]', 'nvarchar(max)') as Seconds 1190 | ,CAST (ui.detailStringParameters as XML).value('(/ArrayOfString//string/node())[2]', 'nvarchar(max)') as Upload 1191 | ,'' as UploadFailed 1192 | ,CAST (ui.detailStringParameters as XML).value('(/ArrayOfString//string/node())[3]', 'nvarchar(max)') as Download 1193 | ,'' as DownloadFailed 1194 | ,'' as Error 1195 | FROM [dss].[UIHistory] AS ui WITH (NOLOCK) 1196 | INNER JOIN [dss].[syncgroup] AS sg WITH (NOLOCK) on ui.syncgroupId = sg.id 1197 | INNER JOIN [dss].[userdatabase] AS ud WITH (NOLOCK) on ui.databaseid = ud.id 1198 | WHERE ui.[detailEnumId] = 'SyncSuccess' AND ud.[server] = '" + $Server + "' AND ud.[database] = '" + $Database + "' 1199 | UNION ALL 1200 | SELECT ui.[completionTime], sg.[name] SyncGroupName, ud.[database] DatabaseName, ui.[detailEnumId] OperationResult 1201 | ,CAST (ui.detailStringParameters as XML).value('(/ArrayOfString//string/node())[1]', 'nvarchar(max)') as Seconds 1202 | ,CAST (ui.detailStringParameters as XML).value('(/ArrayOfString//string/node())[2]', 'nvarchar(max)') as Upload 1203 | ,CAST (ui.detailStringParameters as XML).value('(/ArrayOfString//string/node())[3]', 'nvarchar(max)') as UploadFailed 1204 | ,CAST (ui.detailStringParameters as XML).value('(/ArrayOfString//string/node())[4]', 'nvarchar(max)') as Download 1205 | ,CAST (ui.detailStringParameters as XML).value('(/ArrayOfString//string/node())[5]', 'nvarchar(max)') as DownloadFailed 1206 | ,'' as Error 1207 | FROM [dss].[UIHistory] AS ui WITH (NOLOCK) 1208 | INNER JOIN [dss].[syncgroup] AS sg WITH (NOLOCK) on ui.syncgroupId = sg.id 1209 | INNER JOIN [dss].[userdatabase] AS ud WITH (NOLOCK) on ui.databaseid = ud.id 1210 | WHERE ui.[detailEnumId] = 'SyncSuccessWithWarning' AND ud.[server] = '" + $Server + "' AND ud.[database] = '" + $Database + "' 1211 | UNION ALL 1212 | SELECT ui.[completionTime], sg.[name] SyncGroupName, ud.[database] DatabaseName, ui.[detailEnumId] OperationResult 1213 | ,'' as Seconds 1214 | ,'' as Upload 1215 | ,'' as UploadFailed 1216 | ,'' as Download 1217 | ,'' as DownloadFailed 1218 | ,CAST (ui.detailStringParameters as XML).value('(/ArrayOfString//string/node())[1]', 'nvarchar(max)') as Error 1219 | FROM [dss].[UIHistory] AS ui WITH (NOLOCK) 1220 | INNER JOIN [dss].[syncgroup] AS sg WITH (NOLOCK) on ui.syncgroupId = sg.id 1221 | INNER JOIN [dss].[userdatabase] AS ud WITH (NOLOCK) on ui.databaseid = ud.id 1222 | WHERE ui.[detailEnumId] like '%Failure' AND ud.[server] = '" + $Server + "' AND ud.[database] = '" + $Database + "' 1223 | UNION ALL 1224 | SELECT ui.[completionTime], sg.[name] SyncGroupName, ud.[database] DatabaseName, ui.[detailEnumId] OperationResult 1225 | ,'' as Seconds 1226 | ,'' as Upload 1227 | ,'' as UploadFailed 1228 | ,'' as Download 1229 | ,'' as DownloadFailed 1230 | ,'' as Error 1231 | FROM [dss].[UIHistory] AS ui WITH (NOLOCK) 1232 | INNER JOIN [dss].[syncgroup] AS sg WITH (NOLOCK) on ui.syncgroupId = sg.id 1233 | INNER JOIN [dss].[userdatabase] AS ud WITH (NOLOCK) on ui.databaseid = ud.id 1234 | WHERE ui.[detailEnumId] != 'SyncSuccess' AND ui.[detailEnumId] != 'SyncSuccessWithWarning' AND ui.[detailEnumId] NOT LIKE '%Failure' 1235 | AND ud.[server] = '" + $Server + "' AND ud.[database] = '" + $Database + "') 1236 | SELECT TOP(30) [completionTime],SyncGroupName,OperationResult,Seconds,Upload,UploadFailed AS UpFailed,Download,DownloadFailed AS DFailed,Error 1237 | FROM UIHistory_CTE ORDER BY [completionTime] DESC" 1238 | 1239 | $SyncDbCommand.CommandTimeout = 120 1240 | $SyncDbCommand.CommandText = $query 1241 | $result = $SyncDbCommand.ExecuteReader() 1242 | $datatable = new-object 'System.Data.DataTable' 1243 | $datatable.Load($result) 1244 | 1245 | if ($datatable.Rows.Count -gt 0) { 1246 | Write-Host "UI History:" -Foreground White 1247 | $datatable | Format-Table -AutoSize -Wrap | Out-String -Width 4096 1248 | 1249 | $top = $datatable | Group-Object -Property SyncGroupName | ForEach-Object { $_ | Select-Object -ExpandProperty Group | Select-Object -First 1 } 1250 | $shouldDump = $top | Where-Object { $_.OperationResult -like '*Failure*' } 1251 | if ($null -ne $shouldDump -and $DumpMetadataSchemasForSyncGroup -eq '') { 1252 | foreach ($error in $shouldDump) { 1253 | DumpMetadataSchemasForSyncGroup $error.SyncGroupName 1254 | } 1255 | } 1256 | 1257 | $refreshSchemaTimeouts = $datatable | Where-Object { $_.OperationResult -like 'SchemaRefreshFailure' -and $_.Error -like '*The wait operation timed out*' } 1258 | foreach ($refreshSchemaTimeout in $refreshSchemaTimeouts) { 1259 | Write-Host 1260 | TrackWarningAnonymously 'DSS038' 1261 | $DSS038 = [System.Text.StringBuilder]::new() 1262 | [void]$DSS038.AppendLine( "ROOT CAUSE (DSS038):") 1263 | [void]$DSS038.AppendLine( " On " + $refreshSchemaTimeout.completionTime + " a Refresh Schema failed with 'The wait operation timed out'") 1264 | [void]$DSS038.AppendLine( " After fetching all the schema from the database, Data Sync saves this information in Sync Metadata Database.") 1265 | [void]$DSS038.AppendLine( " In case the performance tier of Sync Metadata Database is small or has heavy load, the operation may timeout when the database schema that needs to be saved is big/complex.") 1266 | [void]$DSS038.AppendLine( "MITIGATION:") 1267 | [void]$DSS038.AppendLine( " Please scale up the Sync Metadata Database. You may scale down once the data sync schema is set, you may need to scale back up if Refresh Schema is needed again.") 1268 | Write-Host $DSS038.ToString() -Foreground Red 1269 | [void]$errorSummary.AppendLine($DSS038.ToString()) 1270 | Write-Host 1271 | } 1272 | 1273 | $openDataReaderErrors = $datatable | Where-Object { $_.OperationResult -like 'SchemaRefreshFailure' -and $_.Error -like '*There is already an open DataReader associated with this Command which must be closed first*' } 1274 | foreach ($openDataReaderError in $openDataReaderErrors) { 1275 | Write-Host 1276 | TrackWarningAnonymously 'DSS023' 1277 | $DSS023 = [System.Text.StringBuilder]::new() 1278 | [void]$DSS023.AppendLine( "ROOT CAUSE (DSS023):") 1279 | [void]$DSS023.AppendLine( " On " + $openDataReaderError.completionTime + " a Refresh Schema failed with 'There is already an open DataReader associated with this Command which must be closed first'") 1280 | [void]$DSS023.AppendLine( " This error is caused by triggering a new Refresh Schema operation while the previous one has not completed yet.") 1281 | [void]$DSS023.AppendLine( "MITIGATION:") 1282 | [void]$DSS023.AppendLine( " Please wait for the previous Refresh Schema operation to complete before triggering a new one.") 1283 | Write-Host $DSS023.ToString() -Foreground Red 1284 | [void]$errorSummary.AppendLine($DSS023.ToString()) 1285 | Write-Host 1286 | } 1287 | 1288 | $incorrectSyntaxErrors = $datatable | Where-Object { $_.Error -like "*Incorrect syntax near 'MERGE'*" } 1289 | foreach ($incorrectSyntaxError in $incorrectSyntaxErrors) { 1290 | Write-Host 1291 | TrackWarningAnonymously 'DSS025' 1292 | $DSS025 = [System.Text.StringBuilder]::new() 1293 | [void]$DSS025.AppendLine( "ROOT CAUSE (DSS025):") 1294 | [void]$DSS025.AppendLine( " On " + $incorrectSyntaxError.completionTime + " there is a failed task with Incorrect syntax near 'MERGE'") 1295 | [void]$DSS025.AppendLine( " This error is usually caused by running under compatibility level <100") 1296 | [void]$DSS025.AppendLine( "MITIGATION:") 1297 | [void]$DSS025.AppendLine( " Please check the compatibility level using: SELECT compatibility level FROM sys.databases WHERE name = DB_NAME();") 1298 | [void]$DSS025.AppendLine( " In case you are running on <100, please consider updating using: ALTER DATABASE myDatabaseName SET COMPATIBILITY_LEVEL = 100") 1299 | Write-Host $DSS025.ToString() -Foreground Red 1300 | [void]$errorSummary.AppendLine($DSS025.ToString()) 1301 | Write-Host 1302 | } 1303 | 1304 | $incorrectSyntaxErrors = $datatable | Where-Object { $_.Error -like "*Incorrect syntax near the keyword 'AS'*" } 1305 | foreach ($incorrectSyntaxError in $incorrectSyntaxErrors) { 1306 | Write-Host 1307 | TrackWarningAnonymously 'DSS025' 1308 | $DSS025 = [System.Text.StringBuilder]::new() 1309 | [void]$DSS025.AppendLine( "ROOT CAUSE (DSS025):") 1310 | [void]$DSS025.AppendLine( " On " + $incorrectSyntaxError.completionTime + " there is a failed task with Incorrect syntax near the keyword 'AS'") 1311 | [void]$DSS025.AppendLine( " This error is usually caused by running under compatibility level <100") 1312 | [void]$DSS025.AppendLine( "MITIGATION:") 1313 | [void]$DSS025.AppendLine( " Please check the compatibility level using: SELECT compatibility level FROM sys.databases WHERE name = DB_NAME();") 1314 | [void]$DSS025.AppendLine( " In case you are running on <100, please consider updating using: ALTER DATABASE myDatabaseName SET COMPATIBILITY_LEVEL = 100") 1315 | Write-Host $DSS025.ToString() -Foreground Red 1316 | [void]$errorSummary.AppendLine($DSS025.ToString()) 1317 | Write-Host 1318 | } 1319 | 1320 | $incorrectSyntaxErrors = $datatable | Where-Object { $_.Error -like "*Incorrect syntax near the keyword 'NOT'*" } 1321 | foreach ($incorrectSyntaxError in $incorrectSyntaxErrors) { 1322 | Write-Host 1323 | TrackWarningAnonymously 'DSS039' 1324 | $DSS039 = [System.Text.StringBuilder]::new() 1325 | [void]$DSS039.AppendLine( "ROOT CAUSE (DSS039):") 1326 | [void]$DSS039.AppendLine( " On " + $incorrectSyntaxError.completionTime + " there is a failed task with Incorrect syntax near the keyword 'NOT'") 1327 | [void]$DSS039.AppendLine( " SQL Data Sync provides basic database auto-provisioning when the table does not exist in the database, but this has some limitations.") 1328 | [void]$DSS039.AppendLine( " The issue is being caused by a lack of default value in some column(s) during auto-provisioning.") 1329 | [void]$DSS039.AppendLine( "MITIGATION:") 1330 | [void]$DSS039.AppendLine( " Please provision the database schema manually.") 1331 | [void]$DSS039.AppendLine( " This is usually done by extracting the schema from the source and creating it manually in the destination.") 1332 | Write-Host $DSS039.ToString() -Foreground Red 1333 | [void]$errorSummary.AppendLine($DSS039.ToString()) 1334 | Write-Host 1335 | } 1336 | } 1337 | } 1338 | Catch { 1339 | Write-Host GetUIHistory exception: 1340 | Write-Host $_.Exception.Message -ForegroundColor Red 1341 | } 1342 | } 1343 | 1344 | function GetUIHistoryForSyncDBValidator { 1345 | Try { 1346 | $query = "WITH UIHistory_CTE ([completionTime], SyncGroupName,DatabaseName,OperationResult,Seconds,Upload,UploadFailed,Download,DownloadFailed, Error) 1347 | AS 1348 | ( 1349 | SELECT ui.[completionTime], sg.[name] SyncGroupName, ud.[database] DatabaseName, ui.[detailEnumId] OperationResult 1350 | ,CAST (ui.detailStringParameters as XML).value('(/ArrayOfString//string/node())[1]', 'nvarchar(max)') as Seconds 1351 | ,CAST (ui.detailStringParameters as XML).value('(/ArrayOfString//string/node())[2]', 'nvarchar(max)') as Upload 1352 | ,'' as UploadFailed 1353 | ,CAST (ui.detailStringParameters as XML).value('(/ArrayOfString//string/node())[3]', 'nvarchar(max)') as Download 1354 | ,'' as DownloadFailed 1355 | ,'' as Error 1356 | FROM [dss].[UIHistory] AS ui WITH (NOLOCK) 1357 | INNER JOIN [dss].[syncgroup] AS sg WITH (NOLOCK) on ui.syncgroupId = sg.id 1358 | INNER JOIN [dss].[userdatabase] AS ud WITH (NOLOCK) on ui.databaseid = ud.id 1359 | WHERE ui.[detailEnumId] = 'SyncSuccess' 1360 | UNION ALL 1361 | SELECT ui.[completionTime], sg.[name] SyncGroupName, ud.[database] DatabaseName, ui.[detailEnumId] OperationResult 1362 | ,CAST (ui.detailStringParameters as XML).value('(/ArrayOfString//string/node())[1]', 'nvarchar(max)') as Seconds 1363 | ,CAST (ui.detailStringParameters as XML).value('(/ArrayOfString//string/node())[2]', 'nvarchar(max)') as Upload 1364 | ,CAST (ui.detailStringParameters as XML).value('(/ArrayOfString//string/node())[3]', 'nvarchar(max)') as UploadFailed 1365 | ,CAST (ui.detailStringParameters as XML).value('(/ArrayOfString//string/node())[4]', 'nvarchar(max)') as Download 1366 | ,CAST (ui.detailStringParameters as XML).value('(/ArrayOfString//string/node())[5]', 'nvarchar(max)') as DownloadFailed 1367 | ,'' as Error 1368 | FROM [dss].[UIHistory] AS ui WITH (NOLOCK) 1369 | INNER JOIN [dss].[syncgroup] AS sg WITH (NOLOCK) on ui.syncgroupId = sg.id 1370 | INNER JOIN [dss].[userdatabase] AS ud WITH (NOLOCK) on ui.databaseid = ud.id 1371 | WHERE ui.[detailEnumId] = 'SyncSuccessWithWarning' 1372 | UNION ALL 1373 | SELECT ui.[completionTime], sg.[name] SyncGroupName, ud.[database] DatabaseName, ui.[detailEnumId] OperationResult 1374 | ,'' as Seconds 1375 | ,'' as Upload 1376 | ,'' as UploadFailed 1377 | ,'' as Download 1378 | ,'' as DownloadFailed 1379 | ,CAST (ui.detailStringParameters as XML).value('(/ArrayOfString//string/node())[1]', 'nvarchar(max)') as Error 1380 | FROM [dss].[UIHistory] AS ui WITH (NOLOCK) 1381 | INNER JOIN [dss].[syncgroup] AS sg WITH (NOLOCK) on ui.syncgroupId = sg.id 1382 | INNER JOIN [dss].[userdatabase] AS ud WITH (NOLOCK) on ui.databaseid = ud.id 1383 | WHERE ui.[detailEnumId] like '%Failure' 1384 | UNION ALL 1385 | SELECT ui.[completionTime], sg.[name] SyncGroupName, ud.[database] DatabaseName, ui.[detailEnumId] OperationResult 1386 | ,'' as Seconds 1387 | ,'' as Upload 1388 | ,'' as UploadFailed 1389 | ,'' as Download 1390 | ,'' as DownloadFailed 1391 | ,'' as Error 1392 | FROM [dss].[UIHistory] AS ui WITH (NOLOCK) 1393 | INNER JOIN [dss].[syncgroup] AS sg WITH (NOLOCK) on ui.syncgroupId = sg.id 1394 | INNER JOIN [dss].[userdatabase] AS ud WITH (NOLOCK) on ui.databaseid = ud.id 1395 | WHERE ui.[detailEnumId] != 'SyncSuccess' AND ui.[detailEnumId] != 'SyncSuccessWithWarning' AND ui.[detailEnumId] NOT LIKE '%Failure') 1396 | SELECT TOP(50) [completionTime],SyncGroupName,OperationResult,Seconds,Upload,UploadFailed AS UpFailed,Download,DownloadFailed AS DFailed,Error 1397 | FROM UIHistory_CTE ORDER BY [completionTime] DESC" 1398 | 1399 | $SyncDbCommand.CommandTimeout = 120 1400 | $SyncDbCommand.CommandText = $query 1401 | $result = $SyncDbCommand.ExecuteReader() 1402 | $datatable = new-object 'System.Data.DataTable' 1403 | $datatable.Load($result) 1404 | 1405 | if ($datatable.Rows.Count -gt 0) { 1406 | Write-Host "UI History:" -Foreground White 1407 | $datatable | Format-Table -AutoSize -Wrap | Out-String -Width 4096 1408 | } 1409 | } 1410 | Catch { 1411 | Write-Host GetUIHistoryForSyncDBValidator exception: 1412 | Write-Host $_.Exception.Message -ForegroundColor Red 1413 | } 1414 | } 1415 | 1416 | function SendAnonymousUsageData { 1417 | Try { 1418 | #Despite computername and username will be used to calculate a hash string, this will keep you anonymous but allow us to identify multiple runs from the same user 1419 | $StringBuilderHash = New-Object System.Text.StringBuilder 1420 | [System.Security.Cryptography.HashAlgorithm]::Create("MD5").ComputeHash([System.Text.Encoding]::UTF8.GetBytes($env:computername + $env:username)) | ForEach-Object { 1421 | [Void]$StringBuilderHash.Append($_.ToString("x2")) 1422 | } 1423 | 1424 | $body = New-Object PSObject ` 1425 | | Add-Member -PassThru NoteProperty name 'Microsoft.ApplicationInsights.Event' ` 1426 | | Add-Member -PassThru NoteProperty time $([System.dateTime]::UtcNow.ToString('o')) ` 1427 | | Add-Member -PassThru NoteProperty iKey "c8aa884b-5a60-4bec-b49e-702d69657409" ` 1428 | | Add-Member -PassThru NoteProperty tags (New-Object PSObject | Add-Member -PassThru NoteProperty 'ai.user.id' $StringBuilderHash.ToString()) ` 1429 | | Add-Member -PassThru NoteProperty data (New-Object PSObject ` 1430 | | Add-Member -PassThru NoteProperty baseType 'EventData' ` 1431 | | Add-Member -PassThru NoteProperty baseData (New-Object PSObject ` 1432 | | Add-Member -PassThru NoteProperty ver 2 ` 1433 | | Add-Member -PassThru NoteProperty name '6.24' ` 1434 | | Add-Member -PassThru NoteProperty properties (New-Object PSObject ` 1435 | | Add-Member -PassThru NoteProperty 'Source:' "Microsoft/AzureSQLDataSyncHealthChecker"` 1436 | | Add-Member -PassThru NoteProperty 'HealthChecksEnabled' $HealthChecksEnabled.ToString()` 1437 | | Add-Member -PassThru NoteProperty 'MonitoringMode' $MonitoringMode.ToString()` 1438 | | Add-Member -PassThru NoteProperty 'MonitoringIntervalInSeconds' $MonitoringIntervalInSeconds.ToString()` 1439 | | Add-Member -PassThru NoteProperty 'MonitoringDurationInMinutes' $MonitoringDurationInMinutes.ToString()` 1440 | | Add-Member -PassThru NoteProperty 'ExtendedValidationsCommandTimeout' $ExtendedValidationsCommandTimeout.ToString()` 1441 | | Add-Member -PassThru NoteProperty 'ExtendedValidationsEnabledForHub' $ExtendedValidationsEnabledForHub.ToString() ` 1442 | | Add-Member -PassThru NoteProperty 'ExtendedValidationsEnabledForMember' $ExtendedValidationsEnabledForMember.ToString() ))); 1443 | $body = $body | ConvertTo-JSON -depth 5; 1444 | Invoke-WebRequest -Uri 'https://dc.services.visualstudio.com/v2/track' -Method 'POST' -UseBasicParsing -body $body > $null 1445 | } 1446 | Catch { 1447 | Write-Host SendAnonymousUsageData exception: 1448 | Write-Host $_.Exception.Message -ForegroundColor Red 1449 | } 1450 | } 1451 | 1452 | function TrackWarningAnonymously ([String] $warningCode) { 1453 | Try { 1454 | #Despite computername and username will be used to calculate a hash string, this will keep you anonymous but allow us to identify multiple runs from the same user 1455 | $StringBuilderHash = New-Object System.Text.StringBuilder 1456 | [System.Security.Cryptography.HashAlgorithm]::Create("MD5").ComputeHash([System.Text.Encoding]::UTF8.GetBytes($env:computername + $env:username)) | ForEach-Object { 1457 | [Void]$StringBuilderHash.Append($_.ToString("x2")) 1458 | } 1459 | 1460 | $body = New-Object PSObject ` 1461 | | Add-Member -PassThru NoteProperty name 'Microsoft.ApplicationInsights.Event' ` 1462 | | Add-Member -PassThru NoteProperty time $([System.dateTime]::UtcNow.ToString('o')) ` 1463 | | Add-Member -PassThru NoteProperty iKey "c8aa884b-5a60-4bec-b49e-702d69657409" ` 1464 | | Add-Member -PassThru NoteProperty tags (New-Object PSObject | Add-Member -PassThru NoteProperty 'ai.user.id' $StringBuilderHash.ToString()) ` 1465 | | Add-Member -PassThru NoteProperty data (New-Object PSObject ` 1466 | | Add-Member -PassThru NoteProperty baseType 'EventData' ` 1467 | | Add-Member -PassThru NoteProperty baseData (New-Object PSObject ` 1468 | | Add-Member -PassThru NoteProperty ver 2 ` 1469 | | Add-Member -PassThru NoteProperty name $warningCode)); 1470 | $body = $body | ConvertTo-JSON -depth 5; 1471 | Invoke-WebRequest -Uri 'https://dc.services.visualstudio.com/v2/track' -Method 'POST' -UseBasicParsing -body $body > $null 1472 | } 1473 | Catch { 1474 | Write-Host TrackWarningAnonymously exception: 1475 | Write-Host $_.Exception.Message -ForegroundColor Red 1476 | } 1477 | } 1478 | 1479 | function ValidateSyncDB { 1480 | Try { 1481 | $SyncDbConnection = New-Object System.Data.SqlClient.SQLConnection 1482 | $SyncDbConnection.ConnectionString = [string]::Format("Server=tcp:{0},1433;Initial Catalog={1};Persist Security Info=False;User ID={2};Password={3};MultipleActiveResultSets=False;Encrypt=True;TrustServerCertificate=False;Connection Timeout=30;", $SyncDbServer, $SyncDbDatabase, $SyncDbUser, $SyncDbPassword) 1483 | 1484 | Write-Host Connecting to SyncDB $SyncDbServer"/"$SyncDbDatabase 1485 | Try { 1486 | $SyncDbConnection.Open() 1487 | } 1488 | Catch { 1489 | Write-Host Error connecting to the database -ForegroundColor Red 1490 | Write-Host $_.Exception.Message -ForegroundColor Red 1491 | Test-NetConnection $SyncDbServer -Port 1433 1492 | Break 1493 | } 1494 | 1495 | $SyncDbCommand = New-Object System.Data.SQLClient.SQLCommand 1496 | $SyncDbCommand.Connection = $SyncDbConnection 1497 | $SyncDbCommand.CommandTimeout = $cmdTimeout 1498 | 1499 | $query = "select [name] from sys.schemas where name in ('dss','TaskHosting')" 1500 | $SyncDbCommand.CommandText = $query 1501 | $result = $SyncDbCommand.ExecuteReader() 1502 | $datatable = new-object 'System.Data.DataTable' 1503 | $datatable.Load($result) 1504 | 1505 | if (($datatable.Rows | Where-Object { $_.name -eq "dss" } | Measure-Object).Count -gt 0) { 1506 | Write-Host "dss schema exists" -Foreground White 1507 | } 1508 | else { 1509 | $msg = "WARNING: dss schema IS MISSING!" 1510 | Write-Host $msg -Foreground Red 1511 | [void]$errorSummaryForSyncDB.AppendLine($msg) 1512 | } 1513 | 1514 | if (($datatable.Rows | Where-Object { $_.name -eq "TaskHosting" } | Measure-Object).Count -gt 0) { 1515 | Write-Host "TaskHosting schema exists" -Foreground White 1516 | } 1517 | else { 1518 | $msg = "WARNING: TaskHosting schema IS MISSING!" 1519 | Write-Host $msg -Foreground Red 1520 | [void]$errorSummaryForSyncDB.AppendLine($msg) 1521 | } 1522 | 1523 | $query = "select schema_name(schema_id) as [name], count(*) as 'Count' from sys.tables 1524 | where schema_name(schema_id) = 'dss' or schema_name(schema_id) = 'TaskHosting' 1525 | group by schema_name(schema_id)" 1526 | $SyncDbCommand.CommandText = $query 1527 | $result = $SyncDbCommand.ExecuteReader() 1528 | $datatable = new-object 'System.Data.DataTable' 1529 | $datatable.Load($result) 1530 | 1531 | $spCount = $datatable.Rows | Where-Object { $_.name -eq "dss" } 1532 | if ($spCount.Count -gt 0) { 1533 | Write-Host "dss" $spCount.Count "tables found" -Foreground White 1534 | } 1535 | else { 1536 | $msg = "WARNING: dss tables are MISSING!" 1537 | Write-Host $msg -Foreground Red 1538 | [void]$errorSummaryForSyncDB.AppendLine($msg) 1539 | } 1540 | 1541 | $spCount = $datatable.Rows | Where-Object { $_.name -eq "TaskHosting" } 1542 | if ($spCount.Count -gt 0) { 1543 | Write-Host "TaskHosting" $spCount.Count "tables found" -Foreground White 1544 | } 1545 | else { 1546 | $msg = "WARNING: TaskHosting tables are MISSING!" 1547 | Write-Host $msg -Foreground Red 1548 | [void]$errorSummaryForSyncDB.AppendLine($msg) 1549 | } 1550 | 1551 | $query = "select schema_name(schema_id) as [name], count(*) as 'Count' from sys.procedures 1552 | where schema_name(schema_id) = 'dss' or schema_name(schema_id) = 'TaskHosting' 1553 | group by schema_name(schema_id)" 1554 | $SyncDbCommand.CommandText = $query 1555 | $result = $SyncDbCommand.ExecuteReader() 1556 | $datatable = new-object 'System.Data.DataTable' 1557 | $datatable.Load($result) 1558 | 1559 | $spCount = $datatable.Rows | Where-Object { $_.name -eq "dss" } 1560 | if ($spCount.Count -gt 0) { 1561 | Write-Host "dss" $spCount.Count "stored procedures found" -Foreground White 1562 | } 1563 | else { 1564 | $msg = "WARNING: dss stored procedures are MISSING!" 1565 | Write-Host $msg -Foreground Red 1566 | [void]$errorSummaryForSyncDB.AppendLine($msg) 1567 | } 1568 | 1569 | $spCount = $datatable.Rows | Where-Object { $_.name -eq "TaskHosting" } 1570 | if ($spCount.Count -gt 0) { 1571 | Write-Host "TaskHosting" $spCount.Count "stored procedures found" -Foreground White 1572 | } 1573 | else { 1574 | $msg = "WARNING: TaskHosting stored procedures are MISSING!" 1575 | Write-Host $msg -Foreground Red 1576 | [void]$errorSummaryForSyncDB.AppendLine($msg) 1577 | } 1578 | 1579 | $query = "select schema_name(schema_id) as [name], count(*) as 'Count' 1580 | from sys.types where is_user_defined = 1 and schema_name(schema_id) = 'dss' or schema_name(schema_id) = 'TaskHosting' 1581 | group by schema_name(schema_id)" 1582 | $SyncDbCommand.CommandText = $query 1583 | $result = $SyncDbCommand.ExecuteReader() 1584 | $datatable = new-object 'System.Data.DataTable' 1585 | $datatable.Load($result) 1586 | 1587 | $spCount = $datatable.Rows | Where-Object { $_.name -eq "dss" } 1588 | if ($spCount.Count -gt 0) { 1589 | Write-Host "dss" $spCount.Count "types found" -Foreground White 1590 | } 1591 | else { 1592 | $msg = "WARNING: dss types are MISSING!" 1593 | Write-Host $msg -Foreground Red 1594 | [void]$errorSummaryForSyncDB.AppendLine($msg) 1595 | } 1596 | 1597 | $spCount = $datatable.Rows | Where-Object { $_.name -eq "TaskHosting" } 1598 | if ($spCount.Count -gt 0) { 1599 | Write-Host "TaskHosting" $spCount.Count "types found" -Foreground White 1600 | } 1601 | else { 1602 | $msg = "WARNING: TaskHosting types are MISSING!" 1603 | Write-Host $msg -Foreground Red 1604 | [void]$errorSummaryForSyncDB.AppendLine($msg) 1605 | } 1606 | 1607 | $query = "select schema_name(schema_id) as [name], count(*) as 'Count' 1608 | from sys.objects where type in ( 'FN', 'IF', 'TF' ) 1609 | and schema_name(schema_id) = 'dss' or schema_name(schema_id) = 'TaskHosting' 1610 | group by schema_name(schema_id)" 1611 | 1612 | $SyncDbCommand.CommandText = $query 1613 | $result = $SyncDbCommand.ExecuteReader() 1614 | $datatable = new-object 'System.Data.DataTable' 1615 | $datatable.Load($result) 1616 | 1617 | $spCount = $datatable.Rows | Where-Object { $_.name -eq "dss" } 1618 | if ($spCount.Count -gt 0) { 1619 | Write-Host "dss" $spCount.Count "functions found" -Foreground White 1620 | } 1621 | else { 1622 | $msg = "WARNING: dss functions are MISSING!" 1623 | Write-Host $msg -Foreground Red 1624 | [void]$errorSummaryForSyncDB.AppendLine($msg) 1625 | } 1626 | 1627 | $spCount = $datatable.Rows | Where-Object { $_.name -eq "TaskHosting" } 1628 | if ($spCount.Count -gt 0) { 1629 | Write-Host "TaskHosting" $spCount.Count "functions found" -Foreground White 1630 | } 1631 | else { 1632 | $msg = "WARNING: TaskHosting functions are MISSING!" 1633 | Write-Host $msg -Foreground Red 1634 | [void]$errorSummaryForSyncDB.AppendLine($msg) 1635 | } 1636 | 1637 | $query = "select name from sys.sysusers where name in ('##MS_SyncAccount##','DataSync_reader','DataSync_executor','DataSync_admin')" 1638 | $SyncDbCommand.CommandText = $query 1639 | $result = $SyncDbCommand.ExecuteReader() 1640 | $datatable = new-object 'System.Data.DataTable' 1641 | $datatable.Load($result) 1642 | 1643 | if (($datatable.Rows | Where-Object { $_.name -eq "##MS_SyncAccount##" } | Measure-Object).Count -gt 0) { Write-Host "##MS_SyncAccount## exists" -Foreground White } 1644 | else { 1645 | $msg = "WARNING: ##MS_SyncAccount## IS MISSING!" 1646 | Write-Host $msg -Foreground Red 1647 | [void]$errorSummaryForSyncDB.AppendLine($msg) 1648 | } 1649 | 1650 | if (($datatable.Rows | Where-Object { $_.name -eq "DataSync_reader" } | Measure-Object).Count -gt 0) { Write-Host "DataSync_reader exists" -Foreground White } 1651 | else { 1652 | $msg = "WARNING: DataSync_reader IS MISSING!" 1653 | Write-Host $msg -Foreground Red 1654 | [void]$errorSummaryForSyncDB.AppendLine($msg) 1655 | } 1656 | 1657 | if (($datatable.Rows | Where-Object { $_.name -eq "DataSync_executor" } | Measure-Object).Count -gt 0) { Write-Host "DataSync_executor exists" -Foreground White } 1658 | else { 1659 | $msg = "WARNING: DataSync_executor IS MISSING!" 1660 | Write-Host $msg -Foreground Red 1661 | [void]$errorSummaryForSyncDB.AppendLine($msg) 1662 | } 1663 | 1664 | if (($datatable.Rows | Where-Object { $_.name -eq "DataSync_admin" } | Measure-Object).Count -gt 0) { Write-Host "DataSync_admin exists" -Foreground White } 1665 | else { 1666 | $msg = "WARNING: DataSync_admin IS MISSING!" 1667 | Write-Host $msg -Foreground Red 1668 | [void]$errorSummaryForSyncDB.AppendLine($msg) 1669 | } 1670 | 1671 | $query = "select [name] AS DataSyncEncryptionKeys from sys.symmetric_keys where name like 'DataSyncEncryptionKey%'" 1672 | $SyncDbCommand.CommandText = $query 1673 | $result = $SyncDbCommand.ExecuteReader() 1674 | $datatable = new-object 'System.Data.DataTable' 1675 | $datatable.Load($result) 1676 | 1677 | $keyCount = $datatable.Rows 1678 | if ($keyCount.Count -gt 0) { 1679 | Write-Host 1680 | Write-Host $datatable.rows.Count DataSyncEncryptionKeys 1681 | $datatable.Rows | Format-Table -Wrap -AutoSize | Out-String -Width 4096 1682 | } 1683 | else { 1684 | $msg = "WARNING: no DataSyncEncryptionKeys were found!" 1685 | Write-Host $msg -Foreground Red 1686 | [void]$errorSummaryForSyncDB.AppendLine($msg) 1687 | } 1688 | 1689 | $query = "select [name] as 'DataSyncEncryptionCertificates' from sys.certificates where name like 'DataSyncEncryptionCertificate%'" 1690 | $SyncDbCommand.CommandText = $query 1691 | $result = $SyncDbCommand.ExecuteReader() 1692 | $datatable = new-object 'System.Data.DataTable' 1693 | $datatable.Load($result) 1694 | 1695 | $keyCount = $datatable.Rows 1696 | if ($keyCount.Count -gt 0) { 1697 | Write-Host 1698 | Write-Host $datatable.rows.Count DataSyncEncryptionCertificates 1699 | $datatable.Rows | Format-Table -Wrap -AutoSize | Out-String -Width 4096 1700 | } 1701 | else { 1702 | $msg = "WARNING: no DataSyncEncryptionCertificates were found!" 1703 | Write-Host $msg -Foreground Red 1704 | [void]$errorSummaryForSyncDB.AppendLine($msg) 1705 | } 1706 | Write-Host 1707 | 1708 | $SyncDbCommand.CommandText = "SELECT sg.id, sg.[name] AS SyncGroup, ud.[database] AS [HubDatabase], ud.[server] AS [HubServer], sg.hub_memberid as DatabaseId 1709 | FROM [dss].[syncgroup] as sg 1710 | INNER JOIN [dss].[userdatabase] as ud on sg.hub_memberid = ud.id 1711 | ORDER BY sg.[name]" 1712 | $SyncDbMembersResult = $SyncDbCommand.ExecuteReader() 1713 | $SyncDbMembersDataTableGroups = new-object 'System.Data.DataTable' 1714 | $SyncDbMembersDataTableGroups.Load($SyncDbMembersResult) 1715 | Write-Host $SyncDbMembersDataTableGroups.rows.Count Sync Groups 1716 | $SyncDbMembersDataTableGroups.Rows | Format-Table -Wrap -AutoSize | Out-String -Width 4096 1717 | Write-Host 1718 | 1719 | $SyncDbCommand.CommandText = "SELECT sg.[name] AS SyncGroup, sgm.[name] AS Member, ud.[database] AS [MemberDatabase], ud.[server] AS [MemberServer], ud.id as DatabaseId 1720 | FROM [dss].[syncgroupmember] sgm 1721 | INNER JOIN [dss].[syncgroup] sg ON sg.id = sgm.syncgroupid 1722 | INNER JOIN [dss].[userdatabase] as ud on sgm.databaseid = ud.id 1723 | ORDER BY sg.[name]" 1724 | $SyncDbMembersResult = $SyncDbCommand.ExecuteReader() 1725 | $SyncDbMembersDataTableMembers = new-object 'System.Data.DataTable' 1726 | $SyncDbMembersDataTableMembers.Load($SyncDbMembersResult) 1727 | Write-Host $SyncDbMembersDataTableMembers.rows.Count Sync Group Members 1728 | $SyncDbMembersDataTableMembers.Rows | Format-Table -Wrap -AutoSize | Out-String -Width 4096 1729 | Write-Host 1730 | 1731 | $SyncDbCommand.CommandText = "SELECT [id],[server],[database],[state],[last_schema_updated],[last_tombstonecleanup] FROM [dss].[userdatabase]" 1732 | $SyncDbMembersResult = $SyncDbCommand.ExecuteReader() 1733 | $SyncDbMembersDataTableMembers = new-object 'System.Data.DataTable' 1734 | $SyncDbMembersDataTableMembers.Load($SyncDbMembersResult) 1735 | Write-Host $SyncDbMembersDataTableMembers.rows.Count Databases 1736 | $SyncDbMembersDataTableMembers.Rows | Format-Table -Wrap -AutoSize | Out-String -Width 4096 1737 | Write-Host 1738 | 1739 | $SyncDbCommand.CommandText = "SELECT [id], [name], [lastalivetime], [version] FROM [dss].[agent]" 1740 | $SyncDbMembersResult = $SyncDbCommand.ExecuteReader() 1741 | $SyncDbMembersDataTableAgents = new-object 'System.Data.DataTable' 1742 | $SyncDbMembersDataTableAgents.Load($SyncDbMembersResult) 1743 | Write-Host $SyncDbMembersDataTableAgents.rows.Count Sync Agents 1744 | $SyncDbMembersDataTableAgents.Rows | Format-Table -Wrap -AutoSize | Out-String -Width 4096 1745 | Write-Host 1746 | 1747 | $SyncDbCommand.CommandText = "SELECT pr.name, pr.type_desc, pe.state_desc, pe.permission_name, class_desc 1748 | ,s.name as SchemaName, c.name as CertificateName, k.name as SymmetricKeyName 1749 | FROM sys.database_principals AS pr 1750 | JOIN sys.database_permissions AS pe ON pe.grantee_principal_id = pr.principal_id 1751 | LEFT OUTER JOIN sys.schemas AS s ON (pe.class = 3 and pe.major_id = s.schema_id) 1752 | LEFT OUTER JOIN sys.certificates AS c ON (pe.class = 25 and pe.major_id = c.certificate_id) 1753 | LEFT OUTER JOIN sys.symmetric_keys AS k ON (pe.class = 24 and pe.major_id = k.symmetric_key_id) 1754 | WHERE pr.[name] = '##MS_SyncAccount##' OR pr.[name] = 'DataSync_admin' 1755 | OR pr.[name] = 'DataSync_executor' OR pr.[name] = 'DataSync_reader' 1756 | ORDER by pe.class, pr.name" 1757 | $SyncDbMembersResult = $SyncDbCommand.ExecuteReader() 1758 | $SyncDbMembersDataTablePermissions = new-object 'System.Data.DataTable' 1759 | $SyncDbMembersDataTablePermissions.Load($SyncDbMembersResult) 1760 | Write-Host $SyncDbMembersDataTablePermissions.rows.Count Permissions 1761 | $SyncDbMembersDataTablePermissions.Rows | Format-Table -Wrap -AutoSize | Out-String -Width 4096 1762 | Write-Host 1763 | 1764 | CheckSchemaPermission $SyncDbMembersDataTablePermissions "DataSync_admin" "CONTROL" "dss" 1765 | CheckSchemaPermission $SyncDbMembersDataTablePermissions "DataSync_admin" "CONTROL" "TaskHosting" 1766 | 1767 | CheckSchemaPermission $SyncDbMembersDataTablePermissions "DataSync_executor" "EXECUTE" "dss" 1768 | CheckSchemaPermission $SyncDbMembersDataTablePermissions "DataSync_executor" "EXECUTE" "TaskHosting" 1769 | CheckSchemaPermission $SyncDbMembersDataTablePermissions "DataSync_executor" "SELECT" "dss" 1770 | CheckSchemaPermission $SyncDbMembersDataTablePermissions "DataSync_executor" "SELECT" "TaskHosting" 1771 | 1772 | CheckSchemaPermission $SyncDbMembersDataTablePermissions "DataSync_reader" "SELECT" "dss" 1773 | CheckSchemaPermission $SyncDbMembersDataTablePermissions "DataSync_reader" "SELECT" "TaskHosting" 1774 | 1775 | CheckDatabasePermission $SyncDbMembersDataTablePermissions "DataSync_admin" "CREATE FUNCTION" 1776 | CheckDatabasePermission $SyncDbMembersDataTablePermissions "DataSync_admin" "CREATE PROCEDURE" 1777 | CheckDatabasePermission $SyncDbMembersDataTablePermissions "DataSync_admin" "CREATE TABLE" 1778 | CheckDatabasePermission $SyncDbMembersDataTablePermissions "DataSync_admin" "CREATE TYPE" 1779 | CheckDatabasePermission $SyncDbMembersDataTablePermissions "DataSync_admin" "CREATE VIEW" 1780 | CheckDatabasePermission $SyncDbMembersDataTablePermissions "DataSync_admin" "VIEW DATABASE STATE" 1781 | 1782 | CheckDatabasePermission $SyncDbMembersDataTablePermissions "##MS_SyncAccount##" "CONNECT" 1783 | 1784 | Write-Host 1785 | GetUIHistoryForSyncDBValidator 1786 | } 1787 | Catch { 1788 | Write-Host ValidateSyncDB exception: 1789 | Write-Host $_.Exception.Message -ForegroundColor Red 1790 | } 1791 | Finally { 1792 | if ($SyncDbConnection) { 1793 | Write-Host Closing connection to SyncDb... 1794 | $SyncDbConnection.Close() 1795 | } 1796 | } 1797 | } 1798 | 1799 | function CheckSchemaPermission($permissionsTable, [String] $permissionUserName, [String] $permissionName, [String] $schemaName) { 1800 | if (($permissionsTable.Rows | Where-Object { $_.name -eq $permissionUserName -and $_.permission_name -eq $permissionName -and $_.class_desc -eq "SCHEMA" -and $_.SchemaName -eq $schemaName } | Measure-Object).Count -eq 0) { 1801 | $msg = "WARNING: $permissionUserName $permissionName on SCHEMA $schemaName IS MISSING!" 1802 | Write-Host $msg -Foreground Red 1803 | [void]$errorSummaryForSyncDB.AppendLine($msg) 1804 | } 1805 | else { 1806 | Write-Host $permissionUserName $permissionName on SCHEMA $schemaName "exists" -ForegroundColor Green 1807 | } 1808 | } 1809 | 1810 | function CheckDatabasePermission($permissionsTable, [String] $permissionUserName, [String] $permissionName, [String] $schemaName) { 1811 | if (($permissionsTable.Rows | Where-Object { $_.name -eq $permissionUserName -and $_.permission_name -eq $permissionName -and $_.class_desc -eq "DATABASE" } | Measure-Object).Count -eq 0) { 1812 | $msg = "WARNING: $permissionUserName $permissionName on DATABASE IS MISSING!" 1813 | Write-Host $msg -Foreground Red 1814 | [void]$errorSummaryForSyncDB.AppendLine($msg) 1815 | } 1816 | else { 1817 | Write-Host $permissionUserName $permissionName on DATABASE "exists" -ForegroundColor Green 1818 | } 1819 | } 1820 | 1821 | function DumpMetadataSchemasForSyncGroup([String] $syncGoupName) { 1822 | Try { 1823 | Write-Host Running DumpMetadataSchemasForSyncGroup 1824 | $SyncDbConnection = New-Object System.Data.SqlClient.SQLConnection 1825 | $SyncDbConnection.ConnectionString = [string]::Format("Server=tcp:{0},1433;Initial Catalog={1};Persist Security Info=False;User ID={2};Password={3};MultipleActiveResultSets=False;Encrypt=True;TrustServerCertificate=False;Connection Timeout=30;", $SyncDbServer, $SyncDbDatabase, $SyncDbUser, $SyncDbPassword) 1826 | Write-Host Connecting to SyncDB $SyncDbServer"/"$SyncDbDatabase 1827 | Try { 1828 | $SyncDbConnection.Open() 1829 | } 1830 | Catch { 1831 | Write-Host Error connecting to the database -ForegroundColor Red 1832 | Write-Host $_.Exception.Message -ForegroundColor Red 1833 | Test-NetConnection $SyncDbServer -Port 1433 1834 | Break 1835 | } 1836 | 1837 | $SyncDbCommand = New-Object System.Data.SQLClient.SQLCommand 1838 | $SyncDbCommand.Connection = $SyncDbConnection 1839 | $SyncDbCommand.CommandTimeout = $cmdTimeout 1840 | 1841 | $query = "SELECT [schema_description] FROM [dss].[syncgroup] WHERE [schema_description] IS NOT NULL AND [name] = '" + $syncGoupName + "'" 1842 | $SyncDbCommand.CommandText = $query 1843 | $result = $SyncDbCommand.ExecuteReader() 1844 | $datatable = new-object 'System.Data.DataTable' 1845 | $datatable.Load($result) 1846 | if ($datatable.Rows.Count -gt 0) { 1847 | $xmlResult = $datatable.Rows[0].schema_description 1848 | if ($xmlResult -and $canWriteFiles) { 1849 | $xmlResult | Out-File -filepath ('.\' + (SanitizeString $syncGoupName) + '_schema_description.xml') 1850 | } 1851 | } 1852 | 1853 | $query = "SELECT [ocsschemadefinition] FROM [dss].[syncgroup] WHERE [ocsschemadefinition] IS NOT NULL AND [name] = '" + $syncGoupName + "'" 1854 | $SyncDbCommand.CommandText = $query 1855 | $result = $SyncDbCommand.ExecuteReader() 1856 | $datatable = new-object 'System.Data.DataTable' 1857 | $datatable.Load($result) 1858 | if ($datatable.Rows.Count -gt 0) { 1859 | $xmlResult = $datatable.Rows[0].ocsschemadefinition 1860 | if ($xmlResult -and $canWriteFiles) { 1861 | $xmlResult | Out-File -filepath ('.\' + (SanitizeString $syncGoupName) + '_ocsschemadefinition.xml') 1862 | } 1863 | } 1864 | 1865 | $query = "SELECT ud.server as HubServer, ud.[database] as HubDatabase, [db_schema] 1866 | FROM [dss].[syncgroup] as sg 1867 | INNER JOIN [dss].[userdatabase] as ud on sg.hub_memberid = ud.id 1868 | LEFT JOIN [dss].[syncgroupmember] as m on sg.id = m.syncgroupid 1869 | WHERE [db_schema] IS NOT NULL AND sg.name = '" + $syncGoupName + "'" 1870 | $SyncDbCommand.CommandText = $query 1871 | $result = $SyncDbCommand.ExecuteReader() 1872 | $datatable = new-object 'System.Data.DataTable' 1873 | $datatable.Load($result) 1874 | if ($datatable.Rows.Count -gt 0) { 1875 | $xmlResult = $datatable.Rows[0].db_schema 1876 | if ($xmlResult -and $canWriteFiles) { 1877 | $xmlResult | Out-File -filepath ('.\' + (SanitizeString $datatable.Rows[0].HubServer) + '_' + (SanitizeString $datatable.Rows[0].HubDatabase) + '_db_schema.xml') 1878 | } 1879 | } 1880 | 1881 | $query = "SELECT ud2.[server] as MemberServer ,ud2.[database] as MemberDatabase, [db_schema] 1882 | FROM [dss].[syncgroup] as sg 1883 | LEFT JOIN [dss].[syncgroupmember] as m on sg.id = m.syncgroupid 1884 | LEFT JOIN [dss].[userdatabase] as ud2 on m.databaseid = ud2.id 1885 | WHERE [db_schema] IS NOT NULL AND sg.name = '" + $syncGoupName + "'" 1886 | $SyncDbCommand.CommandText = $query 1887 | $result = $SyncDbCommand.ExecuteReader() 1888 | $datatable = new-object 'System.Data.DataTable' 1889 | $datatable.Load($result) 1890 | if ($datatable.Rows.Count -gt 0) { 1891 | foreach ($databse in $datatable.Rows) { 1892 | $xmlResult = $databse.db_schema 1893 | if ($xmlResult -and $canWriteFiles) { 1894 | $xmlResult | Out-File -filepath ('.\' + (SanitizeString $databse.MemberServer) + '_' + (SanitizeString $databse.MemberDatabase) + '_db_schema.xml') 1895 | } 1896 | } 1897 | } 1898 | } 1899 | Catch { 1900 | Write-Host DumpMetadataSchemasForSyncGroup exception: 1901 | Write-Host $_.Exception.Message -ForegroundColor Red 1902 | } 1903 | Finally { 1904 | if ($SyncDbConnection) { 1905 | Write-Host Closing connection to SyncDb... 1906 | $SyncDbConnection.Close() 1907 | } 1908 | } 1909 | } 1910 | 1911 | function GetIndexes($table) { 1912 | Try { 1913 | $query = "sp_helpindex '" + $table + "'" 1914 | $MemberCommand.CommandText = $query 1915 | $result = $MemberCommand.ExecuteReader() 1916 | $datatable = new-object 'System.Data.DataTable' 1917 | $datatable.Load($result) 1918 | if ($datatable.Rows.Count -gt 0) { 1919 | Write-Host 1920 | $msg = "Indexes for " + $table + ":" 1921 | Write-Host $msg -Foreground Green 1922 | $datatable | Format-Table -Wrap -AutoSize | Out-String -Width 4096 1923 | Write-Host 1924 | } 1925 | } 1926 | Catch { 1927 | Write-Host GetIndexes exception: 1928 | Write-Host $_.Exception.Message -ForegroundColor Red 1929 | } 1930 | } 1931 | 1932 | function GetConstraints($table) { 1933 | Try { 1934 | $query = "select case when [syskc].[type] = 'PK' then 'PK' when [syskc].[type] = 'UQ' then 'UNIQUE' 1935 | when [sysidx].[type] = 1 then 'UQ CI' when [sysidx].[type] = 2 then 'UQ INDEX' end as [type], 1936 | ISNULL([syskc].[name], [sysidx].[name]) as [name], SUBSTRING([columns], 1, LEN([columns])-1) as [definition] 1937 | from sys.objects [sysobj] 1938 | left outer join sys.indexes [sysidx] on [sysobj].[object_id] = [sysidx].[object_id] 1939 | left outer join sys.key_constraints [syskc] on [sysidx].[object_id] = [syskc].parent_object_id and [sysidx].index_id = [syskc].unique_index_id 1940 | cross apply 1941 | (select [syscol].[name] + ', ' from sys.index_columns [sysic] 1942 | inner join sys.columns [syscol] on [sysic].[object_id] = [syscol].[object_id] and [sysic].column_id = [syscol].column_id 1943 | where [sysic].[object_id] = [sysobj].[object_id] and [sysic].index_id = [sysidx].index_id FOR XML PATH ('') 1944 | ) COLS ([columns]) 1945 | where is_unique = 1 and [sysobj].is_ms_shipped <> 1 and ('['+ SCHEMA_NAME([sysobj].[schema_id]) + '].[' + [sysobj].[name] + ']') = '" + $table + "' 1946 | union all select 'FOREIGN KEY', [sysfk].[name], SCHEMA_NAME([systabpk].[schema_id]) + '.' + [systabpk].[name] 1947 | from sys.foreign_keys [sysfk] 1948 | inner join sys.tables [systabfk] on [systabfk].[object_id] = [sysfk].[parent_object_id] 1949 | inner join sys.tables [systabpk] on [systabpk].[object_id] = [sysfk].[referenced_object_id] 1950 | inner join sys.foreign_key_columns [sysfkcols] on [sysfkcols].[constraint_object_id] = [sysfk].[object_id] 1951 | where ('['+ SCHEMA_NAME([systabfk].[schema_id]) + '].[' + [systabfk].[name] + ']') = '" + $table + "' 1952 | union all select 'CHECK', [syscc].[name] + ']', [syscc].[definition] 1953 | from sys.check_constraints [syscc] 1954 | left outer join sys.objects [sysobj] on [syscc].parent_object_id = [sysobj].[object_id] 1955 | left outer join sys.all_columns [syscol] on [syscc].parent_column_id = [syscol].column_id and [syscc].parent_object_id = [syscol].[object_id] 1956 | where ('['+ SCHEMA_NAME([sysobj].[schema_id]) + '].[' + [sysobj].[name]+ ']') = '" + $table + "' 1957 | union all select 'DEFAULT', [sysdc].[name], [syscol].[name] + ' = ' + [sysdc].[definition] 1958 | from sys.default_constraints [sysdc] 1959 | left outer join sys.objects [sysobj] on [sysdc].[parent_object_id] = [sysobj].[object_id] 1960 | left outer join sys.all_columns [syscol] on [sysdc].[parent_column_id] = [syscol].[column_id] and [sysdc].[parent_object_id] = [syscol].[object_id] 1961 | where ('['+ SCHEMA_NAME([sysobj].[schema_id]) + '].[' + [sysobj].[name] + ']') = '" + $table + "'" 1962 | 1963 | $MemberCommand.CommandText = $query 1964 | $result = $MemberCommand.ExecuteReader() 1965 | $datatable = new-object 'System.Data.DataTable' 1966 | $datatable.Load($result) 1967 | if ($datatable.Rows.Count -gt 0) { 1968 | Write-Host 1969 | $msg = "Constraints for " + $table + ":" 1970 | Write-Host $msg -Foreground Green 1971 | $datatable | Format-Table -Wrap -AutoSize | Out-String -Width 4096 1972 | Write-Host 1973 | } 1974 | } 1975 | Catch { 1976 | Write-Host GetConstraints exception: 1977 | Write-Host $_.Exception.Message -ForegroundColor Red 1978 | } 1979 | } 1980 | 1981 | function GetCustomerTriggers($table) { 1982 | Try { 1983 | $query = "SELECT tr.name AS TriggerName, tr.is_disabled AS 'Disabled' 1984 | FROM sys.triggers tr 1985 | INNER JOIN sys.tables t ON tr.parent_id = t.object_id 1986 | INNER JOIN sys.schemas s ON t.schema_id = s.schema_id 1987 | where '['+ SCHEMA_NAME(t.schema_id) +'].['+ t.name+']' = '" + $table + "' 1988 | AND tr.[name] not like '%_dss_%'" 1989 | 1990 | $MemberCommand.CommandText = $query 1991 | $result = $MemberCommand.ExecuteReader() 1992 | $datatable = new-object 'System.Data.DataTable' 1993 | $datatable.Load($result) 1994 | if ($datatable.Rows.Count -gt 0) { 1995 | Write-Host 1996 | $msg = "Customer triggers for " + $table + ":" 1997 | Write-Host $msg -Foreground Green 1998 | $datatable | Format-Table -Wrap -AutoSize | Out-String -Width 4096 1999 | Write-Host 2000 | } 2001 | } 2002 | Catch { 2003 | Write-Host GetCustomerTriggers exception: 2004 | Write-Host $_.Exception.Message -ForegroundColor Red 2005 | } 2006 | } 2007 | 2008 | function SanitizeString([String] $param) { 2009 | return ($param.Replace('\', '_').Replace('/', '_').Replace("[", "").Replace("]", "").Replace('.', '_').Replace(':', '_').Replace(',', '_')) 2010 | } 2011 | 2012 | function ValidateDSSMember() { 2013 | Try { 2014 | if (-not($HealthChecksEnabled)) { return } 2015 | $runnableScript = New-Object -TypeName "System.Text.StringBuilder" 2016 | $errorSummary = New-Object -TypeName "System.Text.StringBuilder" 2017 | $allTrackingTableList = New-Object System.Collections.ArrayList 2018 | $allTriggersList = New-Object System.Collections.ArrayList 2019 | $allSPsList = New-Object System.Collections.ArrayList 2020 | $allBulkTypeList = New-Object System.Collections.ArrayList 2021 | 2022 | $SyncDbConnection = New-Object System.Data.SqlClient.SQLConnection 2023 | $SyncDbConnection.ConnectionString = [string]::Format("Server=tcp:{0},1433;Initial Catalog={1};Persist Security Info=False;User ID={2};Password={3};MultipleActiveResultSets=False;Encrypt=True;TrustServerCertificate=False;Connection Timeout=30;", $SyncDbServer, $SyncDbDatabase, $SyncDbUser, $SyncDbPassword) 2024 | 2025 | Write-Host Connecting to SyncDB $SyncDbServer"/"$SyncDbDatabase 2026 | Try { 2027 | $SyncDbConnection.Open() 2028 | } 2029 | Catch { 2030 | Write-Host Error connecting to the database -ForegroundColor Red 2031 | Write-Host $_.Exception.Message -ForegroundColor Red 2032 | Test-NetConnection $SyncDbServer -Port 1433 2033 | Break 2034 | } 2035 | 2036 | $SyncDbCommand = New-Object System.Data.SQLClient.SQLCommand 2037 | $SyncDbCommand.Connection = $SyncDbConnection 2038 | $SyncDbCommand.CommandTimeout = $cmdTimeout 2039 | 2040 | Write-Host Validating if $Server/$Database exist in SyncDB: 2041 | 2042 | $SyncDbCommand.CommandText = "SELECT count(*) as C FROM [dss].[userdatabase] WHERE server = '" + $Server + "' and [database] = '" + $Database + "'" 2043 | $SyncDbMembersResult = $SyncDbCommand.ExecuteReader() 2044 | $SyncDbMembersDataTable = new-object 'System.Data.DataTable' 2045 | $SyncDbMembersDataTable.Load($SyncDbMembersResult) 2046 | 2047 | if ($SyncDbMembersDataTable.Rows[0].C -eq 0) { 2048 | $msg = $Server + "/" + $Database + " was not found in [dss].[userdatabase], please make sure you specify the server name and database name exactly like configured during sync setup." 2049 | Write-Host ERROR: $msg -ForegroundColor Red 2050 | 2051 | $SyncDbCommand.CommandText = "SELECT [server],[database] FROM [dss].[userdatabase]" 2052 | $SyncDbMembersResult = $SyncDbCommand.ExecuteReader() 2053 | $SyncDbMembersDataTableMembers = new-object 'System.Data.DataTable' 2054 | $SyncDbMembersDataTableMembers.Load($SyncDbMembersResult) 2055 | Write-Host Server and Databases must be one of: -ForegroundColor Yellow 2056 | $SyncDbMembersDataTableMembers.Rows | Format-Table -Wrap -AutoSize | Out-String -Width 4096 2057 | Write-Host 2058 | 2059 | Write-Error -Message $msg -ErrorAction Stop 2060 | 2061 | } 2062 | else { 2063 | Write-Host $Server/$Database was found in SyncDB -ForegroundColor Green 2064 | } 2065 | 2066 | Write-Host Getting scopes in SyncDB for this member database: 2067 | 2068 | $SyncDbCommand.CommandText = "SELECT m.[scopename] 2069 | ,sg.name as SyncGroupName 2070 | ,CAST(sg.schema_description as nvarchar(max)) as SchemaDescription 2071 | ,m.[name] as MemberName 2072 | ,m.[jobid] as JobId 2073 | ,COUNT(mq.[MessageId]) as Messages 2074 | ,enum1.Name as State 2075 | ,enum2.Name as HubState 2076 | ,enum3.Name as SyncDirection 2077 | FROM [dss].[syncgroup] as sg 2078 | INNER JOIN [dss].[userdatabase] as ud on sg.hub_memberid = ud.id 2079 | LEFT JOIN [dss].[syncgroupmember] as m on sg.id = m.syncgroupid 2080 | LEFT JOIN [dss].[EnumType] as enum1 on (enum1.Type='SyncGroupMemberState' and enum1.EnumId = m.memberstate) 2081 | LEFT JOIN [dss].[EnumType] as enum2 on (enum2.Type='SyncGroupMemberState' and enum2.EnumId = m.hubstate) 2082 | LEFT JOIN [dss].[EnumType] as enum3 on (enum3.Type='DssSyncDirection' and enum3.EnumId = m.syncdirection) 2083 | LEFT JOIN [dss].[userdatabase] as ud2 on m.databaseid = ud2.id 2084 | left outer join [TaskHosting].[Job] job on m.JobId = job.JobId 2085 | left outer join [TaskHosting].[MessageQueue] mq on job.JobId = mq.JobId 2086 | WHERE (ud.server = '" + $Server + "' and ud.[database] = '" + $Database + "') 2087 | or (ud2.[server] = '" + $Server + "' and ud2.[database] = '" + $Database + "') 2088 | GROUP BY m.[scopename],sg.name,CAST(sg.schema_description as nvarchar(max)),m.[name],m.[memberstate],m.[hubstate],m.[jobid],enum1.Name,enum2.Name,enum3.Name" 2089 | $SyncDbMembersResult = $SyncDbCommand.ExecuteReader() 2090 | $SyncDbMembersDataTable = new-object 'System.Data.DataTable' 2091 | $SyncDbMembersDataTable.Load($SyncDbMembersResult) 2092 | 2093 | Write-Host $SyncDbMembersDataTable.Rows.Count members found in this sync metadata database -ForegroundColor Green 2094 | $SyncDbMembersDataTable.Rows | Sort-Object -Property scopename | Select-Object scopename, SyncGroupName, MemberName, SyncDirection, State, HubState, JobId, Messages | Format-Table -Wrap -AutoSize | Out-String -Width 4096 2095 | $scopesList = $SyncDbMembersDataTable.Rows | Select-Object -ExpandProperty scopename 2096 | 2097 | $shouldMonitor = $SyncDbMembersDataTable.Rows | Where-Object { ` 2098 | $_.State.Equals('Provisioning') ` 2099 | -or $_.State.Equals('SyncInProgress') ` 2100 | -or $_.State.Equals('DeProvisioning') ` 2101 | -or $_.State.Equals('DeProvisioned') ` 2102 | -or $_.State.Equals('Reprovisioning') ` 2103 | -or $_.State.Equals('SyncCancelling') ` 2104 | -or $_.HubState.Equals('Provisioning') ` 2105 | -or $_.HubState.Equals('DeProvisioning') ` 2106 | -or $_.HubState.Equals('DeProvisioned') ` 2107 | -or $_.HubState.Equals('Reprovisioning') 2108 | } 2109 | if ($shouldMonitor -and $MonitoringMode -eq 'AUTO') { 2110 | $MonitoringMode = 'ENABLED' 2111 | } 2112 | 2113 | if (($SyncDbMembersDataTable.Rows | Measure-Object Messages -Sum).Sum -gt 0) { 2114 | $allJobIds = "'$(($SyncDbMembersDataTable.Rows | Select-Object -ExpandProperty JobId | Where-Object { $_.ToString() -ne '' }) -join "','")'" 2115 | $SyncDbCommand.CommandText = "select job.[JobId] 2116 | ,job.[IsCancelled] 2117 | ,job.[JobType] 2118 | ,job.[TaskCount] 2119 | ,job.[CompletedTaskCount] 2120 | ,m.[MessageId] 2121 | ,m.[MessageType] 2122 | ,m.[ExecTimes] 2123 | ,m.[ResetTimes] 2124 | from [TaskHosting].[Job] job 2125 | left outer join [TaskHosting].[MessageQueue] m on job.JobId = m.JobId 2126 | where job.JobId IN (" + $allJobIds + ")" 2127 | $SyncJobsResult = $SyncDbCommand.ExecuteReader() 2128 | $SyncJobsDataTable = new-object 'System.Data.DataTable' 2129 | $SyncJobsDataTable.Load($SyncJobsResult) 2130 | $SyncJobsDataTable | Format-Table -Wrap -AutoSize | Out-String -Width 4096 2131 | } 2132 | 2133 | Write-Host 2134 | GetUIHistory 2135 | Write-Host 2136 | 2137 | $MemberConnection = New-Object System.Data.SqlClient.SQLConnection 2138 | if ($MbrUseWindowsAuthentication) { 2139 | $MemberConnection.ConnectionString = [string]::Format("Server={0};Initial Catalog={1};Persist Security Info=False;Integrated Security=true;MultipleActiveResultSets=False;Connection Timeout=30;", $Server, $Database) 2140 | } 2141 | else { 2142 | $MemberConnection.ConnectionString = [string]::Format("Server={0};Initial Catalog={1};Persist Security Info=False;User ID={2};Password={3};MultipleActiveResultSets=False;Connection Timeout=30;", $Server, $Database, $MbrUser, $MbrPassword) 2143 | } 2144 | 2145 | Write-Host 2146 | Write-Host Connecting to $Server"/"$Database 2147 | $MemberConnection.Open() 2148 | 2149 | 2150 | $MemberCommand = New-Object System.Data.SQLClient.SQLCommand 2151 | $MemberCommand.Connection = $MemberConnection 2152 | $MemberCommand.CommandTimeout = $cmdTimeout 2153 | 2154 | Try { 2155 | Write-Host 2156 | Write-Host Database version and configuration: 2157 | $MemberCommand.CommandText = "SELECT compatibility_level AS [CompatLevel], collation_name AS [Collation], snapshot_isolation_state_desc AS [Snapshot], @@VERSION AS [Version] FROM sys.databases WHERE name = DB_NAME();" 2158 | $MemberResult = $MemberCommand.ExecuteReader() 2159 | $MemberVersion = new-object 'System.Data.DataTable' 2160 | $MemberVersion.Load($MemberResult) 2161 | $MemberVersion.Rows | Format-Table -Wrap -AutoSize | Out-String -Width 4096 2162 | Write-Host 2163 | } 2164 | Catch { 2165 | Write-Host $_.Exception.Message -ForegroundColor Red 2166 | } 2167 | 2168 | ### Database Validations ### 2169 | ValidateCircularReferences 2170 | ValidateTableNames 2171 | ValidateObjectNames 2172 | DetectComputedColumns 2173 | DetectProvisioningIssues 2174 | 2175 | ValidateTablesVSSyncDbSchema $SyncDbMembersDataTable 2176 | Write-Host 2177 | Write-Host Getting scopes in this $Server"/"$Database database... 2178 | 2179 | Try { 2180 | $MemberCommand.CommandText = "SELECT [sync_scope_name], [scope_local_id], [scope_config_id],[config_data],[scope_status], CAST([schema_major_version] AS varchar) + '.' + CAST([schema_minor_version] AS varchar) as [Version] FROM [DataSync].[scope_config_dss] AS sc LEFT OUTER JOIN [DataSync].[scope_info_dss] AS si ON si.scope_config_id = sc.config_id LEFT JOIN [DataSync].[schema_info_dss] ON 1=1" 2181 | $MemberResult = $MemberCommand.ExecuteReader() 2182 | $MemberScopes = new-object 'System.Data.DataTable' 2183 | $MemberScopes.Load($MemberResult) 2184 | 2185 | Write-Host $MemberScopes.Rows.Count scopes found in Hub/Member 2186 | $MemberScopes.Rows | Select-Object sync_scope_name, scope_config_id, scope_status, scope_local_id, Version | Sort-Object -Property sync_scope_name | Format-Table -Wrap -AutoSize | Out-String -Width 4096 2187 | Write-Host 2188 | 2189 | $global:Connection = $MemberConnection 2190 | 2191 | foreach ($scope in $MemberScopes) { 2192 | Write-Host 2193 | $SyncGroupName = $SyncDbMembersDataTable.Rows | Where-Object { $_.scopename -eq $scope.sync_scope_name } | Select-Object -ExpandProperty SyncGroupName 2194 | Write-Host "Validating sync group" $SyncGroupName "(ScopeName:"$scope.sync_scope_name")" 2195 | if ($scope.sync_scope_name -notin $scopesList) { 2196 | Write-Host "WARNING:" [DataSync].[scope_config_dss].[config_id] $scope.scope_config_id "should be a leftover." -Foreground Yellow 2197 | Write-Host "WARNING:" [DataSync].[scope_info_dss].[scope_local_id] $scope.scope_local_id "should be a leftover." -Foreground Yellow 2198 | 2199 | $deleteStatement = "DELETE FROM [DataSync].[scope_config_dss] WHERE [config_id] = '" + $scope.scope_config_id + "'" 2200 | [void]$runnableScript.AppendLine($deleteStatement) 2201 | [void]$runnableScript.AppendLine("GO") 2202 | 2203 | $deleteStatement = "DELETE FROM [DataSync].[scope_info_dss] WHERE [scope_local_id] = '" + $scope.scope_local_id + "'" 2204 | [void]$runnableScript.AppendLine($deleteStatement) 2205 | [void]$runnableScript.AppendLine("GO") 2206 | 2207 | $query = "SELECT [object_id], object_name([object_id]) as TableName FROM [DataSync].[provision_marker_dss] WHERE [owner_scope_local_id] = " + $scope.scope_local_id 2208 | $MemberCommand.CommandText = $query 2209 | $provision_marker_result = $MemberCommand.ExecuteReader() 2210 | $provision_marker_leftovers = new-object 'System.Data.DataTable' 2211 | $provision_marker_leftovers.Load($provision_marker_result) 2212 | 2213 | foreach ($provision_marker_leftover in $provision_marker_leftovers) { 2214 | $deleteStatement = "DELETE FROM [DataSync].[provision_marker_dss] WHERE [owner_scope_local_id] = " + $scope.scope_local_id + " and [object_id] = " + $provision_marker_leftover.object_id + " --" + $provision_marker_leftover.TableName 2215 | Write-Host "WARNING: [DataSync].[provision_marker_dss] WHERE [owner_scope_local_id] = " $scope.scope_local_id " and [object_id] = " $provision_marker_leftover.object_id " (" $provision_marker_leftover.TableName ") should be a leftover." -Foreground Yellow 2216 | [void]$runnableScript.AppendLine($deleteStatement) 2217 | [void]$runnableScript.AppendLine("GO") 2218 | } 2219 | } 2220 | else { 2221 | $xmlcontent = [xml]$scope.config_data 2222 | $global:scope_config_data = $xmlcontent 2223 | 2224 | Try { 2225 | $sgSchema = $SyncDbMembersDataTable | Where-Object { $_.scopename -eq $scope.sync_scope_name } | Select-Object SchemaDescription 2226 | $global:sgSchemaXml = ([xml]$sgSchema.SchemaDescription).DssSyncScopeDescription.TableDescriptionCollection.DssTableDescription 2227 | } 2228 | Catch { 2229 | $global:sgSchemaXml = $null 2230 | $ErrorMessage = $_.Exception.Message 2231 | Write-Host "Was not able to get SchemaDescription:" + $ErrorMessage 2232 | } 2233 | 2234 | ### Validations ### 2235 | 2236 | #Tables 2237 | ValidateTablesVSLocalSchema ($xmlcontent.SqlSyncProviderScopeConfiguration.Adapter | Select-Object -ExpandProperty GlobalName) 2238 | ShowRowCountAndFragmentation ($xmlcontent.SqlSyncProviderScopeConfiguration.Adapter | Select-Object -ExpandProperty GlobalName) 2239 | 2240 | foreach ($table in $xmlcontent.SqlSyncProviderScopeConfiguration.Adapter) { 2241 | #Tracking Tables 2242 | ValidateTrackingTable($table.TrackingTable) 2243 | 2244 | ##Triggers 2245 | ValidateTrigger($table.InsTrig) 2246 | ValidateTrigger($table.UpdTrig) 2247 | ValidateTrigger($table.DelTrig) 2248 | [void]$errorSummary.AppendLine() 2249 | 2250 | ## Procedures 2251 | if ($table.SelChngProc) { ValidateSP($table.SelChngProc) } 2252 | if ($table.SelRowProc) { ValidateSP($table.SelRowProc) } 2253 | if ($table.InsProc) { ValidateSP($table.InsProc) } 2254 | if ($table.UpdProc) { ValidateSP($table.UpdProc) } 2255 | if ($table.DelProc) { ValidateSP($table.DelProc) } 2256 | if ($table.InsMetaProc) { ValidateSP($table.InsMetaProc) } 2257 | if ($table.UpdMetaProc) { ValidateSP($table.UpdMetaProc) } 2258 | if ($table.DelMetaProc) { ValidateSP($table.DelMetaProc) } 2259 | if ($table.BulkInsProc) { ValidateSP($table.BulkInsProc) } 2260 | if ($table.BulkUpdProc) { ValidateSP($table.BulkUpdProc) } 2261 | if ($table.BulkDelProc) { ValidateSP($table.BulkDelProc) } 2262 | [void]$errorSummary.AppendLine() 2263 | 2264 | ## BulkType 2265 | if ($table.BulkTableType) { ValidateBulkType $table.BulkTableType $table.Col } 2266 | [void]$errorSummary.AppendLine() 2267 | 2268 | ## Indexes 2269 | GetIndexes $table.Name 2270 | GetConstraints $table.Name 2271 | GetCustomerTriggers $table.Name 2272 | } 2273 | 2274 | #Constraints 2275 | ValidateFKDependencies ($xmlcontent.SqlSyncProviderScopeConfiguration.Adapter | Select-Object -ExpandProperty GlobalName) 2276 | } 2277 | } 2278 | } 2279 | Catch { 2280 | Write-Host $_.Exception.Message -ForegroundColor Red 2281 | } 2282 | 2283 | ### Detect Leftovers ### 2284 | DetectTrackingTableLeftovers 2285 | DetectTriggerLeftovers 2286 | DetectProcedureLeftovers 2287 | DetectBulkTypeLeftovers 2288 | 2289 | ### Validations ### 2290 | ValidateProvisionMarker 2291 | 2292 | if ($runnableScript.Length -gt 0) { 2293 | $dumpScript = New-Object -TypeName 'System.Text.StringBuilder' 2294 | [void]$dumpScript.AppendLine(" --*****************************************************************************************************************") 2295 | [void]$dumpScript.AppendLine(" --LEFTOVERS CLEANUP SCRIPT : START") 2296 | [void]$dumpScript.AppendLine(" --ONLY applicable when this database is not being used by any other sync group in other regions and/or subscription") 2297 | [void]$dumpScript.AppendLine(" --AND Data Sync Health Checker was able to access the right Sync Metadata Database") 2298 | [void]$dumpScript.AppendLine(" --*****************************************************************************************************************") 2299 | [void]$dumpScript.AppendLine($runnableScript.ToString()) 2300 | [void]$dumpScript.AppendLine(" --*****************************************************************************************************************") 2301 | [void]$dumpScript.AppendLine(" --LEFTOVERS CLEANUP SCRIPT : END") 2302 | [void]$dumpScript.AppendLine(" --*****************************************************************************************************************") 2303 | if ($canWriteFiles) { 2304 | ($dumpScript.ToString()) | Out-File -filepath ('.\' + (SanitizeString $Server) + '_' + (SanitizeString $Database) + '_leftovers.sql') 2305 | } 2306 | } 2307 | else { 2308 | Write-Host 2309 | Write-Host NO LEFTOVERS DETECTED! 2310 | } 2311 | 2312 | if ($errorSummary.Length -gt 0) { 2313 | Write-Host 2314 | Write-Host "*******************************************" -Foreground Red 2315 | Write-Host " WARNINGS SUMMARY" -Foreground Red 2316 | Write-Host "*******************************************" -Foreground Red 2317 | Write-Host (RemoveDoubleEmptyLines $errorSummary.ToString()) -Foreground Red 2318 | Write-Host 2319 | } 2320 | else { 2321 | Write-Host 2322 | Write-Host NO ERRORS DETECTED! 2323 | } 2324 | } 2325 | Finally { 2326 | if (($Server -eq $MemberServer) -and ($Database -eq $MemberDatabase)) { 2327 | $script:errorSummaryForMember = $errorSummary 2328 | } 2329 | if (($Server -eq $HubServer) -and ($Database -eq $HubDatabase)) { 2330 | $script:errorSummaryForHub = $errorSummary 2331 | } 2332 | if ($SyncDbConnection) { 2333 | Write-Host Closing connection to SyncDb... 2334 | $SyncDbConnection.Close() 2335 | } 2336 | if ($MemberConnection) { 2337 | Write-Host Closing connection to Member... 2338 | $MemberConnection.Close() 2339 | } 2340 | } 2341 | } 2342 | 2343 | function Monitor() { 2344 | 2345 | Write-Host ****************************** -ForegroundColor Green 2346 | Write-Host MONITORING 2347 | Write-Host ****************************** -ForegroundColor Green 2348 | 2349 | $monitorUntil = (Get-Date).AddMinutes($MonitoringDurationInMinutes) 2350 | 2351 | $HubConnection = New-Object System.Data.SqlClient.SQLConnection 2352 | $HubConnection.ConnectionString = [string]::Format("Server=tcp:{0},1433;Initial Catalog={1};Persist Security Info=False;User ID={2};Password={3};MultipleActiveResultSets=False;Encrypt=True;TrustServerCertificate=False;Connection Timeout=30;", $HubServer, $HubDatabase, $HubUser, $HubPassword) 2353 | $HubCommand = New-Object System.Data.SQLClient.SQLCommand 2354 | $HubCommand.Connection = $HubConnection 2355 | $HubCommand.CommandTimeout = $cmdTimeout 2356 | 2357 | Write-Host Connecting to Hub $HubServer"/"$HubDatabase 2358 | Try { 2359 | $HubConnection.Open() 2360 | } 2361 | Catch { 2362 | Write-Host Error connecting to the database -ForegroundColor Red 2363 | Write-Host $_.Exception.Message -ForegroundColor Red 2364 | Test-NetConnection $HubServer -Port 1433 2365 | Break 2366 | } 2367 | 2368 | $MemberConnection = New-Object System.Data.SqlClient.SQLConnection 2369 | if ($MemberUseWindowsAuthentication) { 2370 | $MemberConnection.ConnectionString = [string]::Format("Server={0};Initial Catalog={1};Persist Security Info=False;Integrated Security=true;MultipleActiveResultSets=False;Connection Timeout=30;", $MemberServer, $MemberDatabase) 2371 | } 2372 | else { 2373 | $MemberConnection.ConnectionString = [string]::Format("Server={0};Initial Catalog={1};Persist Security Info=False;User ID={2};Password={3};MultipleActiveResultSets=False;Connection Timeout=30;", $MemberServer, $MemberDatabase, $MemberUser, $MemberPassword) 2374 | } 2375 | 2376 | $MemberCommand = New-Object System.Data.SQLClient.SQLCommand 2377 | $MemberCommand.Connection = $MemberConnection 2378 | $MemberCommand.CommandTimeout = $cmdTimeout 2379 | 2380 | Write-Host Connecting to Member $MemberServer"/"$MemberDatabase 2381 | Try { 2382 | $MemberConnection.Open() 2383 | } 2384 | Catch { 2385 | Write-Host Error connecting to the database -ForegroundColor Red 2386 | Write-Host $_.Exception.Message -ForegroundColor Red 2387 | Test-NetConnection $MemberServer -Port 1433 2388 | Break 2389 | } 2390 | 2391 | $HubCommand.CommandText = "SELECT GETUTCDATE() as now" 2392 | $result = $HubCommand.ExecuteReader() 2393 | $datatable = new-object 'System.Data.DataTable' 2394 | $datatable.Load($result) 2395 | $lasttime = $datatable.Rows[0].now 2396 | 2397 | while ((Get-Date) -le $monitorUntil) { 2398 | $lastTimeString = ([DateTime]$lasttime).toString("yyyy-MM-dd HH:mm:ss") 2399 | $lastTimeString = $lastTimeString.Replace('.', ':') 2400 | 2401 | Write-Host "Monitoring ("$lastTimeString")..." -ForegroundColor Green 2402 | 2403 | Try { 2404 | $os = Get-Ciminstance Win32_OperatingSystem 2405 | $FreePhysicalMemory = [math]::Round(($os.FreePhysicalMemory / 1024), 2) 2406 | $FreeVirtualMemory = [math]::Round(($os.FreeVirtualMemory / 1024), 2) 2407 | Write-Host "FreePhysicalMemory:" $FreePhysicalMemory "|" "FreeVirtualMemory:" $FreeVirtualMemory -ForegroundColor Yellow 2408 | 2409 | Get-WMIObject Win32_Process -Filter "Name='DataSyncLocalAgentHost.exe' or Name='sqlservr.exe'" | Select Name, @{n = "Private Memory(mb)"; e = { [math]::Round($_.PrivatePageCount / 1mb, 2) } } | Format-Table -AutoSize 2410 | } 2411 | Catch { 2412 | Write-Host $_.Exception.Message -ForegroundColor Red 2413 | } 2414 | 2415 | Try { 2416 | $tempfolderfiles = [System.IO.Directory]::EnumerateFiles([Environment]::GetEnvironmentVariable("TEMP", "User"), "*.*", "AllDirectories") 2417 | $batchFiles = ($tempfolderfiles | Where-Object { $_ -match "DSS2_" -and $_ -match "sync_" -and $_ -match ".batch" }).Count 2418 | $MATSFiles = ($tempfolderfiles | Where-Object { $_ -match "DSS2_" -and $_ -match "MATS_" }).Count 2419 | Write-Host Temp folder at user level - batch:$batchFiles MATS:$MATSFiles -ForegroundColor Yellow 2420 | 2421 | $tempfolderfiles = [System.IO.Directory]::EnumerateFiles([Environment]::GetEnvironmentVariable("TEMP", "Machine"), "*.*", "AllDirectories") 2422 | $batchFiles = ($tempfolderfiles | Where-Object { $_ -match "DSS2_" -and $_ -match "sync_" -and $_ -match ".batch" }).Count 2423 | $MATSFiles = ($tempfolderfiles | Where-Object { $_ -match "DSS2_" -and $_ -match "MATS_" }).Count 2424 | Write-Host Temp folder at machine level - batch:$batchFiles MATS:$MATSFiles -ForegroundColor Yellow 2425 | } 2426 | Catch { 2427 | Write-Host $_.Exception.Message -ForegroundColor Red 2428 | } 2429 | 2430 | 2431 | $query = "select o.name AS What, p.last_execution_time AS LastExecutionTime, p.execution_count AS ExecutionCount 2432 | from sys.dm_exec_procedure_stats p 2433 | inner join sys.objects o on o.object_id = p.object_id 2434 | inner join sys.schemas s on s.schema_id=o.schema_id 2435 | where s.name = 'DataSync' and p.last_execution_time > '" + $lastTimeString + "' 2436 | order by p.last_execution_time desc" 2437 | 2438 | Try { 2439 | $HubCommand.CommandText = $query 2440 | $HubResult = $HubCommand.ExecuteReader() 2441 | $datatable = new-object 'System.Data.DataTable' 2442 | $datatable.Load($HubResult) 2443 | 2444 | if ($datatable.Rows.Count -gt 0) { 2445 | Write-Host "Hub Monitor (SPs) ("$lastTimeString"): new records:" -ForegroundColor Green 2446 | $datatable | Format-Table -Wrap -AutoSize | Out-String -Width 4096 2447 | } 2448 | else { 2449 | Write-Host "- No new records from Hub Monitor (SPs)" -ForegroundColor Green 2450 | } 2451 | } 2452 | Catch { 2453 | Write-Host $_.Exception.Message -ForegroundColor Red 2454 | } 2455 | 2456 | Try { 2457 | $MemberCommand.CommandText = $query 2458 | $MemberResult = $MemberCommand.ExecuteReader() 2459 | $datatable = new-object 'System.Data.DataTable' 2460 | $datatable.Load($MemberResult) 2461 | 2462 | if ($datatable.Rows.Count -gt 0) { 2463 | Write-Host "Member Monitor (SPs) ("$lastTimeString"): new records:" -ForegroundColor Green 2464 | $datatable | Format-Table -Wrap -AutoSize | Out-String -Width 4096 2465 | } 2466 | else { 2467 | Write-Host "- No new records from Member Monitor (SPs)" -ForegroundColor Green 2468 | } 2469 | } 2470 | Catch { 2471 | Write-Host $_.Exception.Message -ForegroundColor Red 2472 | } 2473 | 2474 | $query = "SELECT req.session_id as Session, req.status as Status, req.command as Command, 2475 | req.cpu_time as CPUTime, req.total_elapsed_time as TotalTime, sqltext.TEXT as What 2476 | --SUBSTRING(sqltext.TEXT, CHARINDEX('[DataSync]', sqltext.TEXT), 100) as What 2477 | FROM sys.dm_exec_requests req CROSS APPLY sys.dm_exec_sql_text(sql_handle) AS sqltext 2478 | WHERE sqltext.TEXT like '%[DataSync]%' AND sqltext.TEXT not like 'SELECT req.session_id%'" 2479 | 2480 | Try { 2481 | $HubCommand.CommandText = $query 2482 | $HubResult = $HubCommand.ExecuteReader() 2483 | $datatable = new-object 'System.Data.DataTable' 2484 | $datatable.Load($HubResult) 2485 | 2486 | if ($datatable.Rows.Count -gt 0) { 2487 | Write-Host "Hub Monitor (running commands) ("$lastTimeString"): new records:" -ForegroundColor Green 2488 | $datatable | Format-Table -Wrap -AutoSize | Out-String -Width 4096 2489 | } 2490 | else { 2491 | Write-Host "- No new records from Hub Monitor (running)" -ForegroundColor Green 2492 | } 2493 | } 2494 | Catch { 2495 | Write-Host $_.Exception.Message -ForegroundColor Red 2496 | } 2497 | 2498 | Try { 2499 | $MemberCommand.CommandText = $query 2500 | $MemberResult = $MemberCommand.ExecuteReader() 2501 | $datatable = new-object 'System.Data.DataTable' 2502 | $datatable.Load($MemberResult) 2503 | 2504 | if ($datatable.Rows.Count -gt 0) { 2505 | Write-Host "Member Monitor (running commands) ("$lastTimeString"): new records:" -ForegroundColor Green 2506 | $datatable | Format-Table -Wrap -AutoSize | Out-String -Width 4096 2507 | } 2508 | else { 2509 | Write-Host "- No new records from Member Monitor (running)" -ForegroundColor Green 2510 | } 2511 | } 2512 | Catch { 2513 | Write-Host $_.Exception.Message -ForegroundColor Red 2514 | } 2515 | 2516 | $lasttime = $lasttime.AddSeconds($MonitoringIntervalInSeconds) 2517 | Write-Host "Waiting..." $MonitoringIntervalInSeconds "seconds..." -ForegroundColor Green 2518 | Start-Sleep -s $MonitoringIntervalInSeconds 2519 | } 2520 | Write-Host 2521 | Write-Host "Monitoring finished" -ForegroundColor Green 2522 | } 2523 | 2524 | function FilterTranscript() { 2525 | Try { 2526 | if ($canWriteFiles) { 2527 | $lineNumber = (Select-String -Path $file -Pattern '..TranscriptStart..').LineNumber 2528 | if ($lineNumber) { 2529 | (Get-Content $file | Select-Object -Skip $lineNumber) | Set-Content $file 2530 | } 2531 | } 2532 | } 2533 | Catch { 2534 | Write-Host $_.Exception.Message -ForegroundColor Red 2535 | } 2536 | } 2537 | 2538 | function SanitizeServerName([string]$ServerName) { 2539 | $ServerName = $ServerName.Trim() 2540 | $ServerName = $ServerName.Replace('tcp:', '') 2541 | $ServerName = $ServerName.Replace(',1433', '') 2542 | return $ServerName 2543 | } 2544 | 2545 | function RemoveDoubleEmptyLines([string]$text) { 2546 | do { 2547 | $previous = $text 2548 | $text = $text.Replace("`r`n`r`n`r`n", "`r`n`r`n") 2549 | } while ($text -ne $previous) 2550 | return $text 2551 | } 2552 | 2553 | Try { 2554 | Clear-Host 2555 | $errorSummaryForSyncDB = New-Object -TypeName "System.Text.StringBuilder" 2556 | $errorSummaryForMember 2557 | $errorSummaryForHub 2558 | $canWriteFiles = $true 2559 | Try { 2560 | Set-Location $HOME\clouddrive -ErrorAction Stop 2561 | Write-Host "This seems to be running on Azure Cloud Shell" 2562 | $isThisFromAzurePortal = $true 2563 | } 2564 | Catch { 2565 | $isThisFromAzurePortal = $false 2566 | Write-Host "This doesn't seem to be running on Azure Cloud Shell" 2567 | Set-Location -Path $env:TEMP 2568 | } 2569 | Try { 2570 | If (!(Test-Path DataSyncHealthChecker)) { 2571 | New-Item DataSyncHealthChecker -ItemType directory | Out-Null 2572 | } 2573 | Set-Location DataSyncHealthChecker 2574 | $outFolderName = [System.DateTime]::Now.ToString('yyyyMMddTHHmmss') 2575 | New-Item $outFolderName -ItemType directory | Out-Null 2576 | Set-Location $outFolderName 2577 | $file = '.\_SyncDB_Log.txt' 2578 | Start-Transcript -Path $file 2579 | Write-Host '..TranscriptStart..' 2580 | } 2581 | Catch { 2582 | $canWriteFiles = $false 2583 | Write-Host Warning: Cannot write files -ForegroundColor Yellow 2584 | } 2585 | 2586 | Try { 2587 | Write-Host ************************************************************ -ForegroundColor Green 2588 | Write-Host " Azure SQL Data Sync Health Checker v6.24 Results" -ForegroundColor Green 2589 | Write-Host ************************************************************ -ForegroundColor Green 2590 | Write-Host 2591 | Write-Host "Configuration:" -ForegroundColor Green 2592 | Write-Host PowerShell $PSVersionTable.PSVersion 2593 | Write-Host 2594 | Write-Host "Databases:" -ForegroundColor Green 2595 | Write-Host SyncDbServer = $SyncDbServer 2596 | Write-Host SyncDbDatabase = $SyncDbDatabase 2597 | Write-Host HubServer = $HubServer 2598 | Write-Host HubDatabase = $HubDatabase 2599 | Write-Host MemberServer = $MemberServer 2600 | Write-Host MemberDatabase = $MemberDatabase 2601 | Write-Host 2602 | Write-Host "Parameters you can change:" -ForegroundColor Green 2603 | Write-Host HealthChecksEnabled = $HealthChecksEnabled 2604 | Write-Host MonitoringMode = $MonitoringMode 2605 | Write-Host MonitoringIntervalInSeconds = $MonitoringIntervalInSeconds 2606 | Write-Host MonitoringDurationInMinutes = $MonitoringDurationInMinutes 2607 | Write-Host SendAnonymousUsageData = $SendAnonymousUsageData 2608 | Write-Host ExtendedValidationsEnabledForHub = $ExtendedValidationsEnabledForHub 2609 | Write-Host ExtendedValidationsEnabledForMember = $ExtendedValidationsEnabledForMember 2610 | Write-Host ExtendedValidationsTableFilter = $ExtendedValidationsTableFilter 2611 | Write-Host ExtendedValidationsCommandTimeout = $ExtendedValidationsCommandTimeout 2612 | Write-Host DumpMetadataSchemasForSyncGroup = $DumpMetadataSchemasForSyncGroup 2613 | Write-Host DumpMetadataObjectsForTable = $DumpMetadataObjectsForTable 2614 | 2615 | if ($SendAnonymousUsageData) { 2616 | SendAnonymousUsageData 2617 | } 2618 | 2619 | #SyncDB 2620 | if (($null -eq $SyncDbServer) -or ('' -eq $SyncDbServer)) { 2621 | Write-Host 2622 | Write-Host 'WARNING:SyncDbServer was not specified, validations cannot continue without it.' -ForegroundColor Red 2623 | Write-Host 2624 | exit 2625 | } 2626 | 2627 | if (($null -eq $SyncDbDatabase) -or ('' -eq $SyncDbDatabase)) { 2628 | Write-Host 2629 | Write-Host 'WARNING:SyncDbDatabase was not specified, validations cannot continue without it.' -ForegroundColor Red 2630 | Write-Host 2631 | exit 2632 | } 2633 | 2634 | if (($null -eq $SyncDbUser) -or ('' -eq $SyncDbUser)) { 2635 | Write-Host 2636 | Write-Host 'WARNING:SyncDbUser was not specified, validations cannot continue without it.' -ForegroundColor Red 2637 | Write-Host 2638 | exit 2639 | } 2640 | 2641 | if (($null -eq $SyncDbPassword) -or ('' -eq $SyncDbPassword)) { 2642 | Write-Host 2643 | Write-Host 'WARNING:SyncDbPassword was not specified, validations cannot continue without it.' -ForegroundColor Red 2644 | Write-Host 2645 | exit 2646 | } 2647 | 2648 | Write-Host 2649 | Write-Host ***************** Validating Sync Metadata Database ********************** -ForegroundColor Green 2650 | Write-Host 2651 | $SyncDbServer = SanitizeServerName $SyncDbServer 2652 | ValidateSyncDB 2653 | if ($DumpMetadataSchemasForSyncGroup -ne '') { 2654 | DumpMetadataSchemasForSyncGroup $DumpMetadataSchemasForSyncGroup 2655 | } 2656 | } 2657 | Finally { 2658 | if ($canWriteFiles) { 2659 | Try { 2660 | Stop-Transcript | Out-Null 2661 | } 2662 | Catch [System.InvalidOperationException] { } 2663 | FilterTranscript 2664 | } 2665 | } 2666 | 2667 | #Hub 2668 | $Server = SanitizeServerName $HubServer 2669 | $Database = $HubDatabase 2670 | $MbrUseWindowsAuthentication = $false 2671 | $MbrUser = $HubUser 2672 | $MbrPassword = $HubPassword 2673 | $ExtendedValidationsEnabled = $ExtendedValidationsEnabledForHub 2674 | if ($HealthChecksEnabled -and ($null -ne $Server) -and ($Server -ne '') -and ($null -ne $Database) -and ($Database -ne '')) { 2675 | Try { 2676 | if ($canWriteFiles) { 2677 | $file = '.\_Hub_Log.txt' 2678 | Start-Transcript -Path $file 2679 | Write-Host '..TranscriptStart..' 2680 | } 2681 | Write-Host 2682 | Write-Host ***************** Validating Hub ********************** -ForegroundColor Green 2683 | Write-Host 2684 | ValidateDSSMember 2685 | } 2686 | Catch { 2687 | $msg = "An unexpected error happened during the validation." 2688 | Write-Host $msg -Foreground Red 2689 | [void]$errorSummaryForHub.AppendLine($msg) 2690 | $msg = "Error: " + $_.Exception.Message 2691 | Write-Host $msg -Foreground Yellow 2692 | [void]$errorSummaryForHub.AppendLine($msg) 2693 | } 2694 | Finally { 2695 | Try { 2696 | if ($canWriteFiles) { 2697 | Stop-Transcript | Out-Null 2698 | } 2699 | } 2700 | Catch [System.InvalidOperationException] { } 2701 | FilterTranscript 2702 | } 2703 | } 2704 | 2705 | #Member 2706 | $Server = $MemberServer 2707 | $Database = $MemberDatabase 2708 | $MbrUseWindowsAuthentication = $MemberUseWindowsAuthentication 2709 | $MbrUser = $MemberUser 2710 | $MbrPassword = $MemberPassword 2711 | $ExtendedValidationsEnabled = $ExtendedValidationsEnabledForMember 2712 | if ($HealthChecksEnabled -and ($null -ne $Server) -and ($Server -ne '') -and ($null -ne $Database) -and ($Database -ne '')) { 2713 | Try { 2714 | if ($canWriteFiles) { 2715 | $file = '.\_Member_Log.txt' 2716 | Start-Transcript -Path $file 2717 | Write-Host '..TranscriptStart..' 2718 | } 2719 | Write-Host 2720 | Write-Host ***************** Validating Member ********************** -ForegroundColor Green 2721 | Write-Host 2722 | ValidateDSSMember 2723 | } 2724 | Catch { 2725 | $msg = "An unexpected error happened during the validation." 2726 | Write-Host $msg -Foreground Red 2727 | [void]$errorSummaryForMember.AppendLine($msg) 2728 | $msg = "Error: " + $_.Exception.Message 2729 | Write-Host $msg -Foreground Yellow 2730 | [void]$errorSummaryForMember.AppendLine($msg) 2731 | } 2732 | Finally { 2733 | Try { 2734 | if ($canWriteFiles) { 2735 | Stop-Transcript | Out-Null 2736 | } 2737 | } 2738 | Catch [System.InvalidOperationException] { } 2739 | FilterTranscript 2740 | } 2741 | } 2742 | 2743 | #Monitor 2744 | if ($MonitoringMode -eq 'ENABLED') { 2745 | Try { 2746 | if ($canWriteFiles) { 2747 | $file = '.\_Monitoring_Log.txt' 2748 | Start-Transcript -Path $file 2749 | Write-Host '..TranscriptStart..' 2750 | } 2751 | Monitor 2752 | } 2753 | Catch { 2754 | Write-Host "An error occurred:" 2755 | Write-Host $_.Exception 2756 | Write-Host $_.ErrorDetails 2757 | Write-Host $_.ScriptStackTrace 2758 | } 2759 | Finally { 2760 | Try { 2761 | if ($canWriteFiles) { 2762 | Stop-Transcript | Out-Null 2763 | } 2764 | } 2765 | Catch [System.InvalidOperationException] { } 2766 | FilterTranscript 2767 | } 2768 | } 2769 | 2770 | Try { 2771 | if ($canWriteFiles) { 2772 | $file = '.\__SummaryReport.txt' 2773 | Start-Transcript -Path $file 2774 | Write-Host '..TranscriptStart..' 2775 | } 2776 | if ($script:errorSummaryForSyncDB -and $script:errorSummaryForSyncDB.Length -gt 0) { 2777 | Write-Host 2778 | Write-Host "*********************************" -Foreground Red 2779 | Write-Host " WARNINGS SUMMARY FOR SyncDB" -Foreground Red 2780 | Write-Host "*********************************" -Foreground Red 2781 | Write-Host (RemoveDoubleEmptyLines $script:errorSummaryForSyncDB.ToString()) -Foreground Red 2782 | Write-Host 2783 | } 2784 | else { 2785 | Write-Host 2786 | Write-Host "NO ERRORS DETECTED IN THE SyncDB!" 2787 | } 2788 | if ($script:errorSummaryForHub -and $script:errorSummaryForHub.Length -gt 0) { 2789 | Write-Host 2790 | Write-Host "******************************" -Foreground Red 2791 | Write-Host " WARNINGS SUMMARY FOR HUB" -Foreground Red 2792 | Write-Host "******************************" -Foreground Red 2793 | Write-Host (RemoveDoubleEmptyLines $script:errorSummaryForHub.ToString()) -Foreground Red 2794 | Write-Host 2795 | } 2796 | else { 2797 | Write-Host 2798 | Write-Host "NO ERRORS DETECTED IN THE HUB!" 2799 | } 2800 | if ($script:errorSummaryForMember -and $script:errorSummaryForMember.Length -gt 0) { 2801 | Write-Host 2802 | Write-Host "*********************************" -Foreground Red 2803 | Write-Host " WARNINGS SUMMARY FOR MEMBER" -Foreground Red 2804 | Write-Host "*********************************" -Foreground Red 2805 | Write-Host (RemoveDoubleEmptyLines $script:errorSummaryForMember.ToString()) -Foreground Red 2806 | Write-Host 2807 | } 2808 | else { 2809 | Write-Host 2810 | Write-Host "NO ERRORS DETECTED IN THE MEMBER!" 2811 | Write-Host 2812 | } 2813 | } 2814 | Finally { 2815 | Try { 2816 | if ($canWriteFiles) { 2817 | Stop-Transcript | Out-Null 2818 | } 2819 | } 2820 | Catch [System.InvalidOperationException] { } 2821 | FilterTranscript 2822 | } 2823 | } 2824 | Finally { 2825 | if ($canWriteFiles) { 2826 | Write-Host Files can be found at (Get-Location).Path 2827 | if ($PSVersionTable.PSVersion.Major -ge 5) { 2828 | $destAllFiles = (Get-Location).Path + '/AllFiles.zip' 2829 | Compress-Archive -Path (Get-Location).Path -DestinationPath $destAllFiles -Force 2830 | Write-Host 'A zip file with all the files can be found at' $destAllFiles -ForegroundColor Yellow 2831 | } 2832 | if (!$isThisFromAzurePortal) { 2833 | Invoke-Item (Get-Location).Path 2834 | } 2835 | } 2836 | } -------------------------------------------------------------------------------- /CONTRIBUTING.md: -------------------------------------------------------------------------------- 1 | # Contributing 2 | 3 | This project welcomes contributions and suggestions. Most contributions require you to 4 | agree to a Contributor License Agreement (CLA) declaring that you have the right to, 5 | and actually do, grant us the rights to use your contribution. For details, visit 6 | https://cla.microsoft.com. 7 | 8 | When you submit a pull request, a CLA-bot will automatically determine whether you need 9 | to provide a CLA and decorate the PR appropriately (e.g., label, comment). Simply follow the 10 | instructions provided by the bot. You will only need to do this once across all repositories using our CLA. 11 | 12 | This project has adopted the [Microsoft Open Source Code of Conduct](https://opensource.microsoft.com/codeofconduct/). 13 | For more information see the [Code of Conduct FAQ](https://opensource.microsoft.com/codeofconduct/faq/) 14 | or contact [opencode@microsoft.com](mailto:opencode@microsoft.com) with any additional questions or comments. -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) Microsoft Corporation. All rights reserved. 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE 22 | -------------------------------------------------------------------------------- /PRIVACY: -------------------------------------------------------------------------------- 1 | Data Collection. 2 | The software may collect information about you and your use of the software and send it to Microsoft. Microsoft may use this information to provide services and improve our products and services. You may turn off the telemetry as described in the repository. There are also some features in the software that may enable you and Microsoft to collect data from users of your applications. If you use these features, you must comply with applicable law, including providing appropriate notices to users of your applications together with a copy of Microsoft's privacy statement. Our privacy statement is located at https://go.microsoft.com/fwlink/?LinkID=824704. You can learn more about data collection and use in the help documentation and our privacy statement. Your use of the software operates as your consent to these practices. 3 | 4 | You can avoid sending anonymous usage data by setting: 5 | SendAnonymousUsageData = $false -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Azure SQL Data Sync Health Checker 2 | 3 | This PowerShell script will check if all the metadata of a hub and member is in place and also validate the scopes against the information we have on the sync metadata database (among other validations). 4 | This script will not make any changes, will just validate data sync and user objects. 5 | It will also gather some useful information for faster troubleshooting during a support request. 6 | 7 | **In order to run it you need to:** 8 | 1. Open Windows PowerShell ISE 9 |   10 | 2. Open a New Script window 11 |   12 | 3. Paste the following in the script window (please note that, except databases and credentials, the other parameters are optional): 13 | 14 | ```powershell 15 | $parameters = @{ 16 | ## Databases and credentials 17 | # Sync metadata database credentials (Only SQL Authentication is supported) 18 | SyncDbServer = '.database.windows.net' 19 | SyncDbDatabase = '' 20 | SyncDbUser = '' 21 | SyncDbPassword = '' 22 | 23 | # Hub credentials (Only SQL Authentication is supported) 24 | HubServer = '.database.windows.net' 25 | HubDatabase = '' 26 | HubUser = '' 27 | HubPassword = '' 28 | 29 | # Member credentials (Azure SQL DB or SQL Server) 30 | MemberServer = '' 31 | MemberDatabase = '' 32 | MemberUser = '' 33 | MemberPassword = '' 34 | # set MemberUseWindowsAuthentication to $true in case you wish to use integrated Windows authentication (MemberUser and MemberPassword will be ignored) 35 | MemberUseWindowsAuthentication = $false 36 | 37 | ## Optional parameters (default values will be used if ommited) 38 | 39 | ## Health checks 40 | HealthChecksEnabled = $true #Set as $true (default) or $false 41 | 42 | ## Monitoring 43 | MonitoringMode = 'AUTO' #Set as AUTO (default), ENABLED or DISABLED 44 | MonitoringIntervalInSeconds = 20 45 | MonitoringDurationInMinutes = 2 46 | 47 | ## Tracking Record Validations 48 | ExtendedValidationsTableFilter = @('All') #Set as "All" or the tables you need using '[dbo].[TableName1]','[dbo].[TableName2]' 49 | ExtendedValidationsEnabledForHub = $true #Set as $true (default) or $false 50 | ExtendedValidationsEnabledForMember = $true #Set as $true (default) or $false 51 | ExtendedValidationsCommandTimeout = 900 #seconds (default) 52 | 53 | ## Other 54 | SendAnonymousUsageData = $true #Set as $true (default) or $false 55 | DumpMetadataSchemasForSyncGroup = '' #leave empty for automatic detection 56 | DumpMetadataObjectsForTable = '' #needs to be formatted like [SchemaName].[TableName] 57 | } 58 |   59 | $scriptUrlBase = 'https://raw.githubusercontent.com/Microsoft/AzureSQLDataSyncHealthChecker/master' 60 | cls 61 | Write-Host 'Trying to download the script file from GitHub (https://github.com/Microsoft/AzureSQLDataSyncHealthChecker), please wait...' 62 | try { 63 | [Net.ServicePointManager]::SecurityProtocol = [Net.SecurityProtocolType]::Tls12 -bor [Net.SecurityProtocolType]::Tls11 -bor [Net.SecurityProtocolType]::Tls 64 | Invoke-Command -ScriptBlock ([Scriptblock]::Create((Invoke-WebRequest ($scriptUrlBase +'/AzureSQLDataSyncHealthChecker.ps1') -UseBasicParsing -TimeoutSec 60).Content)) -ArgumentList $parameters 65 | } 66 | catch { 67 | Write-Host 'ERROR: The script file could not be downloaded:' -ForegroundColor Red 68 | $_.Exception 69 | Write-Host 'Confirm this machine can access https://github.com/Microsoft/AzureSQLDataSyncHealthChecker/' -ForegroundColor Yellow 70 | Write-Host 'or use a machine with Internet access to see how to run this from machines without Internet. See how at https://github.com/Azure/SQL-Connectivity-Checker/' -ForegroundColor Yellow 71 | } 72 | #end 73 | ``` 74 | 4. Set the parameters on the script, you need to set server names, database names, users and passwords. 75 | 76 | 5. Run it. 77 | 78 | 6. The major results can be seen in the output window. 79 | If the user has the permissions to create folders, a folder with all the resulting files will be created. 80 | When running on Windows, the folder will be opened automatically after the script completes. 81 | When running on Azure Portal Cloud Shell the files will be stored in the file share (clouddrive). 82 | A zip file with all the files (AllFiles.zip) will be created. 83 | 84 | ## Roadmap 85 | 1. Detect issues and export action plans automatically is the next major goal. 86 | 87 | 88 | ## Data / Telemetry 89 | 90 | This project collects usage data and sends it to Microsoft to help improve our products and services. 91 | Read our [privacy statement](https://go.microsoft.com/fwlink/?LinkId=521839) to learn more. 92 | Telemetry can be disabled by setting the parameter SendAnonymousUsageData = $false (default value is $true). 93 | 94 | 95 | ## Reporting Security Issues 96 | 97 | Security issues and bugs should be reported privately, via email, to the Microsoft Security 98 | Response Center (MSRC) at [secure@microsoft.com](mailto:secure@microsoft.com). You should 99 | receive a response within 24 hours. If for some reason you do not, please follow up via 100 | email to ensure we received your original message. Further information, including the 101 | [MSRC PGP](https://technet.microsoft.com/en-us/security/dn606155) key, can be found in 102 | the [Security TechCenter](https://technet.microsoft.com/en-us/security/default). 103 | 104 | 105 | ## License 106 | 107 | Copyright (c) Microsoft Corporation. All rights reserved. 108 | 109 | Licensed under the [MIT License](./LICENSE). -------------------------------------------------------------------------------- /SECURITY.md: -------------------------------------------------------------------------------- 1 | 2 | 3 | ## Security 4 | 5 | Microsoft takes the security of our software products and services seriously, which includes all source code repositories managed through our GitHub organizations, which include [Microsoft](https://github.com/Microsoft), [Azure](https://github.com/Azure), [DotNet](https://github.com/dotnet), [AspNet](https://github.com/aspnet), [Xamarin](https://github.com/xamarin), and [our GitHub organizations](https://opensource.microsoft.com/). 6 | 7 | If you believe you have found a security vulnerability in any Microsoft-owned repository that meets [Microsoft's definition of a security vulnerability](https://aka.ms/opensource/security/definition), please report it to us as described below. 8 | 9 | ## Reporting Security Issues 10 | 11 | **Please do not report security vulnerabilities through public GitHub issues.** 12 | 13 | Instead, please report them to the Microsoft Security Response Center (MSRC) at [https://msrc.microsoft.com/create-report](https://aka.ms/opensource/security/create-report). 14 | 15 | If you prefer to submit without logging in, send email to [secure@microsoft.com](mailto:secure@microsoft.com). If possible, encrypt your message with our PGP key; please download it from the [Microsoft Security Response Center PGP Key page](https://aka.ms/opensource/security/pgpkey). 16 | 17 | You should receive a response within 24 hours. If for some reason you do not, please follow up via email to ensure we received your original message. Additional information can be found at [microsoft.com/msrc](https://aka.ms/opensource/security/msrc). 18 | 19 | Please include the requested information listed below (as much as you can provide) to help us better understand the nature and scope of the possible issue: 20 | 21 | * Type of issue (e.g. buffer overflow, SQL injection, cross-site scripting, etc.) 22 | * Full paths of source file(s) related to the manifestation of the issue 23 | * The location of the affected source code (tag/branch/commit or direct URL) 24 | * Any special configuration required to reproduce the issue 25 | * Step-by-step instructions to reproduce the issue 26 | * Proof-of-concept or exploit code (if possible) 27 | * Impact of the issue, including how an attacker might exploit the issue 28 | 29 | This information will help us triage your report more quickly. 30 | 31 | If you are reporting for a bug bounty, more complete reports can contribute to a higher bounty award. Please visit our [Microsoft Bug Bounty Program](https://aka.ms/opensource/security/bounty) page for more details about our active programs. 32 | 33 | ## Preferred Languages 34 | 35 | We prefer all communications to be in English. 36 | 37 | ## Policy 38 | 39 | Microsoft follows the principle of [Coordinated Vulnerability Disclosure](https://aka.ms/opensource/security/cvd). 40 | 41 | 42 | --------------------------------------------------------------------------------