Voici une requête permettant de savoir pour chaque ligne d’une table partitionnée ou elle se situe.
La requête suppose que :
– la table partitionnée est de nom « S_CHB.T_FACTURE_FAC »
– la colonne de partitionnement est FAC_DATE
– la fonction de partitionnement est PF_DATE_FACTURE
WITH T AS
(
SELECT *, $PARTITION.PF_DATE_FACTURE(FAC_DATE) AS "PARTITION"
FROM S_CHB.T_FACTURE_FAC AS f
)
SELECT T.*, fs.name AS FILEGROUP_NAME,
f.name AS FILE_NAME,
f.physical_name
FROM T
JOIN sys.partitions AS p
ON p.object_id = OBJECT_ID('S_CHB.T_FACTURE_FAC')
AND T."PARTITION" = p.partition_number
AND index_id = 0
JOIN sys.allocation_units AS au
ON p.hobt_id = au.container_id
JOIN sys.filegroups AS fs
ON au.data_space_id = fs.data_space_id
JOIN sys.database_files AS f
ON fs.data_space_id = f.file_id;
(
SELECT *, $PARTITION.PF_DATE_FACTURE(FAC_DATE) AS "PARTITION"
FROM S_CHB.T_FACTURE_FAC AS f
)
SELECT T.*, fs.name AS FILEGROUP_NAME,
f.name AS FILE_NAME,
f.physical_name
FROM T
JOIN sys.partitions AS p
ON p.object_id = OBJECT_ID('S_CHB.T_FACTURE_FAC')
AND T."PARTITION" = p.partition_number
AND index_id = 0
JOIN sys.allocation_units AS au
ON p.hobt_id = au.container_id
JOIN sys.filegroups AS fs
ON au.data_space_id = fs.data_space_id
JOIN sys.database_files AS f
ON fs.data_space_id = f.file_id;
La mise en place du partitionnement pour cette table a été la suivante :
-- création de la fonction de partitionnement :
CREATE PARTITION FUNCTION PF_DATE_FACTURE (datetime)
AS RANGE RIGHT
FOR VALUES ( '20070101', '20080101');
-- création des espace de stockage pour les différentes partitions
ALTER DATABASE [DB_GRAND_HOTEL]
ADD FILEGROUP FG_PART_OLD;
ALTER DATABASE [DB_GRAND_HOTEL]
ADD FILEGROUP FG_PART_2007;
ALTER DATABASE [DB_GRAND_HOTEL]
ADD FILEGROUP FG_PART_2008;
ALTER DATABASE [DB_GRAND_HOTEL]
ADD FILE
(NAME = 'F_PART_OLD',
FILENAME = 'C:\temp\F_PART_OLD.ndf',
SIZE = 250 MB,
FILEGROWTH = 50 MB
)
TO FILEGROUP FG_PART_OLD;
ALTER DATABASE [DB_GRAND_HOTEL]
ADD FILE
(NAME = 'F_PART_2007',
FILENAME = 'C:\temp\F_PART_2007.ndf',
SIZE = 250 MB,
FILEGROWTH = 50 MB
)
TO FILEGROUP FG_PART_2007;
ALTER DATABASE [DB_GRAND_HOTEL]
ADD FILE
(NAME = 'F_PART_2008',
FILENAME = 'C:\temp\F_PART_2008.ndf',
SIZE = 250 MB,
FILEGROWTH = 50 MB
)
TO FILEGROUP FG_PART_2008;
-- création du schéma de ventilation des partitions
CREATE PARTITION SCHEME PS_DATE_FACTURE
AS PARTITION PF_DATE_FACTURE
TO (FG_PART_OLD, FG_PART_2007, FG_PART_2008);
CREATE PARTITION FUNCTION PF_DATE_FACTURE (datetime)
AS RANGE RIGHT
FOR VALUES ( '20070101', '20080101');
-- création des espace de stockage pour les différentes partitions
ALTER DATABASE [DB_GRAND_HOTEL]
ADD FILEGROUP FG_PART_OLD;
ALTER DATABASE [DB_GRAND_HOTEL]
ADD FILEGROUP FG_PART_2007;
ALTER DATABASE [DB_GRAND_HOTEL]
ADD FILEGROUP FG_PART_2008;
ALTER DATABASE [DB_GRAND_HOTEL]
ADD FILE
(NAME = 'F_PART_OLD',
FILENAME = 'C:\temp\F_PART_OLD.ndf',
SIZE = 250 MB,
FILEGROWTH = 50 MB
)
TO FILEGROUP FG_PART_OLD;
ALTER DATABASE [DB_GRAND_HOTEL]
ADD FILE
(NAME = 'F_PART_2007',
FILENAME = 'C:\temp\F_PART_2007.ndf',
SIZE = 250 MB,
FILEGROWTH = 50 MB
)
TO FILEGROUP FG_PART_2007;
ALTER DATABASE [DB_GRAND_HOTEL]
ADD FILE
(NAME = 'F_PART_2008',
FILENAME = 'C:\temp\F_PART_2008.ndf',
SIZE = 250 MB,
FILEGROWTH = 50 MB
)
TO FILEGROUP FG_PART_2008;
-- création du schéma de ventilation des partitions
CREATE PARTITION SCHEME PS_DATE_FACTURE
AS PARTITION PF_DATE_FACTURE
TO (FG_PART_OLD, FG_PART_2007, FG_PART_2008);
Création de la table partitionnée :
CREATE TABLE S_CHB.T_FACTURE_FAC
(
FAC_ID INT IDENTITY(1,1) NOT NULL,
PMT_ID INT NOT NULL,
PRS_ID INT NOT NULL,
FAC_DATE DATETIME NOT NULL,
FAC_REMISE_GLOBALE FLOAT NULL
) ON PS_DATE_FACTURE(FAC_DATE)
GO
ALTER TABLE S_CHB.T_FACTURE_FAC
ADD CONSTRAINT PK_FAC
PRIMARY KEY NONCLUSTERED (FAC_ID)
ON GF_INDX;
GO
(
FAC_ID INT IDENTITY(1,1) NOT NULL,
PMT_ID INT NOT NULL,
PRS_ID INT NOT NULL,
FAC_DATE DATETIME NOT NULL,
FAC_REMISE_GLOBALE FLOAT NULL
) ON PS_DATE_FACTURE(FAC_DATE)
GO
ALTER TABLE S_CHB.T_FACTURE_FAC
ADD CONSTRAINT PK_FAC
PRIMARY KEY NONCLUSTERED (FAC_ID)
ON GF_INDX;
GO
Frédéric Brouard, alias SQLpro, ARCHITECTE DE DONNÉES
Expert S.G.B.D relationnelles et langage S.Q.L
Moste Valuable Professionnal Microsoft SQL Server
Société SQLspot : modélisation, conseil, formation,
optimisation, audit, tuning, administration SGBDR
Enseignant: CNAM PACA, ISEN Toulon, CESI Aix en Prov.
Expert S.G.B.D relationnelles et langage S.Q.L
Moste Valuable Professionnal Microsoft SQL Server
Société SQLspot : modélisation, conseil, formation,
optimisation, audit, tuning, administration SGBDR
Enseignant: CNAM PACA, ISEN Toulon, CESI Aix en Prov.
L’entreprise SQL Spot
Le site web sur le SQL et les SGBDR