473,387 Members | 1,876 Online
Bytes | Software Development & Data Engineering Community
Post Job

Home Posts Topics Members FAQ

Join Bytes to post your question to a community of 473,387 software developers and data experts.

Table partitioning in V8.2

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
10 3529
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
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
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
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
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
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
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
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
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

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 thread has been closed and replies have been disabled. Please start a new discussion.

Similar topics

1
by: Girish | last post by:
I have a set of tables partitioned horizontally. DML below. I have also created a view that will allow me to display information stored in all partitioned tables. Im trying to create an INSERT...
18
by: Jeff Boes | last post by:
I'm sure this is a concept that's been explored here. I have a table (fairly simple, just two columns, one of which is a 32-digit checksum) with several million rows (currently, about 7 million)....
0
by: Leonardo Francalanci | last post by:
A couple of days ago I announced that I wrote a JDBC driver that adds table partitioning features to databases accessed via JDBC. I also wrote: > In case you think this could be of any...
1
by: Chessie | last post by:
I'm currently working on Table Partitioning. I have done everything succesfull for partitioning, what I'm struggling with is to use " SELECT MAX(NAME) from sys.filegroups WHERE NAME NOT LIKE...
15
by: Piero 'Giops' Giorgi | last post by:
Hi! I have a question: I already have a DB that uses partitions to divide data in US Counties, partitioned by state. Can I use TWO levels of partitioning? I mean... 3077 filegroups and...
2
by: mandor | last post by:
Hello, I need some advise in table design, and more specifically about table partitioning. I read some papers and there was mentioned that if a table is expected to hold millions of rows, it's a...
2
by: Justin | last post by:
I have set up a test table with range partitioning. The partitions are by date (recdate): 1) Pre-2004 2) 2004 3) 2005 4) 2006 5) 2007 6) 2008 When executing the query: select * from...
0
by: ryjfgjl | last post by:
If we have dozens or hundreds of excel to import into the database, if we use the excel import function provided by database editors such as navicat, it will be extremely tedious and time-consuming...
0
by: ryjfgjl | last post by:
In our work, we often receive Excel tables with data in the same format. If we want to analyze these data, it can be difficult to analyze them because the data is spread across multiple Excel files...
0
BarryA
by: BarryA | last post by:
What are the essential steps and strategies outlined in the Data Structures and Algorithms (DSA) roadmap for aspiring data scientists? How can individuals effectively utilize this roadmap to progress...
1
by: Sonnysonu | last post by:
This is the data of csv file 1 2 3 1 2 3 1 2 3 1 2 3 2 3 2 3 3 the lengths should be different i have to store the data by column-wise with in the specific length. suppose the i have to...
0
by: Hystou | last post by:
There are some requirements for setting up RAID: 1. The motherboard and BIOS support RAID configuration. 2. The motherboard has 2 or more available SATA protocol SSD/HDD slots (including MSATA, M.2...
0
marktang
by: marktang | last post by:
ONU (Optical Network Unit) is one of the key components for providing high-speed Internet services. Its primary function is to act as an endpoint device located at the user's premises. However,...
0
by: Hystou | last post by:
Most computers default to English, but sometimes we require a different language, especially when relocating. Forgot to request a specific language before your computer shipped? No problem! You can...
0
Oralloy
by: Oralloy | last post by:
Hello folks, I am unable to find appropriate documentation on the type promotion of bit-fields when using the generalised comparison operator "<=>". The problem is that using the GNU compilers,...
0
jinu1996
by: jinu1996 | last post by:
In today's digital age, having a compelling online presence is paramount for businesses aiming to thrive in a competitive landscape. At the heart of this digital strategy lies an intricately woven...

By using Bytes.com and it's services, you agree to our Privacy Policy and Terms of Use.

To disable or enable advertisements and analytics tracking please visit the manage ads & tracking page.