By using this site, you agree to our updated Privacy Policy and our Terms of Use. Manage your Cookies Settings.
424,833 Members | 2,067 Online
Bytes IT Community
+ Ask a Question
Need help? Post your question and get tips & solutions from a community of 424,833 IT Pros & Developers. It's quick & easy.

Table partitioning in V8.2

P: n/a
DB2 V8.2 (not Viper yet and no range partitioning!!)
I have created a table T1 (col1, col2) with col1 as the primary key.
When I try to create a partitioning key on col2, it gives me error that it
should have all primary keys included.

So, I created table T1 again with col2 as the partitioning key.
Now, I do not have col1 as the primary key.
When I try to create col1 as the primary key, I get the following error:
1 The primary key, each unique constraint, and each unique index
must contain all partitioning columns of the table (columns may
appear in any order).

Also, what are the other considerations that I should see before
partitioning? I am creating the above table in a SMS tablespace.

Is there any way to identify the particular partition with a name or
something?

Please let me know.... am a newbie to this partitioning thing.

Cheers,
San.

Jul 26 '06 #1
Share this Question
Share on Google+
10 Replies


P: n/a
shsandeep wrote:
DB2 V8.2 (not Viper yet and no range partitioning!!)
I have created a table T1 (col1, col2) with col1 as the primary key.
When I try to create a partitioning key on col2, it gives me error that it
should have all primary keys included.
The partitioning key needs to contain the primary key so that if you
try to insert a row with a duplicate value for the primary key, it is
guaranteed to be routed to the partition/node in the system that
already has the existing row with that primary key.

e.g. Say you have T1 (col1, col2) with primary key (col1) and
partitioning key (col1). Suppose you have a row (1, 1) in the table, on
node 4 (just to make up a node number). Then if you try to insert the
row (1, 2) it is sent to node 4 (because that's where a value of 1 for
col1 was hashed to before, it will always be hashed to node 4). Then,
the DB2 subagent process on node 4 will detect that you're trying to
insert a duplicate value and return an error.

If DB2 did not have this restriction, any INSERT into a partitioned
table might need to check with every node for each row to make sure it
is not a duplicate. As it is, an INSERT of many rows can be split up,
and each node can check for duplicate values for the primary key in
parallel.

It sounds like you really want your primary key to be col1. Maybe a
partitioning key of (col1) or (col1,col2) would work for your needs?

Jul 26 '06 #2

