SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Tried to remove filegroup


Tried to remove filegroup

Author
Message
SQL Guy 1
SQL Guy  1
Ten Centuries
Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)

Group: General Forum Members
Points: 1372 Visits: 2515
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
andrewkane17
andrewkane17
Right there with Babe
Right there with Babe (741 reputation)Right there with Babe (741 reputation)Right there with Babe (741 reputation)Right there with Babe (741 reputation)Right there with Babe (741 reputation)Right there with Babe (741 reputation)Right there with Babe (741 reputation)Right there with Babe (741 reputation)

Group: General Forum Members
Points: 741 Visits: 3240
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



SQL Guy 1
SQL Guy  1
Ten Centuries
Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)

Group: General Forum Members
Points: 1372 Visits: 2515
But my problem is that I could not find any file for the filegroup in the first place.
DBA in Unit 7
DBA in Unit 7
Old Hand
Old Hand (363 reputation)Old Hand (363 reputation)Old Hand (363 reputation)Old Hand (363 reputation)Old Hand (363 reputation)Old Hand (363 reputation)Old Hand (363 reputation)Old Hand (363 reputation)

Group: General Forum Members
Points: 363 Visits: 1124
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.
SQL Guy 1
SQL Guy  1
Ten Centuries
Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)

Group: General Forum Members
Points: 1372 Visits: 2515
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)
DBA in Unit 7
DBA in Unit 7
Old Hand
Old Hand (363 reputation)Old Hand (363 reputation)Old Hand (363 reputation)Old Hand (363 reputation)Old Hand (363 reputation)Old Hand (363 reputation)Old Hand (363 reputation)Old Hand (363 reputation)

Group: General Forum Members
Points: 363 Visits: 1124
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



Scott Clark-275269
Scott Clark-275269
SSC Veteran
SSC Veteran (211 reputation)SSC Veteran (211 reputation)SSC Veteran (211 reputation)SSC Veteran (211 reputation)SSC Veteran (211 reputation)SSC Veteran (211 reputation)SSC Veteran (211 reputation)SSC Veteran (211 reputation)

Group: General Forum Members
Points: 211 Visits: 422
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.
SA-1
SA-1
SSCommitted
SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)

Group: General Forum Members
Points: 1547 Visits: 944
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.
Scott Clark-275269
Scott Clark-275269
SSC Veteran
SSC Veteran (211 reputation)SSC Veteran (211 reputation)SSC Veteran (211 reputation)SSC Veteran (211 reputation)SSC Veteran (211 reputation)SSC Veteran (211 reputation)SSC Veteran (211 reputation)SSC Veteran (211 reputation)

Group: General Forum Members
Points: 211 Visits: 422
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
nmederich
nmederich
SSC Rookie
SSC Rookie (43 reputation)SSC Rookie (43 reputation)SSC Rookie (43 reputation)SSC Rookie (43 reputation)SSC Rookie (43 reputation)SSC Rookie (43 reputation)SSC Rookie (43 reputation)SSC Rookie (43 reputation)

Group: General Forum Members
Points: 43 Visits: 203
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.



Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search