Results 1 to 8 of 8
  1. #1
    Join Date
    Dec 2007
    Posts
    288

    Unanswered: dropping a login that is DBO

    I am in the procecss of migrating a Database from SQL Server 2000 to 2005.

    In the past I have logged into my SQL Server 2000 Standard Edition Instance, scripted out the users associated with the database that I want to migrate then recreate the users on the 2005 Instance.

    Then when I restore my 2000 DB to 2005, all users and their permissions are already in place.

    This time I have a little bit of a different situation. The DB I want to move needs ALOT of clean-up!!! Seems the previous DBA made every NT authenticated login that has access to this database OWNER of the Database. What I WANTED to do in my test system is restore the database (2000 to 2005) then in the 2005 DB, drop all of the users so that I can create a DB role and add each user to the Role for their permissions.

    My problem is, I cannot drop the users from my 2005 DB because I get this errror:

    Msg 15138, Level 16, State 1, Line 3
    The database principal owns a schema in the database, and cannot be dropped.

    I know I'm getting this error because the user is designated as DB_Owner.

    How can I get around this and drop the user? Is there a better way of doing this migration???

  2. #2
    Join Date
    Nov 2004
    Location
    on the wrong server
    Posts
    8,835
    Provided Answers: 6
    I might find the objects in question and change their owner.
    “If one brings so much courage to this world the world has to kill them or break them, so of course it kills them. The world breaks every one and afterward many are strong at the broken places. But those that will not break it kills. It kills the very good and the very gentle and the very brave impartially. If you are none of these you can be sure it will kill you too but there will be no special hurry.” Earnest Hemingway, A Farewell To Arms.

  3. #3
    Join Date
    Dec 2007
    Posts
    288
    excuse my ignorance.. but I don't think I understand. When I look at each login (there are about 40 of them), each is designated as DB_Owner in this particular database. I can't drop any of them until I take away their DB_Owner status. Do I have to do that through the gui or is there a way to do this programatically?

  4. #4
    Join Date
    Jun 2004
    Location
    Long Island
    Posts
    696
    create a new temporary schema, make that their default, save, then drop that schema, then drop the users.

    alter each user:
    alter user username
    with default_schema = schemaname

    drop the schema

    then drop the users

  5. #5
    Join Date
    Dec 2007
    Posts
    288
    Thank you so much for all the help!! I guess I didn't realize how complicated all of this could be migrating databases from 2000 to 2005.

    If I create a temp schema, assign the users to it then drop the users and schema... What would be the best way to add these users back in?

    I have 40+ users that need read\write access to this database.

    What I was going to do was use the above procedure to drop them all and then add them back into the Instance as users and then into a Database role in the database itself for their permissions.. Am I on right track? In my migration, I am trying to get away for all of these individual permissions all over the place. Should I put them in some kind of global group at the instance level and also use the database role?? your suggestions are certainly appreciated.

  6. #6
    Join Date
    Jun 2004
    Location
    Long Island
    Posts
    696
    Quote Originally Posted by itsonlyme44
    Thank you so much for all the help!! I guess I didn't realize how complicated all of this could be migrating databases from 2000 to 2005.

    If I create a temp schema, assign the users to it then drop the users and schema... What would be the best way to add these users back in?

    I have 40+ users that need read\write access to this database.

    What I was going to do was use the above procedure to drop them all and then add them back into the Instance as users and then into a Database role in the database itself for their permissions.. Am I on right track? In my migration, I am trying to get away for all of these individual permissions all over the place. Should I put them in some kind of global group at the instance level and also use the database role?? your suggestions are certainly appreciated.
    One quirk I've noticed with Management Studio (if you choose to use the GUI) to change default schema, you must refresh to see the new schema assignment, else it does not look like the schema has changed for that user.

  7. #7
    Join Date
    Dec 2007
    Posts
    288
    I'll have 40+ users to change so I won't be using the GUI.

    so basically what I will do is this:

    Script my NT logins on 2000 and recreate them in the 2005 instance.
    restore my DB to 2005
    In the database, I will create a new schema, assign all of the users to it then delete the individual user schemas IN the database. Once that is done, I will create a new Database ROLE and all the users to it for their permissions.

    So my question now is, these users are greated globally in the instance and their schemas exist in a particular database. if they need permissions to another Database, do they get a new schema in THAT database???

  8. #8
    Join Date
    Jan 2003
    Location
    Massachusetts
    Posts
    5,800
    Provided Answers: 11
    By default, any user in a database will get a schema in that database, unless specifically set to use an existing schema. When a SQL 2000 database is restored to a SQL 2005 server, these schemas are created automatically.

    To speed things up, and get them all at once, you can do this old trick:

    Code:
    select 'alter user ' + name + ' with default_schema = dbo'
    from sys.database_principals
    where type in ('U', 'S')
      and sid is not null
      and sid not in (0x00, 0x01)
    Simply run the output, and you should be able to drop the schemas or the users. A similar statement can be written to drop the spurious schemas. Make sure you do not drop INFORMATION_SCHEMA or dbo.

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •