The default filegroup, and why you should care.

2

February 19, 2018 by Kenneth Fisher

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.

2 thoughts on “The default filegroup, and why you should care.

  1. […] Kenneth Fisher shows how you can change the default filegroup: […]

  2. […] There are two files, one for data and one for the log, the MDF and LDF files. Then there is the default filegroup PRIMARY. But that’s all just the […]

Leave a comment

This site uses Akismet to reduce spam. Learn how your comment data is processed.

Enter your email address to follow this blog and receive notifications of new posts by email.

Join 6,757 other subscribers

Follow me on Twitter

Archives

ToadWorld Pro of the Month November 2013