Find message type owners

When dropping a user from a database, sometimes they own a table or a schema, and you can go drop them.  This had become routine, until I came across a new message today.

“The database principal owns a message type in the database and cannot be dropped”

To find the owners of service types, run the following T-SQL:

select dp.name, smt.*
from sys.service_message_types smt
inner join sys.database_principals dp on smt.principal_id = dp.principal_id

To change the owner to dbo, run the following:
ALTER AUTHORIZATION ON MESSAGE TYPE::Name TO dbo;

Then another error was next up:

“The database principal owns a contract in the database, and cannot be dropped.”

select dp.name, sc.*
from sys.service_contracts sc
inner join sys.database_principals dp on sc.principal_id = dp.principal_id

To change the owner to dbo, run the following:
ALTER AUTHORIZATION ON CONTRACT::Name TO dbo;

Then finally, the error about the service showed up:

“The database principal owns a service in the database, and cannot be dropped.”

select dp.name, s.*
from sys.services s
inner join sys.database_principals dp on s.principal_id = dp.principal_id

To change the owner to dbo, run the following:
ALTER AUTHORIZATION ON SERVICE::Name TO dbo;

After changing the owners, I was able to drop the user from the database.  I recommend changing these changes on non-production, to see how the application does, before applying to production.

Advertisements
This entry was posted in Uncategorized. Bookmark the permalink.

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s