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

Users, Groups, and Schemas Expand / Collapse
Author
Message
Posted Monday, January 7, 2013 11:51 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Yesterday @ 6:34 AM
Points: 240, Visits: 512
Hi guys,

I've got the following problem that I need help with:

Our team can be roughly divided into 2 groups:

Group 1: Only needs read access to the database (data reader)
Group 2: Needs to be able to do anything within the database (dbo)

Every time a new database is created, we have historically added each user (with either dbo or data reader privileges).

At some point we've realized that it would make sense to create 2 windows domain groups with appropriate users, and then, as a new database is created we'll just grant data_reader access to group_1 and grant dbo access to group_2. And this is what we did, until we ran into the following problem:

Once a user X (which belongs to group_2) creates a new table (without using dbo schema as a prefix), a new schema is created for that user, and this user is created in the database (with a red arrow pointing downward next to his/her name). If dbo.Table_Name is used, then the user and schema are not created.

When I asked our DBA why this is happening, the response was that dbo should always be used in front of the object name when the object is created. This sounds fine, but not always possible to enforce and also when a specific user is created the default schema can be set to dbo, but for the domain group it seems not to be possible.

Questions:

1. Is what I am observing the expected behavior?

2. How do people deal with the issue - do they enforce all the users to specify dbo or is there a way to set the default schema at the group level?

Thanks in advance!

Post #1403792
Posted Monday, January 7, 2013 2:35 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 10:47 AM
Points: 7,126, Visits: 12,727
sql_er (1/7/2013)
Group 2: Needs to be able to do anything within the database (dbo)

Membership in the db_owner Role (could be many members) is not the same as the dbo user. Know that dbo (a Database User in every database linked to sa Server Login), the db_owner Fixed Database Role and the database owner (the Server Login that actually owns the database) are three different things and it is important to make the proper distinctions when discussing permissions because they imply different things.

Questions:

1. Is what I am observing the expected behavior?

Yes. What you are seeing is the expected behavior for Database Users based on Windows Groups in SQL 2005, SQL 2008 and SQL 2008 R2. In SQL 2012 we have the ability to define a default schema for a Database User based on a Windows Group which is a feature added to respond to the presumably undesirable behavior you are seeing.

2. How do people deal with the issue - do they enforce all the users to specify dbo or is there a way to set the default schema at the group level?

Yes. I enforce this through code reviews. It is a best practice to schema-qualify your objects, unless you are in a multi-tenant database using a tenant-by-schema approach in which case it is expected that developers not schema-qualify object references.


__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato
Post #1403878
Posted Tuesday, January 8, 2013 2:10 PM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Yesterday @ 6:34 AM
Points: 240, Visits: 512
Thank you for your suggestions.

It makes sense.
Post #1404446
Posted Wednesday, January 9, 2013 4:31 PM
Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Yesterday @ 2:36 PM
Points: 570, Visits: 758
opc.three. Would you be so kind as to implement your statement, ' In SQL 2012 we have the ability to define a default schema for a Database User based on a Windows Group which is a feature added to respond to the presumably undesirable behavior you are seeing.' I need to do this but can't figure out exactly how. Thanks.
Post #1405071
Posted Wednesday, January 9, 2013 7:22 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 10:47 AM
Points: 7,126, Visits: 12,727
michaelkinlb (1/9/2013)
opc.three. Would you be so kind as to implement your statement, ' In SQL 2012 we have the ability to define a default schema for a Database User based on a Windows Group which is a feature added to respond to the presumably undesirable behavior you are seeing.' I need to do this but can't figure out exactly how. Thanks.

Sure. It's now the same syntax as adding a Database User based on a Windows Account.

USE master;
CREATE LOGIN [domain\group] FROM WINDOWS;
USE daabasename;
CREATE USER [domain\group] FOR LOGIN [domain\group] WITH DEFAULT_SCHEMA = [dbo];

Now when any member of domain\group creates a table or module without schema-qualifying it that object will go into the dbo schema instead of SQL Server creating a new schema for that username and adding it to the new schema.


__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato
Post #1405124
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse