分类: SQLServer
2013-03-06 14:31:11
--Table/Index creation CREATE TABLE [dbo].[TABLE1] ([pkcol] [int] NOT NULL, [datacol1] [int] NULL, [datacol2] [int] NULL, [datacol3] [varchar](50) NULL, [partitioncol] datetime) GO ALTER TABLE dbo.TABLE1 ADD CONSTRAINT PK_TABLE1 PRIMARY KEY CLUSTERED (pkcol) GO CREATE NONCLUSTERED INDEX IX_TABLE1_col2col3 ON dbo.TABLE1 (datacol1,datacol2) WITH (STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO -- Populate table data DECLARE @val INT SELECT @val=1 WHILE @val < 1000 BEGIN INSERT INTO dbo.Table1(pkcol, datacol1, datacol2, datacol3, partitioncol) VALUES (@val,@val,@val,'TEST',getdate()-@val) SELECT @val=@val+1 END GO通过查看sys.partitions系统视图,上面的代码创建了一个传统的单分区表.
SELECT o.name objectname,i.name indexname, partition_id, partition_number, [rows] FROM sys.partitions p INNER JOIN sys.objects o ON o.object_id=p.object_id INNER JOIN sys.indexes i ON i.object_id=p.object_id and p.index_id=i.index_id WHERE o.name LIKE '%TABLE1%'
objectname |
indexname |
partition_id |
partition_number |
rows |
---|---|---|---|---|
TABLE1 | PK_TABLE1 | 72057594042712064 | 1 | 999 |
TABLE1 | IX_TABLE1_col2col3 | 72057594042777600 | 1 | 999 |
CREATE PARTITION FUNCTION myDateRangePF (datetime) AS RANGE RIGHT FOR VALUES ('20110101', '20120101','20130101') GO CREATE PARTITION SCHEME myPartitionScheme AS PARTITION myDateRangePF ALL TO ([PRIMARY]) GO SELECT ps.name,pf.name,boundary_id,value FROM sys.partition_schemes ps INNER JOIN sys.partition_functions pf ON pf.function_id=ps.function_id INNER JOIN sys.partition_range_values prf ON pf.function_id=prf.function_id现在我们有一个分区方案,可对表进行分区操作. 既然我们想通过聚集索引来对一个创建了聚集索引的表进行分区,我们需要先删除掉这个索引并通过一个非聚集索引重建这个约束. 若这张表没有聚集索引,我们可忽略这一步,直接执行语句. 类似地,若有一个聚集索引创建在分区字段上,我们可执行带DROP_EXISTING的语句. 最后,若关注于执行此任务时数据库停止服务时间并且你使用的是SQL Server企业版本,可通过的ONLINE=ON选项来使数据库的停止服务时间最小. 记住,在使用ONLINE选项重建索引时,你可能会看到一些性能降低的现象. 这里是一些可能会乃至的脚本.
ALTER TABLE dbo.TABLE1 DROP CONSTRAINT PK_TABLE1 GO ALTER TABLE dbo.TABLE1 ADD CONSTRAINT PK_TABLE1 PRIMARY KEY NONCLUSTERED (pkcol) WITH (STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO CREATE CLUSTERED INDEX IX_TABLE1_partitioncol ON dbo.TABLE1 (partitioncol) WITH (STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON myPartitionScheme(partitioncol) GO在这些语句结束后,我们可再次查看sys.partitions系统视图(看上面的代码)并确认我们的表有4个分区.
objectname |
indexname |
partition_id |
partition_number |
rows |
---|---|---|---|---|
TABLE1 | IX_TABLE1_partitioncol | 72057594043039744 | 1 | 233 |
TABLE1 | IX_TABLE1_partitioncol | 72057594043105280 | 2 | 365 |
TABLE1 | IX_TABLE1_partitioncol | 72057594043170816 | 3 | 366 |
TABLE1 | IX_TABLE1_partitioncol | 72057594043236352 | 4 | 35 |
TABLE1 | IX_TABLE1_col2col3 | 72057594043301888 | 1 | 999 |
TABLE1 | PK_TABLE1 | 72057594043367424 | 1 | 999 |
--cleanup DROP TABLE TABLE1 DROP PARTITION SCHEME myPartitionScheme DROP PARTITION FUNCTION myDateRangePF其它步骤: