Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 123»»»

Hash Partitioning Expand / Collapse
Author
Message
Posted Thursday, May 17, 2012 3:48 AM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Thursday, March 06, 2014 11:47 PM
Points: 86, Visits: 214
Hi All,

I am in situation where I am not sure how to divide / Partition the table, and send the Data to Multipple File Group / Files.

So I want to implement the Hash Partition as we do for the Table as we do for the Tables in Oracle.

Please need your pointers.

Thanks & Regards,
Sudhir Nune.
Post #1301588
Posted Thursday, May 17, 2012 8:38 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Wednesday, April 16, 2014 9:25 AM
Points: 7,070, Visits: 12,523
Pick a column in your table and create a persisted computed column off it using the HASHBYTES function:

ALTER TABLE dbo.[TableName]
ADD [HashedColumnName] AS CAST(HASHBYTES('MD5',CAST([ExistingColumnName] AS VARCHAR(40))) AS VARBINARY(40))
PERSISTED -- important, computed column must be persisted to be used a partition column

Creating Partitioned Tables and Indexes


__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato

Believe you can and you're halfway there. --Theodore Roosevelt

Everything Should Be Made as Simple as Possible, But Not Simpler --Albert Einstein

The significant problems we face cannot be solved at the same level of thinking we were at when we created them. --Albert Einstein

1 apple is not exactly 1/8 of 8 apples. Because there are no absolutely identical apples. --Giordy
Post #1301820
Posted Friday, May 18, 2012 6:52 AM


SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: Yesterday @ 7:58 PM
Points: 4,133, Visits: 5,848
I have said it many times before and will say it again. Table Partitioning in SQL Server is a very complex subsystem with lots of requirements, conditions, gotchas, etc. You have very little chance of success if you just read a few forum/blog posts and Books Online and slap it into your system - even if you have extensive Oracle experience. I can't tell you the number of clients and forum people that have gotten themselves into a mess, or at best increased complexity in their system for no benefit, from doing partitioning on their own. And most don't actually NEED partitioning in the first place. Please consider getting a professional on board to help you understand what SQL Server Partitioning is and is not, review your requirements, and move you forward in the best direction successfully.

Best,

Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru at GMail
Post #1302471
Posted Friday, May 18, 2012 7:25 PM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Thursday, March 06, 2014 11:47 PM
Points: 86, Visits: 214
Thanks for the reply, I will try to do as you said.
Post #1302941
Posted Saturday, May 19, 2012 4:57 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 6:47 AM
Points: 41,549, Visits: 34,471
You are highly unlikely to achieve anything other than adding complexity and wasting time. Partitioning is not a performance optimisation (mostly), it's for ease of maintenance, loading and deleting rows.

Partitioning a table so that is it useful requires a careful choice of partitioning column based on the data and the queries, and a semi-random hash is highly unlikely to be useful.

Honestly, don't go this route.



Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1303002
Posted Saturday, May 19, 2012 9:07 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Wednesday, April 16, 2014 9:25 AM
Points: 7,070, Visits: 12,523
GilaMonster (5/19/2012)
You are highly unlikely to achieve anything other than adding complexity and wasting time. Partitioning is not a performance optimisation (mostly), it's for ease of maintenance, loading and deleting rows.

Partitioning a table so that is it useful requires a careful choice of partitioning column based on the data and the queries, and a semi-random hash is highly unlikely to be useful.

Honestly, don't go this route.

What about for tables with no natural partitioning key and a low cardinality on all candidates?


__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato

Believe you can and you're halfway there. --Theodore Roosevelt

Everything Should Be Made as Simple as Possible, But Not Simpler --Albert Einstein

The significant problems we face cannot be solved at the same level of thinking we were at when we created them. --Albert Einstein

1 apple is not exactly 1/8 of 8 apples. Because there are no absolutely identical apples. --Giordy
Post #1303028
Posted Saturday, May 19, 2012 10:06 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 1:13 AM
Points: 35,996, Visits: 30,290
opc.three (5/19/2012)
GilaMonster (5/19/2012)
You are highly unlikely to achieve anything other than adding complexity and wasting time. Partitioning is not a performance optimisation (mostly), it's for ease of maintenance, loading and deleting rows.