P: n/a
Thanks Harold for your reply.
When I try to create a partioning key on (col1,col2) it gives me the
following error:
SQL0270N Function not supported (Reason code = "1
").

Explanation:

The statement cannot be processed because it violates a
restriction as indicated by the following reason code:
1 The primary key, each unique constraint, and each unique index
must contain all partitioning columns of the table (columns may
appear in any order).

I have defined col1 as the primary key.

Cheers,
San.

Jul 26 '06 #3

P: n/a
Forgot to mention this:
It is a single partitioned database. Am wondering as to how this will help
in any manner.

Cheers,
San.

Jul 26 '06 #4

P: n/a
shsandeep wrote:
Forgot to mention this:
It is a single partitioned database. Am wondering as to how this will help
in any manner.
? Why are you bothering with partitioning keys then ?
You only need partitioning keys if you use DPF.
If you are simply developing for a DPF system that development and test
system should also be DPF.

Cheers
Serge
--
Serge Rielau
DB2 Solutions Development
IBM Toronto Lab

IOD Conference
http://www.ibm.com/software/data/ond...ness/conf2006/
Jul 26 '06 #5

P: n/a
shsandeep wrote:
Thanks Harold for your reply.
When I try to create a partioning key on (col1,col2) it gives me the
following error:
SQL0270N Function not supported (Reason code = "1
").

Explanation:

The statement cannot be processed because it violates a
restriction as indicated by the following reason code:
1 The primary key, each unique constraint, and each unique index
must contain all partitioning columns of the table (columns may
appear in any order).

I have defined col1 as the primary key.
The partitioning key must be a subset of the PK. (col1, col2) is not a
subset of (col1). Hence, the error message...

--
Knut Stolze
DB2 Information Integration Development
IBM Germany
Jul 26 '06 #6

P: n/a
Knut Stolze wrote:
shsandeep wrote:
Thanks Harold for your reply.
When I try to create a partioning key on (col1,col2) it gives me the
following error:
SQL0270N Function not supported (Reason code = "1
").

Explanation:

The statement cannot be processed because it violates a
restriction as indicated by the following reason code:
1 The primary key, each unique constraint, and each unique index
must contain all partitioning columns of the table (columns may
appear in any order).

I have defined col1 as the primary key.

The partitioning key must be a subset of the PK. (col1, col2) is not a
subset of (col1). Hence, the error message...

--
Knut Stolze
DB2 Information Integration Development
IBM Germany
All the literature states (as does Knut) that the Partitioning key
must be a subset of any uniq, primary keys etc. Is it also valid for
the partitioning key make-up to be identical to the column(s) of a
uniq or Prim Key also? i.e. Pr/UNIQ Key col(s)>= Partitioning key
col(s). Can they be identical, with an EQUAL number of columns? Is that
also valid? Does superset mean "contains all Part Key col(s), and a
column more", or does it mean "contains at least all Partitioning Key
columns...and may optionally contain more columns, as required"
Thanks
wombat53

Jul 27 '06 #7

P: n/a
So, does it mean that I have to change my Primary key from (col1) to
(col1,col2) ?
The other way could be to have only col1 as my partitioning key but that
does not seem to give me too much advantage as compared to if the
partitioning key is (col1,col2).

Cheers,
San.

Jul 27 '06 #8

P: n/a
wombat53 wrote:
All the literature states (as does Knut) that the Partitioning key
must be a subset of any uniq, primary keys etc. Is it also valid for
the partitioning key make-up to be identical to the column(s) of a
uniq or Prim Key also? i.e. Pr/UNIQ Key col(s)>= Partitioning key
col(s). Can they be identical, with an EQUAL number of columns? Is that
also valid?
Yes, the partitioning key can be identical to the primary key.
Does superset mean "contains all Part Key col(s), and a
column more", or does it mean "contains at least all Partitioning Key
columns...and may optionally contain more columns, as required"
I used the terms "subset" and "superset" in the mathematical sense, i.e. a
set is always a subset of itself (but not a proper or strict subset). So
yes, the partitioning key as a subset of the columns of the primary key can
be identical to the primary key.

The thing with the partitioning key is this: The verification for the
uniqueness of the primary key or any unique key is done locally on each
node. A row is taken, its partition determined and then the row is send to
the partition on which it is to be stored. There, the row is inserted into
the table and the index maintained (locally on the partition). For unique
constraints (a PK is just that), the uniqueness is ensured on based on the
data on the partition only, i.e. the partial index on the partition must
suffice to find possible duplicates or to make sure that there is no
duplicate. With such an approach, it is mandatory that all potential
duplicates are always stored on the same partition. Otherwise, the columns
in the partitioning key could have different values in different rows,
leading to the rows being distributed to different partitions. That can
only be ensured if the partitioning key is a part of _all_ unique
constraints/indexes.

If you have multiple independent unique constraints, you'll have to resort
to other mechanisms. For example, you could ensure uniqueness in a trigger
for those unique constraints that cannot be created due to the partitioning
key. (A non-unique index on those columns may be a good idea then.)

--
Knut Stolze
DB2 Information Integration Development
IBM Germany
Jul 27 '06 #9

P: n/a
shsandeep wrote:
So, does it mean that I have to change my Primary key from (col1) to
(col1,col2) ?
Or change the partitioning key to "col1"
The other way could be to have only col1 as my partitioning key but that
does not seem to give me too much advantage as compared to if the
partitioning key is (col1,col2).
It depends on what you want to do.

--
Knut Stolze
DB2 Information Integration Development
IBM Germany
Jul 27 '06 #10

P: n/a

Knut Stolze wrote:
wombat53 wrote:
All the literature states (as does Knut) that the Partitioning key
must be a subset of any uniq, primary keys etc. Is it also valid for
the partitioning key make-up to be identical to the column(s) of a
uniq or Prim Key also? i.e. Pr/UNIQ Key col(s)>= Partitioning key
col(s). Can they be identical, with an EQUAL number of columns? Is that
also valid?

Yes, the partitioning key can be identical to the primary key.
Does superset mean "contains all Part Key col(s), and a
column more", or does it mean "contains at least all Partitioning Key
columns...and may optionally contain more columns, as required"

I used the terms "subset" and "superset" in the mathematical sense, i.e. a
set is always a subset of itself (but not a proper or strict subset). So
yes, the partitioning key as a subset of the columns of the primary key can
be identical to the primary key.

The thing with the partitioning key is this: The verification for the
uniqueness of the primary key or any unique key is done locally on each
node. A row is taken, its partition determined and then the row is send to
the partition on which it is to be stored. There, the row is inserted into
the table and the index maintained (locally on the partition). For unique
constraints (a PK is just that), the uniqueness is ensured on based on the
data on the partition only, i.e. the partial index on the partition must
suffice to find possible duplicates or to make sure that there is no
duplicate. With such an approach, it is mandatory that all potential
duplicates are always stored on the same partition. Otherwise, the columns
in the partitioning key could have different values in different rows,
leading to the rows being distributed to different partitions. That can
only be ensured if the partitioning key is a part of _all_ unique
constraints/indexes.

If you have multiple independent unique constraints, you'll have to resort
to other mechanisms. For example, you could ensure uniqueness in a trigger
for those unique constraints that cannot be created due to the partitioning
key. (A non-unique index on those columns may be a good idea then.)

--
Knut Stolze
DB2 Information Integration Development
IBM Germany
Knut - you have precisely answered my question.
Many thanks
wombat53

Jul 27 '06 #11

This discussion thread is closed

Replies have been disabled for this discussion.