x

SQL 2008 Table Partitioning

Hello,

I am using Table Partitioning in SQL 2008, I created a partitioned function right boundary, a partitioned scheme and a partitioning column (datetime) in a way that I have 12 partitions and 13 filegroups (12 for each month of the year and 1 additional filegroup).

Is there a way to create a script that I can run once a year that creates 12 new partitions on 12 new filegroups and set the boundary for each partition as a new month for a new year? i.e. create 12 new partitions per year

Regards,

Joe

more ▼

asked Nov 09, 2009 at 10:52 AM in Default

Joe Wazen gravatar image

Joe Wazen
23 2 2 2

(comments are locked)
10|1200 characters needed characters left

1 answer: sort voted first

This isn't going to be exactly what you want, but it will certainly get you started:

DECLARE @path varchar SET @path = 'D:\Database_Data' -- Loop from 1 to 12 DECLARE @x int SET @x = 1 WHILE @x <= 12 BEGIN

DECLARE @newdate [datetime], @newDateString varchar SET @newdate = DATEADD(m, @x, GETDATE()) SET @newDateString = CONVERT([varchar], YEAR(@newDate)) + RIGHT('00' + CONVERT([varchar], MONTH(@newDate)), 2)

-- create filegroup
PRINT 'ALTER DATABASE [' + DB_NAME() + '] ADD FILEGROUP [PARTITION_DATA_' + @newDateString + ']'  
PRINT 'GO' -- create file in filegroup PRINT 'ALTER DATABASE [' + DB_NAME() + '] ADD FILE (' PRINT ' NAME = ''PARTITION_DATA_' + @newDateString + ',' PRINT ' FILENAME = ''' + @path + db_name() + '_PARTITION_DATA_' + @newDateString + '.ndf'')' PRINT 'TO FILEGROUP [PARTITION_DATA_' + @newDateString + ']' PRINT 'GO' -- SET NEXT USED for partition scheme PRINT 'ALTER PARTITION SCHEME [MonthPartitions] NEXT USED [PARTITION_DATA_' + @newDateString + ']' PRINT 'GO' -- Now add boundary value to partition function PRINT 'ALTER PARTITION FUNCTION [MonthPartitionFunction] SPLIT RANGE ( ''' + CONVERT([varchar], YEAR(@newDate)) + '/' + RIGHT('00' + CONVERT([varchar], MONTH(@newDate)), 2) + '/01'' )' PRINT 'GO' SET @x = @x + 1 END
more ▼

answered Nov 09, 2009 at 12:26 PM

Matt Whitfield gravatar image

Matt Whitfield ♦♦
29.4k 61 65 87

Well Matt thanks a lot mate that's exactly what i want. once again thanks for the reply
Nov 10, 2009 at 03:55 AM Joe Wazen
(comments are locked)
10|1200 characters needed characters left
Your answer
toggle preview:

Up to 2 attachments (including images) can be used with a maximum of 524.3 kB each and 1.0 MB total.

New code box

There's a new way to format code on the site - the red speech bubble logo will automatically format T-SQL for you. The original code box is still there for XML, etc. More details here.

Follow this question

By Email:

Once you sign in you will be able to subscribe for any updates here

By RSS:

Answers

Answers and Comments

SQL Server Central

Need long-form SQL discussion? SQLserverCentral.com is the place.

Topics:

x1834
x51

asked: Nov 09, 2009 at 10:52 AM

Seen: 1865 times

Last Updated: Nov 09, 2009 at 11:54 AM