The default filegroup, and why you should care.

Kenneth Fisher, 2018-02-19

You know you can have multiple filegroups right? You might have a separate filegroup for the data (the clustered index & heaps) and another for the indexes (non-clustered indexes). Or maybe you want to separate your data tables from the system tables. There are any number of reasons why you might want to have multiple filegroups, however, there will always be a primary filegroup and it will always be the default if you don’t specify otherwise. Right? Wrong.

I’ve never seen a way to remove primary or to move the system objects in it. However, you can change the primary filegroup.

CREATE DATABASE [PrimaryFG]
 ON  PRIMARY 
( NAME = N'PrimaryFG', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL13.SQL2016CS\MSSQL\DATA\PrimaryFG.mdf' , SIZE = 1048576KB , FILEGROWTH = 524288KB ), 
-- Create an additional filegroup and file for it.
 FILEGROUP [DATA] 
( NAME = N'PrimaryFG_Data', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL13.SQL2016CS\MSSQL\DATA\PrimaryFG_Data.ndf' , SIZE = 1048576KB , FILEGROWTH = 524288KB )
 LOG ON 
( NAME = N'PrimaryFG_log', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL13.SQL2016CS\MSSQL\DATA\PrimaryFG_log.ldf' , SIZE = 1048576KB , FILEGROWTH = 524288KB )
GO
USE [PrimaryFG]
GO
-- If it isn't already the primary filegroup change it to the primary.
IF NOT EXISTS (SELECT name FROM sys.filegroups WHERE is_default=1 AND name = N'DATA') 
	ALTER DATABASE [PrimaryFG] MODIFY FILEGROUP [DATA] DEFAULT
GO

Now when I create a new table it will be created in the DATA filegroup unless I specify otherwise.

CREATE TABLE OnData (col1 int);
CREATE TABLE OnPrimary (col1 int) ON [PRIMARY];
GO
SELECT d.name As DataSpace, ISNULL(i.name,'Heap') AS IndexName, t.name AS TableName
FROM sys.data_spaces d
JOIN sys.indexes i
	ON d.data_space_id = i.data_space_id
JOIN sys.tables t
	ON i.object_id = t.object_id;

The nice thing here is that it helps prevent mistakes. If you want all of your tables in DATA then set your primary filegroup. That way when a developer just creates a table and doesn’t think to change the default (and really, how often do you really specify the filegroup when creating a basic table?) it still goes in the correct place.

Rate

Share

Share

Rate

Related content

Database Mirroring FAQ: Can a 2008 SQL instance be used as the witness for a 2005 database mirroring setup?

Question: Can a 2008 SQL instance be used as the witness for a 2005 database mirroring setup? This question was sent to me via email. My reply follows. Can a 2008 SQL instance be used as the witness for a 2005 database mirroring setup? Databases to be mirrored are currently running on 2005 SQL instances but will be upgraded to 2008 SQL in the near future.

Robert Davis

2009-02-23

1,567 reads

Networking – Part 4

You may want to read Part 1 , Part 2 , and Part 3 before continuing. This time around I’d like to talk about social networking. We’ll start with social networking. Facebook, MySpace, and Twitter are all good examples of using technology to let…

Andy Warren

2009-02-17

1,530 reads

Speaking at Community Events – More Thoughts

Last week I posted Speaking at Community Events – Time to Raise the Bar?, a first cut at talking about to what degree we should require experience for speakers at events like SQLSaturday as well as when it might be appropriate to add additional focus/limitations on the presentations that are accepted. I’ve got a few more thoughts on the topic this week, and I look forward to your comments.

Andy Warren

2009-02-13

360 reads