Last day I had excellent fun asking puzzle on SQL Server Login SQL SERVER – Merry Christmas and Happy Holidays – Database Properties – Number of Users. One of the user sent me email asking urgent question about how to resolve following error. Reader was trying to remove the login from database but every single time he was getting error and was not able to remove the user.
The database principal owns a schema in the database, and cannot be dropped. (Microsoft SQL Server, Error: 15138)
As per him it was very urgent and he was not able to solve the same. I totally understand his situation and here is the quick workaround to the issue. The reason for error is quite clear from the error message as there were schema associated with the user and that needs to be transferred to another user.
Workaround / Resolution / Fix:
Let us assume that user was trying to delete user which is named as ‘pinaladmin’ and it exists in the database ‘AdventureWorks’.
Now run following script with the context of the database where user belongs.
USE AdventureWorks;
SELECT s.name
FROM sys.schemas s
WHERE s.principal_id = USER_ID('pinaladmin');
In my query I get following two schema as a result.
Now let us run following query where I will take my schema and and alter authorization on schema. In our case we have two schema so we will execute it two times.
ALTER AUTHORIZATION ON SCHEMA::db_denydatareader TO dbo;
ALTER AUTHORIZATION ON SCHEMA::db_denydatawriter TO dbo;
Now if you drop the database owner it will not throw any error.
Here is generic script for resolving the error:
SELECT s.name
FROM sys.schemas s
WHERE s.principal_id = USER_ID('YourUserID');
Now replace the result name in following script:
ALTER AUTHORIZATION ON SCHEMA::YourSchemaName TO dbo;
Reference: Pinal Dave (https://blog.sqlauthority.com)
129 Comments. Leave new
thank you
Pinal Dave you are Damn Good!! Please continue to help the entire SQL community
Thanks, Dave – this was exactly what I was looking for. And I like the scripting method because it gives me a better understanding of SQLServer internals.
Thanks a lot Pinal !
Thanks for the post !!!!
Thank you. It worked. Saved my bacon.
Hi Dave,
How to restrict the users to access the objects of different schema under same Database without schema name.
Ex if I have two users dbo. and Test respective default schemas are dbo. and TEST_SCHEMA. objects which is present in dbo schema and not in TEST_SCHEMA Now I want TEST USER to allow acces dbo user’s objs with schema Name only if the same objects name is not present under TEST_SCHEMA.
as Select * from dbo.emp not select * from emp (if emp is not in TEST_SCHEMA)
Hi Dave,
I have a sql 2008 instance where dbo is orphaned. Found by running sp_change_users_login ‘report’.
Any ideas how to fix this?
Nice script. Still works a treat!
Dude just had to say your awesome!!!!!
Thank you! This helped a lot!
Thanks..it helped to resolve my issue.
Thanks a lot
it resolved my pending issue
You have great information. Thank you!
Thanks \(^.^)/
Great help…thank you.
great article ! thanks
Great help for me thnk you thank youuuuuu
Great post! :)
Thank you :]
Tried many suggestions, but only this one worked for me. Thank you!!!