├── README.md └── SyncLogins.sql /README.md: -------------------------------------------------------------------------------- 1 | # ag-sync 2 | Utilities to synchronize server-level objects (currently just logins) across availability groups. 3 | 4 | Copyright Daniel Hutmacher under [Creative Commons 4.0 license with attribution](http://creativecommons.org/licenses/by/4.0/). 5 | 6 | Source: http://sqlsunday.com/downloads/ 7 | 8 | DISCLAIMER: This script may not be suitable to run in a production 9 | environment. I cannot assume any responsibility regarding 10 | the accuracy of the output information, performance 11 | impacts on your server, or any other consequence. If 12 | your juristiction does not allow for this kind of 13 | waiver/disclaimer, or if you do not accept these terms, 14 | you are NOT allowed to store, distribute or use this 15 | code in any way. 16 | 17 | Please test stuff before you put it in your 18 | production environment. 19 | 20 | **USAGE:** 21 | 22 | EXECUTE dbo.SyncLogins 23 | @primary_replica, -- {name of SOURCE linked server} 24 | @allow_drop_logins, -- 1=allow script to drop logins 25 | @print_only, -- 1=only print the T-SQL. 26 | @check_policy -- 1=force check password policy to on 27 | @exclude_logins -- comma-separated list of logins to exclude. Example: 'abc,def,DOMAIN\ghi' 28 | 29 | TODO: 30 | * Owners of logins. 31 | * Permissions on endpoints. 32 | -------------------------------------------------------------------------------- /SyncLogins.sql: -------------------------------------------------------------------------------- 1 | USE master; 2 | GO 3 | IF (OBJECT_ID('dbo.SyncLogins') IS NULL) EXEC('CREATE PROCEDURE dbo.SyncLogins AS SELECT 0;'); 4 | GO 5 | /* 6 | 7 | Copyright Daniel Hutmacher under Creative Commons 4.0 license with attribution. 8 | http://creativecommons.org/licenses/by/4.0/ 9 | 10 | Source: http://sqlsunday.com/downloads/ 11 | 12 | DISCLAIMER: This script may not be suitable to run in a production 13 | environment. I cannot assume any responsibility regarding 14 | the accuracy of the output information, performance 15 | impacts on your server, or any other consequence. If 16 | your juristiction does not allow for this kind of 17 | waiver/disclaimer, or if you do not accept these terms, 18 | you are NOT allowed to store, distribute or use this 19 | code in any way. 20 | 21 | Please test stuff before you put it in your 22 | production environment. 23 | 24 | USAGE: EXECUTE dbo.SyncLogins 25 | @primary_replica, -- {name of SOURCE linked server} 26 | @allow_drop_logins, -- 1=allow script to drop logins 27 | @print_only, -- 1=only print the T-SQL. 28 | @exclude_logins -- comma-separated list of logins to exclude. Example: 'abc,def,DOMAIN\ghi' 29 | 30 | TODO: Owners of logins. 31 | Permissions on endpoints. 32 | 33 | VERSION: 2020-05-15 34 | 35 | */ 36 | ALTER PROCEDURE dbo.SyncLogins 37 | @primary_replica sysname=NULL, 38 | @allow_drop_logins bit=0, 39 | @print_only bit=0, 40 | @check_policy bit=0, 41 | @exclude_logins nvarchar(max)=NULL 42 | AS 43 | 44 | 45 | 46 | SET NOCOUNT ON; 47 | DECLARE @sql nvarchar(max), @msg nvarchar(max); 48 | 49 | 50 | 51 | 52 | --- Thanks, sqlDimsJesper! 53 | IF (@primary_replica NOT IN (SELECT [name] FROM sys.servers)) BEGIN; 54 | THROW 50000, N'Primary replica is not a linked server.', 16; 55 | RETURN; 56 | END; 57 | 58 | 59 | IF (@primary_replica IS NULL) BEGIN; 60 | SELECT @primary_replica=primary_replica 61 | FROM sys.dm_hadr_availability_group_states; 62 | 63 | IF (@@ROWCOUNT>1) BEGIN; 64 | THROW 50000, N'More than one availability group exists on server, please specify @primary_replica.', 16; 65 | RETURN; 66 | END; 67 | 68 | IF (@primary_replica IS NULL) BEGIN; 69 | THROW 50000, N'No availability group found, please specify @primary_replica.', 16; 70 | RETURN; 71 | END; 72 | END; 73 | 74 | IF (@primary_replica=@@SERVERNAME) BEGIN; 75 | PRINT N'This server is the primary replica. No changes will be made.'; 76 | RETURN; 77 | END; 78 | 79 | 80 | 81 | 82 | --- These are the logins (Windows user and groups, SQL logins) from 83 | --- the primary replica. 84 | DECLARE @primaryLogins TABLE ( 85 | [name] sysname NOT NULL, 86 | [sid] varbinary(85) NOT NULL, 87 | [type] char(1) NOT NULL, 88 | is_disabled bit NULL, 89 | default_database_name sysname NULL, 90 | default_language_name sysname NULL, 91 | is_policy_checked bit NULL, 92 | is_expiration_checked bit NULL, 93 | password_hash varbinary(256) NULL, 94 | PRIMARY KEY CLUSTERED ([sid]) 95 | ); 96 | 97 | SET @sql=N' 98 | SELECT sp.[name], sp.[sid], sp.[type], sp.is_disabled, sp.default_database_name, 99 | sp.default_language_name, l.is_policy_checked, l.is_expiration_checked, l.password_hash 100 | FROM ['+@primary_replica+'].master.sys.server_principals AS sp 101 | LEFT JOIN ['+@primary_replica+'].master.sys.sql_logins AS l ON sp.[sid]=l.[sid] 102 | WHERE sp.[type] IN (''U'', ''G'', ''S'') AND 103 | UPPER(sp.[name]) NOT LIKE ''NT SERVICE\%'' AND 104 | UPPER(sp.[name]) NOT LIKE ''##%##'' AND'+ISNULL(' 105 | UPPER(sp.[name]) NOT IN ('''+REPLACE(NULLIF(@exclude_logins, ''), ',', ''',''')+''') AND', '')+' 106 | sp.[name] NOT IN (''NT AUTHORITY\SYSTEM'')'; 107 | 108 | INSERT INTO @primaryLogins 109 | EXECUTE master.sys.sp_executesql @sql; 110 | 111 | 112 | --- These are the server roles on the primary replica. 113 | DECLARE @primaryRoles TABLE ( 114 | [sid] varbinary(85) NOT NULL, 115 | [name] sysname NOT NULL, 116 | PRIMARY KEY CLUSTERED ([sid]) 117 | ); 118 | 119 | SET @sql=N' 120 | SELECT sr.[sid], sr.[name] 121 | FROM ['+@primary_replica+'].master.sys.server_principals AS sr 122 | WHERE sr.is_fixed_role=0 AND 123 | sr.[type]=''R'''; 124 | 125 | INSERT INTO @primaryRoles 126 | EXECUTE master.sys.sp_executesql @sql; 127 | 128 | 129 | --- These are the role members of the server roles on 130 | --- the primary replica. 131 | DECLARE @primaryMembers TABLE ( 132 | role_sid varbinary(85) NOT NULL, 133 | member_sid varbinary(85) NOT NULL, 134 | PRIMARY KEY CLUSTERED (role_sid, member_sid) 135 | ); 136 | 137 | SET @sql=N' 138 | SELECT r.[sid], m.[sid] 139 | FROM ['+@primary_replica+N'].master.sys.server_principals AS r 140 | INNER JOIN ['+@primary_replica+N'].master.sys.server_role_members AS rm ON r.principal_id=rm.role_principal_id 141 | INNER JOIN ['+@primary_replica+N'].master.sys.server_principals AS m ON rm.member_principal_id=m.principal_id'; 142 | 143 | INSERT INTO @primaryMembers 144 | EXECUTE master.sys.sp_executesql @sql; 145 | 146 | 147 | --- These are the server-level permissions on the 148 | --- primary replica. 149 | DECLARE @primaryPermissions TABLE ( 150 | state_desc nvarchar(120) NOT NULL, 151 | [permission_name] nvarchar(256) NOT NULL, 152 | principal_name sysname NOT NULL, 153 | PRIMARY KEY CLUSTERED ([permission_name], principal_name) 154 | ); 155 | 156 | SET @sql=N' 157 | SELECT p.state_desc, p.[permission_name], sp.[name] 158 | FROM ['+@primary_replica+'].master.sys.server_permissions AS p 159 | INNER JOIN ['+@primary_replica+'].master.sys.server_principals AS sp ON p.grantee_principal_id=sp.principal_id 160 | WHERE p.class=100'; 161 | 162 | INSERT INTO @primaryPermissions 163 | EXECUTE master.sys.sp_executesql @sql; 164 | 165 | 166 | --- This table variable contains the "run queue" of all commands 167 | --- we want to execute on the local (secondary) replica, ordered 168 | --- by "seq". 169 | DECLARE @queue TABLE ( 170 | seq int IDENTITY(1, 1) NOT NULL, 171 | [sql] nvarchar(max) NOT NULL, 172 | PRIMARY KEY CLUSTERED (seq) 173 | ); 174 | 175 | 176 | ------------------------------------------------------------------------------- 177 | --- Login doesn't exist on the primary - DROP. 178 | INSERT INTO @queue ([sql]) 179 | SELECT N' 180 | DROP LOGIN ['+sp.[name]+N'];' 181 | FROM master.sys.server_principals AS sp 182 | WHERE sp.[type] IN ('U', 'G', 'S') AND 183 | UPPER(sp.[name]) NOT LIKE 'NT SERVICE\%' AND 184 | sp.[name] NOT IN ('NT AUTHORITY\SYSTEM') AND 185 | sp.[sid] NOT IN (SELECT [sid] FROM @primaryLogins) AND 186 | @allow_drop_logins=1; 187 | 188 | 189 | --- Login doesn't exist on the secondary - CREATE. 190 | INSERT INTO @queue ([sql]) 191 | SELECT N' 192 | CREATE LOGIN ['+p.[name]+'] '+(CASE 193 | WHEN p.[type]='S' 194 | THEN N'WITH PASSWORD=0x'+CONVERT(nvarchar(max), p.password_hash, 2)+N' HASHED, CHECK_POLICY='+(CASE WHEN @check_policy=1 THEN N'ON' ELSE N'OFF' END)+N', SID=0x'+CONVERT(nvarchar(max), p.[sid], 2)+N', ' 195 | WHEN p.[type] IN ('U', 'G') 196 | THEN N'FROM WINDOWS WITH ' END)+ 197 | N'DEFAULT_DATABASE=['+p.default_database_name+N']'+ 198 | ISNULL(N', DEFAULT_LANGUAGE='+p.default_language_name, N'')+N';' 199 | FROM @primaryLogins AS p 200 | WHERE p.[sid] NOT IN (SELECT [sid] FROM master.sys.server_principals) AND 201 | p.[type] IN ('U', 'G', 'S'); 202 | 203 | 204 | --- Login exists but has been enabled/disabled - ALTER. 205 | INSERT INTO @queue ([sql]) 206 | SELECT N' 207 | ALTER LOGIN ['+ISNULL(sp.[name], x.[name])+']'+ 208 | (CASE WHEN x.is_disabled=0 AND sp.is_disabled=1 THEN N' ENABLE' 209 | WHEN x.is_disabled=1 AND (sp.is_disabled=0 OR sp.[sid] IS NULL) THEN N' DISABLE' END)+N';' 210 | FROM @primaryLogins AS x 211 | LEFT JOIN master.sys.server_principals AS sp ON x.[sid]=sp.[sid] 212 | WHERE x.is_disabled!=sp.is_disabled OR 213 | x.is_disabled=1 AND sp.[sid] IS NULL; 214 | 215 | 216 | --- Login exists but has changed in some respect - ALTER. 217 | INSERT INTO @queue ([sql]) 218 | SELECT N' 219 | ALTER LOGIN ['+sp.[name]+'] WITH '+ 220 | SUBSTRING( 221 | (CASE WHEN x.password_hash!=l.password_hash 222 | THEN N', PASSWORD=0x'+CONVERT(nvarchar(max), x.password_hash, 2)+N' HASHED, CHECK_POLICY=OFF' 223 | ELSE N'' END)+ 224 | (CASE WHEN ISNULL(x.default_database_name, N'master')!=ISNULL(sp.default_database_name, N'master') 225 | THEN ', DEFAULT_DATABASE=['+x.default_database_name+N']' 226 | ELSE N'' END)+ 227 | (CASE WHEN x.default_language_name!=sp.default_language_name 228 | THEN ', DEFAULT_LANGUAGE='+x.default_language_name 229 | ELSE N'' END)+ 230 | (CASE WHEN x.[name]!=sp.[name] 231 | THEN ', NAME=['+x.[name]+N']' 232 | ELSE N'' END)+ 233 | -- If CHECK_POLICY has changed, but the password hasn't: 234 | (CASE WHEN x.password_hash=l.password_hash AND x.is_policy_checked!=l.is_policy_checked 235 | THEN ', CHECK_POLICY='+(CASE x.is_policy_checked WHEN 1 THEN N'ON' ELSE N'OFF' END) 236 | ELSE N'' END)+ 237 | (CASE WHEN x.is_expiration_checked!=l.is_expiration_checked 238 | THEN ', CHECK_EXPIRATION='+(CASE x.is_expiration_checked WHEN 1 THEN N'ON' ELSE N'OFF' END) 239 | ELSE N'' END), 3, 10000)+N';' 240 | FROM @primaryLogins AS x 241 | INNER JOIN master.sys.server_principals AS sp ON x.[sid]=sp.[sid] 242 | LEFT JOIN master.sys.sql_logins AS l ON sp.[sid]=l.[sid] 243 | WHERE x.password_hash!=l.password_hash OR 244 | ISNULL(x.default_database_name, N'master')!=ISNULL(sp.default_database_name, N'master') OR 245 | ISNULL(x.default_language_name, N'us_english')!=ISNULL(sp.default_language_name, N'us_english') OR 246 | x.[name]!=sp.[name] OR 247 | ISNULL(x.is_policy_checked, 0)!=ISNULL(l.is_policy_checked, 0) OR 248 | ISNULL(x.is_expiration_checked, 0)!=ISNULL(l.is_expiration_checked, 0); 249 | 250 | INSERT INTO @queue ([sql]) 251 | SELECT N' 252 | ALTER LOGIN ['+sp.[name]+'] WITH CHECK_POLICY=ON;' 253 | FROM @primaryLogins AS x 254 | INNER JOIN master.sys.server_principals AS sp ON x.[sid]=sp.[sid] 255 | LEFT JOIN master.sys.sql_logins AS l ON sp.[sid]=l.[sid] 256 | WHERE x.password_hash!=l.password_hash AND 257 | ISNULL(x.is_policy_checked, 0)=1; 258 | 259 | INSERT INTO @queue ([sql]) 260 | SELECT N' 261 | ALTER LOGIN ['+sp.[name]+'] WITH CHECK_EXPIRATION=ON;' 262 | FROM @primaryLogins AS x 263 | INNER JOIN master.sys.server_principals AS sp ON x.[sid]=sp.[sid] 264 | LEFT JOIN master.sys.sql_logins AS l ON sp.[sid]=l.[sid] 265 | WHERE x.password_hash!=l.password_hash AND 266 | ISNULL(x.is_expiration_checked, 0)=1; 267 | 268 | ------------------------------------------------------------------------------- 269 | --- Roles that don't exist on the primary - DROP. 270 | INSERT INTO @queue ([sql]) 271 | SELECT N' 272 | DROP ROLE ['+sp.[name]+N'];' 273 | FROM master.sys.server_principals AS sp 274 | WHERE is_fixed_role=0 AND 275 | sp.[type]='R' AND 276 | sp.[sid] NOT IN (SELECT [sid] FROM @primaryRoles); 277 | 278 | 279 | --- Roles that don't exist on the secondary - CREATE. 280 | INSERT INTO @queue ([sql]) 281 | SELECT N' 282 | CREATE SERVER ROLE ['+r.[name]+N'];' 283 | FROM @primaryRoles AS r 284 | WHERE [sid] NOT IN ( 285 | SELECT [sid] 286 | FROM sys.server_principals 287 | WHERE is_fixed_role=0 AND 288 | [type]='R'); 289 | 290 | 291 | ------------------------------------------------------------------------------- 292 | --- Revoke role memberships: 293 | INSERT INTO @queue ([sql]) 294 | SELECT N' 295 | ALTER SERVER ROLE ['+r.[name]+N'] DROP MEMBER ['+m.[name]+N'];' 296 | FROM sys.server_role_members AS rm 297 | INNER JOIN sys.server_principals AS r ON r.principal_id=rm.role_principal_id 298 | INNER JOIN sys.server_principals AS m ON m.principal_id=rm.member_principal_id 299 | LEFT JOIN @primaryMembers AS pm ON pm.member_sid=m.[sid] AND pm.role_sid=r.[sid] 300 | WHERE pm.role_sid IS NULL; 301 | 302 | 303 | --- Add server role memberships: 304 | INSERT INTO @queue ([sql]) 305 | SELECT N' 306 | ALTER SERVER ROLE ['+r.[name]+N'] ADD MEMBER ['+pl.[name]+N'];' 307 | FROM @primaryMembers AS pm 308 | INNER JOIN @primaryLogins AS pl ON pm.member_sid=pl.[sid] 309 | LEFT JOIN sys.server_principals AS r ON pm.role_sid=r.[sid] AND r.[type]='R' 310 | LEFT JOIN sys.server_principals AS m ON pm.member_sid=m.[sid] 311 | LEFT JOIN sys.server_role_members AS rm ON r.principal_id=rm.role_principal_id AND m.principal_id=rm.member_principal_id 312 | WHERE rm.role_principal_id IS NULL; 313 | 314 | 315 | ------------------------------------------------------------------------------- 316 | --- GRANT/DENY server-level permissions: 317 | INSERT INTO @queue ([sql]) 318 | SELECT N' 319 | '+pp.state_desc+N' '+pp.[permission_name]+N' TO ['+pp.principal_name+'];' 320 | FROM @primaryPermissions AS pp 321 | INNER JOIN sys.server_principals AS sp ON pp.principal_name=sp.[name] 322 | LEFT JOIN sys.server_permissions AS p ON 323 | p.grantee_principal_id=sp.principal_id AND 324 | p.[permission_name] COLLATE database_default=pp.[permission_name] AND 325 | p.class=100 326 | WHERE pp.state_desc!=p.state_desc COLLATE database_default; 327 | 328 | 329 | ------------------------------------------------------------------------------- 330 | --- Ready to roll: 331 | 332 | SET @sql=N''; 333 | SELECT @sql=@sql+[sql] FROM @queue ORDER BY seq; 334 | 335 | --- @print_only=1: PRINT the queue. 336 | WHILE (@print_only=1 AND @sql!=N'') BEGIN; 337 | PRINT LEFT(@sql, CHARINDEX(CHAR(13), @sql+CHAR(13))-1); 338 | SET @sql=SUBSTRING(@sql, CHARINDEX(CHAR(13), @sql+CHAR(13))+2, LEN(@sql)); 339 | END; 340 | 341 | 342 | --- @print_only=0: Execute the queue. 343 | IF (@print_only=0) 344 | EXECUTE master.sys.sp_executesql @sql; 345 | GO 346 | --------------------------------------------------------------------------------