Partitioning a table so that is it useful requires a careful choice of partitioning column based on the data and the queries, and a semi-random hash is highly unlikely to be useful.

Honestly, don't go this route.

What about for tables with no natural partitioning key and a low cardinality on all candidates?


I agree with Gail. It won't help for performance and it won't help with maintenance because the hash partitioning would mean that new rows added have just as much likelyhood of being added to one partition as another. It's no better than partitioning on something like NEWID(). IMHO, hash partitioning isn't just a waste of time, it's a move in the wrong direction. You're adding complexity to make things worse. It's kind of like using NEWID() as the clustered index of a table except it's worse.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

"Change is inevitable. Change for the better is not." -- 04 August 2013
(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1303036
Posted Saturday, May 19, 2012 11:09 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Wednesday, April 16, 2014 9:25 AM
Points: 7,070, Visits: 12,523
So would you say this is simply one area where the concept does not transfer from Oracle to SQL Server? Oracle touts partitioning as a way to improve performance by allowing the table 'to be managed and accessed at a finer level of granularity'.

__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato

Believe you can and you're halfway there. --Theodore Roosevelt

Everything Should Be Made as Simple as Possible, But Not Simpler --Albert Einstein

The significant problems we face cannot be solved at the same level of thinking we were at when we created them. --Albert Einstein

1 apple is not exactly 1/8 of 8 apples. Because there are no absolutely identical apples. --Giordy
Post #1303046
Posted Saturday, May 19, 2012 11:58 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 6:47 AM
Points: 41,549, Visits: 34,471
On the point of hash partitioning, correct. If you just want to spread a table over multiple drives, create multiple files in the filegroup and SQL will do it's proportional fill and spread the data without you having to do anything.

Partitioning's great for improved maintenance (rebuilding individual partitions, partition switch for data load or removal), but it requires careful planning and a good knowledge of the data.



Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1303050
Posted Saturday, May 19, 2012 12:04 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 1:13 AM
Points: 35,996, Visits: 30,290
Partioning is a great way to reduce index maintenance. It might even help the performance of certain types of queries. However, and I've not done it in Oracle, I can't see how "hash partitioning" will help anything because of the things I mentioned. It's about as effective as partitioning on NEWID() or any other random number.

[EDIT] The only place I can see where it might help is to spread the load across drives as Gail just mentioned. What would be a much larger help is to fix the data and give it some sort of reasonable partitioning column.

Consider the following example... we have some very easily sortable data that, under normal conditions, would appear in a single partition (say, the "A" partition out of 26 lettered partitions).

SELECT HASHBYTES('SHA1','AAAAA') UNION ALL
SELECT HASHBYTES('SHA1','AABAA') UNION ALL
SELECT HASHBYTES('SHA1','AACAA') UNION ALL
SELECT HASHBYTES('SHA1','AADAA') UNION ALL
SELECT HASHBYTES('SHA1','AAEAA')


Now, if we look at the HASHBYTES output of that, you'll easilly see that having similar data means nothing to HASHBYTES.

0xC1FE3A7B487F66A6AC8C7E4794BC55C31B0EF403
0x9F97773310D994CBEFDB584A0D1883EDBF610B28
0x81778503C0258525DBE9F4D999CCB46EEB25379A
0xE2A9D1EB98CFED14F12629EEF20B1A44B6E4E96A
0x2F45DA2C2D16CCC875CC308C445A070D5957B3B2



There are 5 items and the hashbytes all start with a different character. How is this going to help anything by partitioning? All 5 partitions got updates. That means that 5 indexes also got updated and you still have to go across all 5 partitions to return the 5 pieces of data that start with "AA".


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

"Change is inevitable. Change for the better is not." -- 04 August 2013
(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1303052
« Prev Topic | Next Topic »

Add to briefcase 123»»»

Permissions Expand / Collapse