Validate_sku_features_before_uninstalling_SP1.sql 4.6 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384
  1. SET NOCOUNT ON;
  2. DECLARE @database_id int, @dbname VARCHAR(1000), @sqlcmd NVARCHAR(4000), @ErrorMessage NVARCHAR(1000), @sqlmajorver int
  3. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpdbs'))
  4. DROP TABLE #tmpdbs;
  5. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpdbs'))
  6. CREATE TABLE #tmpdbs (id int IDENTITY(1,1), [database_id] int, [dbname] VARCHAR(1000), is_database_joined bit, isdone bit);
  7. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblPerSku'))
  8. DROP TABLE #tblPerSku;
  9. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblPerSku'))
  10. CREATE TABLE #tblPerSku ([dbname] sysname NULL, [feature_name] VARCHAR(100));
  11. /*
  12. Reference: SERVERPROPERTY for sql major versions supported after:
  13. @sqlmajorver >= 13 OR (@sqlmajorver = 12 AND @sqlbuild >= 2556 AND @sqlbuild < 4100) OR (@sqlmajorver = 12 AND @sqlbuild >= 4427)
  14. */
  15. SELECT @sqlmajorver = CONVERT(int, (@@microsoftversion / 0x1000000) & 0xff)
  16. SET @sqlcmd = 'SELECT sd.database_id, sd.name, rcs.is_database_joined, 0
  17. FROM master.sys.databases (NOLOCK) sd
  18. LEFT JOIN sys.dm_hadr_database_replica_states (NOLOCK) d ON sd.database_id = d.database_id
  19. LEFT JOIN sys.availability_replicas ar (NOLOCK) ON d.group_id = ar.group_id AND d.replica_id = ar.replica_id
  20. LEFT JOIN sys.dm_hadr_availability_replica_states (NOLOCK) ars ON d.group_id = ars.group_id AND d.replica_id = ars.replica_id
  21. LEFT JOIN sys.dm_hadr_database_replica_cluster_states (NOLOCK) rcs ON rcs.database_name = sd.name AND rcs.replica_id = ar.replica_id
  22. WHERE sd.[state] = 0 AND sd.database_id > 4
  23. GROUP BY sd.database_id, sd.name, sd.is_read_only, sd.[state], sd.is_distributor, ar.secondary_role_allow_connections, sd.[compatibility_level], rcs.is_database_joined, rcs.is_failover_ready
  24. HAVING MIN(COALESCE(ars.[role],1)) <> 2;'
  25. INSERT INTO #tmpdbs ([database_id], [dbname], is_database_joined, [isdone])
  26. EXEC sp_executesql @sqlcmd;
  27. WHILE (SELECT COUNT(id) FROM #tmpdbs WHERE isdone = 0) > 0
  28. BEGIN
  29. SELECT TOP 1 @dbname = [dbname], @database_id = [database_id] FROM #tmpdbs WHERE isdone = 0
  30. SET @sqlcmd = 'USE ' + QUOTENAME(@dbname) + ';
  31. SELECT ''' + REPLACE(@dbname, CHAR(39), CHAR(95)) + ''' AS [dbname], feature_name FROM sys.dm_db_persisted_sku_features (NOLOCK)
  32. UNION ALL
  33. SELECT ''' + REPLACE(@dbname, CHAR(39), CHAR(95)) + ''' AS [dbname], ''ChangeTracking'' AS feature_name FROM sys.change_tracking_databases (NOLOCK) WHERE database_id = DB_ID()
  34. UNION ALL
  35. SELECT TOP 1 ''' + REPLACE(@dbname, CHAR(39), CHAR(95)) + ''' AS [dbname], ''RowLevelSecurity'' AS feature_name FROM sys.security_policies (NOLOCK)
  36. UNION ALL
  37. SELECT TOP 1 ''' + REPLACE(@dbname, CHAR(39), CHAR(95)) + ''' AS [dbname], ''FineGrainedAuditing'' AS feature_name FROM sys.database_audit_specifications (NOLOCK)
  38. UNION ALL
  39. SELECT TOP 1 ''' + REPLACE(@dbname, CHAR(39), CHAR(95)) + ''' AS [dbname], ''AlwaysEncrypted'' AS feature_name FROM sys.column_master_keys (NOLOCK)'
  40. IF @sqlmajorver >= 13
  41. SET @sqlcmd = @sqlcmd + CHAR(10) + 'UNION ALL
  42. SELECT TOP 1 ''' + REPLACE(@dbname, CHAR(39), CHAR(95)) + ''' AS [dbname], ''Polybase'' AS feature_name FROM sys.external_data_sources (NOLOCK)
  43. UNION ALL
  44. SELECT TOP 1 ''' + REPLACE(@dbname, CHAR(39), CHAR(95)) + ''' AS [dbname], ''DynamicDataMasking'' AS feature_name FROM sys.masked_columns (NOLOCK) WHERE is_masked = 1'
  45. BEGIN TRY
  46. INSERT INTO #tblPerSku
  47. EXECUTE sp_executesql @sqlcmd
  48. END TRY
  49. BEGIN CATCH
  50. ;THROW
  51. END CATCH
  52. UPDATE #tmpdbs
  53. SET isdone = 1
  54. WHERE [database_id] = @database_id
  55. END;
  56. IF (SELECT COUNT(DISTINCT [name]) FROM master.sys.databases (NOLOCK) WHERE database_id NOT IN (2,3) AND source_database_id IS NOT NULL) > 0 -- Snapshot
  57. BEGIN
  58. INSERT INTO #tblPerSku
  59. SELECT DISTINCT [name], 'DatabaseSnapshot' AS feature_name FROM master.sys.databases (NOLOCK) WHERE database_id NOT IN (2,3) AND source_database_id IS NOT NULL;
  60. END;
  61. IF (SELECT COUNT([dbname]) FROM #tblPerSku) > 0
  62. BEGIN
  63. SELECT [Feature_Name], [dbname] AS [Database_Name]
  64. FROM #tblPerSku
  65. ORDER BY [Feature_Name], [dbname];
  66. THROW 60000, 'The instance cannot be downgraded from SP1 as it contains at least 1 database mentioned above with SKU features not available in SQL Server 2016 RTM. If downgrade is attempted, it can leave the database in suspect mode. DROP or DISABLE the feature and rerun the script to confirm before you downgrade',0
  67. END
  68. ELSE
  69. BEGIN
  70. ;THROW 60000,'The instance can be downgraded as it does not contain any database leveraging features that were only enabled on lower editions with SP1',0
  71. END