Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 

Basit's SQL Server Tips

Basit Farooq is a Lead Database Administrator, Trainer and Technical Author. He has more than a decade of IT experience in development, technical training and database administration on Microsoft SQL Server platforms. Basit has authored numerous SQL Server technical articles, and developed and implemented many successful database infrastructure, data warehouse and business intelligence projects. He holds a master's degree in computer science from London Metropolitan University, and industry standard certifications from Microsoft, Sun, Cisco, Brainbench, Prosoft and APM, including MCITP Database Administrator 2008, MCITP Database Administrator 2005, MCDBA SQL Server 2000 and MCTS .NET Framework 2.0 Web Applications.

The database principal owns a schema in the database, and cannot be dropped

Problem

You are trying to drop a database user, but are getting the following error message:

The database principal owns a schema in the database, and cannot be dropped. (Microsoft SQL Server, Error: 15138)

This error is self-explanatory as it tells you that the database user you are trying to drop is the database schema owner.

Resolution

To successfully drop the database user, you must find all the schemas that are owned by the database user, and then transfer their ownership to another user.

Here is the Transact-SQL script, which I wrote a while ago, to drop the database user. This script first transfer’s ownership of all database schemas associated with particular database user to the specified database user, and then drops that database user from the database.

To use this script, change the following two local variables of this script:

  • @SQLUser – Specify the name of the database user that you want to drop
  • @NewSchemaOwner – Specify the name of the database user that will be used as new schema owner for the schemas that is owned by the database user, which you are dropping

-- Ensure a USE database_name statement has been executed first.
SET NOCOUNT ON;

DECLARE @ID [int] ,
		@CurrentCommand [nvarchar](MAX) ,
		@ErrorMessage   [nvarchar](2000) ,
		@SQLUser        [sysname] , --Specify the name of the database user that you want to drop
		@NewSchemaOwner [sysname];  --Specify the name of the database user that will be used as new schema
								    --owner for the schemas that is owned by the database user you are dropping

SET @SQLUser = N'Specify_Database_User_You_Want_To_Drop'; --Example: testuser
SET @NewSchemaOwner = N'Specify_Database_User_Who_Will_User_As_New_Schema_Owner'; --Example: liveuser

DECLARE @Work_To_Do TABLE
    (
      [ID] [int] IDENTITY(1, 1)
                 PRIMARY KEY ,
      [TSQL_Text] [varchar](1024) ,
      [Completed] [bit]
    );

INSERT  INTO @Work_To_Do
        ( [TSQL_Text] ,
          [Completed]
        )
        SELECT  N'ALTER AUTHORIZATION ON SCHEMA::' + [name] + SPACE(1) + 'TO'
                + SPACE(1) + QUOTENAME(@NewSchemaOwner) ,
                0
        FROM    [sys].[schemas]
        WHERE   [principal_id] = USER_ID(@SQLUser);

INSERT  INTO @Work_To_Do
        ( [TSQL_Text] ,
          [Completed]
        )
        SELECT  N'DROP USER' + SPACE(1) + @SQLUser ,
                0

SELECT  @ID = MIN([ID])
FROM    @Work_To_Do
WHERE   [Completed] = 0;

WHILE @ID IS NOT NULL
    BEGIN
        SELECT  @CurrentCommand = [TSQL_Text]
        FROM    @Work_To_Do
        WHERE   [ID] = @ID;

        BEGIN TRY
            EXEC [sys].[sp_executesql] @CurrentCommand
            PRINT @CurrentCommand
        END TRY
        BEGIN CATCH

            SET @ErrorMessage = N'"Oops, an error occurred that could not be resolved. For more information, see below:'
                + CHAR(13) + ERROR_MESSAGE() 

            RAISERROR(@ErrorMessage,16,1) WITH NOWAIT

            GOTO ChooseNextCommand
        END CATCH

        ChooseNextCommand:

        UPDATE  @Work_To_Do
        SET     [Completed] = 1
        WHERE   [ID] = @ID

        SELECT  @ID = MIN([ID])
        FROM    @Work_To_Do
        WHERE   [Completed] = 0
    END;

SET NOCOUNT OFF;


Comments

Leave a comment on the original post [basitaalishan.com, opens in a new window]

Loading comments...