If you’re familiar with creating partitioned tables in SQL Server, you might be used to creating a separate filegroup for each partition. This has its benefits, and may very well be the method you would choose in most scenarios.
However, you also have the option of mapping multiple partitions to a single filegroup.
In this article I share two examples of mapping multiple partitions to a single filegroup.
- Example 1 maps all partitions to a single filegroup.
- Example 2 maps some partitions to one filegroup, and some to another.
Example 1 – Map All Partitions to a Single Filegroup
To map all partitions to a single filegroup, use the ALL argument. This specifies that all partitions map to the filegroup specified, or to the primary filegroup if [PRIMARY]
is specified.
Note that when ALL
is specified, only one filegroup can be specified.
-- Create one filegroup
ALTER DATABASE Test ADD FILEGROUP OrdersNewFg1;
GO
ALTER DATABASE Test
ADD FILE
(
NAME = OrdersNewFg1dat,
FILENAME = '/var/opt/mssql/data/OrdersNewFg1dat.ndf',
SIZE = 5MB,
MAXSIZE = 100MB,
FILEGROWTH = 5MB
)
TO FILEGROUP OrdersNewFg1;
GO
-- Create a partition function that will result in twelve partitions
CREATE PARTITION FUNCTION OrdersNewPartitionFunction (date)
AS RANGE RIGHT FOR VALUES (
'20200201',
'20200301',
'20200401',
'20200501',
'20200601',
'20200701',
'20200801',
'20200901',
'20201001',
'20201101',
'20201201'
);
GO
-- Create a partition scheme that maps all partitions to the OrdersNewFg1 filegroup
CREATE PARTITION SCHEME OrdersNewPartitionScheme
AS PARTITION OrdersNewPartitionFunction
ALL TO (OrdersNewFg1);
GO
-- Create a partitioned table
CREATE TABLE OrdersNew (
OrderDate date NOT NULL,
OrderId int IDENTITY NOT NULL,
OrderDesc varchar(255) NOT NULL
)
ON OrdersNewPartitionScheme (OrderDate);
GO
Here, I did the following:
- Created a filegroup and associated file
- Created a partition function
- Created a a partition scheme
- Created a table that uses that partition scheme
The key part is the last line of the CREATE PARTITION SCHEME
statement. Specifically, it’s the ALL
keyword that maps all partitions to the specified filegroup.
If you were mapping them to multiple filegroups, you’d omit ALL
, then have a comma separated list of filegroups instead of just one.
Check the Mapping
We can use the following query to verify that each partition is mapped to the same filegroup.
SELECT
p.partition_number AS [Partition],
fg.name AS [Filegroup],
p.Rows
FROM sys.partitions p
INNER JOIN sys.allocation_units au
ON au.container_id = p.hobt_id
INNER JOIN sys.filegroups fg
ON fg.data_space_id = au.data_space_id
WHERE p.object_id = OBJECT_ID('OrdersNew');
Result:
+-------------+--------------+--------+ | Partition | Filegroup | Rows | |-------------+--------------+--------| | 1 | OrdersNewFg1 | 0 | | 2 | OrdersNewFg1 | 0 | | 3 | OrdersNewFg1 | 0 | | 4 | OrdersNewFg1 | 0 | | 5 | OrdersNewFg1 | 0 | | 6 | OrdersNewFg1 | 0 | | 7 | OrdersNewFg1 | 0 | | 8 | OrdersNewFg1 | 0 | | 9 | OrdersNewFg1 | 0 | | 10 | OrdersNewFg1 | 0 | | 11 | OrdersNewFg1 | 0 | | 12 | OrdersNewFg1 | 0 | +-------------+--------------+--------+
This query also shows us how many rows are in each partition. We haven’t inserted any data so they’re all zero.
Example 2 – Map Some Partitions to a Single Filegroup
This example is almost identical to the previous example, except that we map the twelve partitions across two separate filegroups.
In this case, we omit the ALL
argument, because only one filegroup can be specified when ALL
is specified.
-- Create two filegroups
ALTER DATABASE Test ADD FILEGROUP OrdersNewFg1;
GO
ALTER DATABASE Test
ADD FILE
(
NAME = OrdersNewFg1dat,
FILENAME = '/var/opt/mssql/data/OrdersNewFg1dat.ndf',
SIZE = 5MB,
MAXSIZE = 100MB,
FILEGROWTH = 5MB
)
TO FILEGROUP OrdersNewFg1;
GO
ALTER DATABASE Test ADD FILEGROUP OrdersNewFg2;
GO
ALTER DATABASE Test
ADD FILE
(
NAME = OrdersNewFg2dat,
FILENAME = '/var/opt/mssql/data/OrdersNewFg2dat.ndf',
SIZE = 5MB,
MAXSIZE = 100MB,
FILEGROWTH = 5MB
)
TO FILEGROUP OrdersNewFg2;
GO
-- Create a partition function that will result in twelve partitions
CREATE PARTITION FUNCTION OrdersNewPartitionFunction (date)
AS RANGE RIGHT FOR VALUES (
'20200201',
'20200301',
'20200401',
'20200501',
'20200601',
'20200701',
'20200801',
'20200901',
'20201001',
'20201101',
'20201201'
);
GO
-- Create a partition scheme that maps all partitions to the OrdersNewFg1 filegroup
CREATE PARTITION SCHEME OrdersNewPartitionScheme
AS PARTITION OrdersNewPartitionFunction
TO (
OrdersNewFg1,
OrdersNewFg1,
OrdersNewFg1,
OrdersNewFg1,
OrdersNewFg1,
OrdersNewFg1,
OrdersNewFg2,
OrdersNewFg2,
OrdersNewFg2,
OrdersNewFg2,
OrdersNewFg2,
OrdersNewFg2
);
GO
-- Create a partitioned table
CREATE TABLE OrdersNew (
OrderDate date NOT NULL,
OrderId int IDENTITY NOT NULL,
OrderDesc varchar(255) NOT NULL
)
ON OrdersNewPartitionScheme (OrderDate);
GO
Check the Mapping
Let’s see how the partitions are mapped to the filegroups.
SELECT
p.partition_number AS [Partition],
fg.name AS [Filegroup],
p.Rows
FROM sys.partitions p
INNER JOIN sys.allocation_units au
ON au.container_id = p.hobt_id
INNER JOIN sys.filegroups fg
ON fg.data_space_id = au.data_space_id
WHERE p.object_id = OBJECT_ID('OrdersNew');
Result:
+-------------+--------------+--------+ | Partition | Filegroup | Rows | |-------------+--------------+--------| | 1 | OrdersNewFg1 | 0 | | 2 | OrdersNewFg1 | 0 | | 3 | OrdersNewFg1 | 0 | | 4 | OrdersNewFg1 | 0 | | 5 | OrdersNewFg1 | 0 | | 6 | OrdersNewFg1 | 0 | | 7 | OrdersNewFg2 | 0 | | 8 | OrdersNewFg2 | 0 | | 9 | OrdersNewFg2 | 0 | | 10 | OrdersNewFg2 | 0 | | 11 | OrdersNewFg2 | 0 | | 12 | OrdersNewFg2 | 0 | +-------------+--------------+--------+
As expected, the first six partitions are mapped to the first filegroup, and the remainder are mapped to the second.