Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Question about SQL2012 availability groups & security Expand / Collapse
Author
Message
Posted Tuesday, April 1, 2014 1:14 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Today @ 1:11 PM
Points: 15, Visits: 285
How should application/users security be set up? If server #1 fails, availability group #1 fails over to server #2 but the security does not, so applications fail. I have duplicated all users to server #2 (from server #1) but the apps/users' mappings are not there and cannot be created...


Thanks
Post #1557174
Posted Tuesday, April 1, 2014 1:43 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 10:02 AM
Points: 6,268, Visits: 13,500
Zubius (4/1/2014)
How should application/users security be set up? If server #1 fails, availability group #1 fails over to server #2 but the security does not, so applications fail. I have duplicated all users to server #2 (from server #1) but the apps/users' mappings are not there and cannot be created...


Thanks

Just like Log Shipping and Database Mirroring, for SQL Server authentication accounts you'll need to synchronise these between the replicas.
This includes preserving the account SIDs to avoid orphaned users. Plenty of scripts available to help with this, here's a basic to get you going

SELECT		'CREATE LOGIN [' + name + '] WITH PASSWORD = ' + 
sys.fn_varbintohexstr(password_hash) +
' HASHED, SID = ' + sys.fn_varbintohexstr(sid) +
', DEFAULT_DATABASE = ' + QUOTENAME(default_database_name) +
', DEFAULT_LANGUAGE = ' + default_language_name +
', CHECK_EXPIRATION = ' +
CASE
WHEN is_expiration_checked = 0 THEN 'OFF'
ELSE 'ON'
END +
', CHECK_POLICY = ' +
CASE
WHEN is_policy_checked = 0 THEN 'OFF'
ELSE 'ON'
END +
CASE is_disabled
WHEN 0 THEN ''
ELSE '; ALTER LOGIN [' + name + '][ DISABLE;'
END
FROM master.sys.sql_logins



-----------------------------------------------------------------------------------------------------------

"Ya can't make an omelette without breaking just a few eggs"
Post #1557186
Posted Tuesday, April 1, 2014 8:11 PM


SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: Today @ 7:50 PM
Points: 4,342, Visits: 6,147
Perry is spot-on as usual. You will need to pick a "master" sql instance and then script out the logins with the SID and then replace all existing instances with the new login (drop/create). Once that is done the database will be accessible by those logins because the SIDs are the same all around. Easy-peasy, lemon-squeezy ... once you know the trick!!

Best,

Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru at GMail
Post #1557293
Posted Wednesday, April 2, 2014 1:07 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 10:02 AM
Points: 6,268, Visits: 13,500
And as part of your AO group deployment you've already identified a preferred Primary

-----------------------------------------------------------------------------------------------------------

"Ya can't make an omelette without breaking just a few eggs"
Post #1557343
Posted Wednesday, April 2, 2014 6:49 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Today @ 1:11 PM
Points: 15, Visits: 285
Thank You both for the prompt replies. I was struggling with this for some time. I'll run a few tests during our next maintenance window and post back If I have any issues.
Post #1557450
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse