SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


How to find the owner of the table in MSSQL 2005?


How to find the owner of the table in MSSQL 2005?

Author
Message
kasper-383322
kasper-383322
SSC-Enthusiastic
SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)

Group: General Forum Members
Points: 103 Visits: 4

Hi,

The question is: the default owner of the table was set to the principal name by the "ALTER AUTHORIZATION" query.

Now, how can I see the name of the owner, and can I get it using SQL query?

Thanks.


Julian Kuiters
Julian Kuiters
SSCrazy
SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)

Group: General Forum Members
Points: 2975 Visits: 1
In SQL2005:

SELECT SCHEMA_NAME(OBJECTPROPERTYEX(OBJECT_ID('yourTablesName'),N'SchemaId'))




Julian Kuiters
juliankuiters.id.au
peterhe
peterhe
SSCertifiable
SSCertifiable (6.4K reputation)SSCertifiable (6.4K reputation)SSCertifiable (6.4K reputation)SSCertifiable (6.4K reputation)SSCertifiable (6.4K reputation)SSCertifiable (6.4K reputation)SSCertifiable (6.4K reputation)SSCertifiable (6.4K reputation)

Group: General Forum Members
Points: 6398 Visits: 453

In 2005, an object's owner is schema owner by default. It can be changed to other principals by "ALTER AUTHORIZATION", in this case, the principal_id will not be null i the sys.objects table. To get table (view, SP,udf, etc) owner:

SELECT o.object_id, o.name,

CASE WHEN principal_id is NOT NULL THEN (SELECT name FROM sys.database_principals dp WHERE dp.principal_id=o.principal_id)

ELSE (SELECT dp.name FROM sys.database_principals dp,sys.schemas s WHERE s.schema_id=o.schema_id and s.principal_id=dp.principal_id)

END as Owner

FROM sys.objects o

WHERE type='U'

GO

E.g.:

USE AdventureWorks

GO

select * FROM sys.objects where type='U'

select * from sys.schemas

SELECT * from sys.database_principals

GO

SELECT o.object_id, o.name,

CASE WHEN principal_id is NOT NULL THEN (SELECT name FROM sys.database_principals dp WHERE dp.principal_id=o.principal_id)

ELSE (SELECT dp.name FROM sys.database_principals dp,sys.schemas s WHERE s.schema_id=o.schema_id and s.principal_id=dp.principal_id)

END as Owner

FROM sys.objects o

WHERE type='U'

GO

Change one table owner to guest:

ALTER AUTHORIZATION ON Production.ProductSubcategory TO guest

GO

SELECT o.object_id, o.name,

CASE WHEN principal_id is NOT NULL THEN (SELECT name FROM sys.database_principals dp WHERE dp.principal_id=o.principal_id)

ELSE (SELECT dp.name FROM sys.database_principals dp,sys.schemas s WHERE s.schema_id=o.schema_id and s.principal_id=dp.principal_id)

END as Owner

FROM sys.objects o

WHERE type='U'

GO

Restore the table owner to schema owner:

ALTER AUTHORIZATION ON Production.ProductSubcategory TO schema owner

GO





barbara.roy
barbara.roy
SSC Rookie
SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)

Group: General Forum Members
Points: 31 Visits: 107
Can it be seen in SSMS anywhere once the ALTER AUTHORIZATION has been done? It doesn't look like it changes anything there.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum








































































































































































SQLServerCentral


Search