Tried to remove filegroup

  • I'm rolling back my partitioning. I am doing it by merging range in partition function, deleting files and filegroups. I removed all partitions that I wanted to remove, except one. When I try to run :

    alter dbname dashbrd_base remove filegroup lpad_20090124

    it generates message:

    Msg 5042, Level 16, State 12, Line 1

    The filegroup 'lpad_20090124' cannot be removed because it is not empty.

    I built a query to find out which files are members of this filegroup:

    select f.database_id,

    g.data_space_id,

    file_group_name = left(g.name,20),

    file_name = left(f.name,20)

    from sys.filegroups g join sys.master_files f

    on g.data_space_id = f.data_space_id

    where g.name = 'lpad_20090124'

    The result is:

    database_id data_space_id file_group_name file_name

    ----------- ------------- -------------------- --------------------

    NULL 104 lpad_20090124 NULL

    Which means that data space exists, but no files are associated with it. But because of this data space I cannot drop filegroup.

    I also queried sys.indexes, tables, allocation_units, database_files, but could find nothing for data_space_id = 104. However, the only one system recourse where I could find it is sys.destination_data_spaces. And it has some number for destination_id. What is this destination_id ? Where I should go from there ? Any other ideas how to find what makes up a filegroup ?

    Thanks

  • You will need to issue a shrink file against the files in the file group, after they are empty you can then drop them and the filegroup.

    Andrew

  • But my problem is that I could not find any file for the filegroup in the first place.

  • Try GUI:

    Go to SSMS, Right Click the DB, Properties,

    => FILES==> see which file is under your filegroup;

    => Filegroups=> You can remove the filegroup from here.

  • In SSMS/Database/Properties/Filegroups I found my FileGroup, it has 0 under Files column. I pressed Remove button and then OK, but got a message :

    Drop failed for FileGroup 'lpad_20090124'. (Microsoft.SqlServer Smo)

    Additional information:

    Exception occured while executing Transact-SQL stetement or batch.(Microsoft.SqlServer.ConnectionInfo)

    The filegroup 'lpad_20090124' cannot be removed because it is not empty. (Microsoft SQL Server, Error: 5042)

  • Run the following and see what are there:

    USE YOURDATABASE

    SELECT object_name([object_id]) AS Objects_IN_Filegroup

    FROM sys.indexes

    WHERE data_space_id=104

  • Did you check that the filegroup isn't set as the default? If not, set a different filegroup as the default and then you will be able to drop the filegroup.

  • Do you have any partition schemes left over from the partitioning? If so, you won't be able to remove the filegroup unless you drop the schemes.

  • check that the internal tables used for service broker queues aren't in that file group. Read this article for more details:

    http://connect.microsoft.com/SQLServer/feedback/ViewFeedback.aspx?FeedbackID=239891

  • I'm sharing the answer that i found in the hopes it helps someone else.

    I too had a stubborn filegroup that could not be removed. All the files had been removed from the filegroup, the filegroup had been removed from the partition scheme, and it was not holding service broker information. It was truly an empty filegroup yet SQL Server thought it was not empty and thus would not allow the filegroup to be deleted.

    Using the following query i found a record in sys.destination_data_spaces for the filegroup i wished to delete and this record was preventing me from deleting the filegroup.

    select

    partition_scheme_id,destination_id,a.data_space_id,name,b.data_space_id

    from sys.destination_data_spaces a right join sys.filegroups b

    on a.data_space_id = b.data_space_id

    Why did this occur? I could be wrong but my theory is this:

    I had been massaging the partitions quite a bit, adding some new splits to the partition schema then removing some partitions by merging as a result there was gaps in the list of data_space_id's like so

    1

    2

    3

    4

    6

    9

    10

    11

    id's 5 and 7 and 8 had been deleted, id 11 was the filegroup i was wanting to delete but could not.

    The resolution:

    I added 4 new filegroups and then added these filegroups to partition scheme which created ids 5,7,9, and 12. This cause SQL Server to remove id 11 from sys.destination_data_spaces and then i was able to delete the filegroup with no problem.

  • nmederich (1/11/2011)


    I'm sharing the answer that i found in the hopes it helps someone else.

    Why did this occur? I could be wrong but my theory is this:

    I had been massaging the partitions quite a bit, adding some new splits to the partition schema then removing some partitions by merging as a result there was gaps in the list of data_space_id's like so

    1

    2

    3

    4

    6

    9

    10

    11

    id's 5 and 7 and 8 had been deleted, id 11 was the filegroup i was wanting to delete but could not.

    The resolution:

    I added 4 new filegroups and then added these filegroups to partition scheme which created ids 5,7,9, and 12. This cause SQL Server to remove id 11 from sys.destination_data_spaces and then i was able to delete the filegroup with no problem.

    I had exactly the same problem, talked to MS and they walked me through exact same solution.

    Lesson learned.

  • I had the same issue on 2005 sp4. You can check the following query.

    I do have to mention the file group was default all files were removed. However there were primary keys and table objects for sysdiagarms existed in the file group.

    select*

    fromsys.filegroups as fg

    join sys.indexes as i

    on fg.data_space_id = i.data_space_id

    wherefg.name = @file_group_name /** your file group name **/

Viewing 12 posts - 1 through 11 (of 11 total)

You must be logged in to reply to this topic. Login to reply