Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> RE: Partitioning Quandry

RE: Partitioning Quandry

From: Toepke, Kevin M <ktoepke_at_trilegiant.com>
Date: Tue, 30 Apr 2002 10:24:08 -0800
Message-ID: <F001.00453C4E.20020430102408@fatcity.com>


Thanks to Dennis, I found that partitioning on a concatenated key solves my dilema.

For those who are interested, here is my new partitioning clause:

    PARTITION BY RANGE (invoice_state, update_date) (

        PARTITION inv_active  VALUES LESS THAN
            ('B', TO_DATE('01-jan-9999', 'DD-MON-YYYY'))
            TABLESPACE fins_sml_tbl
       ,PARTITION inv_paid_00 VALUES LESS THAN
            ('P', TO_DATE('01-jan-2001', 'DD-MON-YYYY'))
            TABLESPACE fins_sml_tbl
       ,PARTITION inv_paid_01 VALUES LESS THAN
            ('P', TO_DATE('01-jan-2002', 'DD-MON-YYYY'))
            TABLESPACE fins_sml_tbl
       ,PARTITION inv_paid_02 VALUES LESS THAN
            ('P', TO_DATE('01-jan-2003', 'DD-MON-YYYY'))
            TABLESPACE fins_sml_tbl

The following table shows where records go:
	invoice_state		update_date			partition

'A' does not matter inv_active
'P' < '01-jan-2001' inv_paid_00
'P' < '01-jan-2002' inv_paid_01
'P' < '01-jan-2003' inv_paid_02

The kicker is that when doing concatenated key range partitioning, the first column in the key has to be EQUAL to the value for the 2nd column to be considered!

Caver

-----Original Message-----
Sent: Tuesday, April 30, 2002 12:53 PM
To: Multiple recipients of list ORACLE-L

Kevin - This sounds similar to a partitioning issue that I was able to resolve. My suggestion is to consider partitioning on a concatenated key, INVOICE_STATE, UPDATE_DATE. You'll have to play with it, the partitions don't work the way you think they do. As I recall, if you say "less than 'AL', '01-DEC-02' it will actually partition on values that equal 'AL', but less than '01-DEC-02'. I haven't done dates myself, so I probably have the syntax wrong. The part about sub-partitioning some partitions, should work as well, since your syntax is "less than". If this isn't making sense, email me directly.
Dennis Williams
DBA
Lifetouch, Inc.
dwilliams_at_lifetouch.com

-----Original Message-----
Sent: Tuesday, April 30, 2002 10:04 AM
To: Multiple recipients of list ORACLE-L

here's one for the partitioning gurus out there....

I have an INVOICE table that I want to partition for performance and purging. The way I want to partition it is to do range partitioning on the INVOICE_STATE column, then sub-partition some of the partitions by UPDATE_DATE. The logic behind this is:
1) An invoice may be in sent, but unpaid ("A") state for several months.

2)	We never want to purge off unpaid invoices
3)	After an invoice has been in paid ("P") state for 6 months, we want
to purge the invoice

My basic idea was to have partition-movement enabled and to use a partitioning scheme like the following:
TABLE invoice (

        invoice_id, invoice_state, update_date, ... ) partition by range (invoice_state) (

    partition inv_act values less than 'B'    ,partition inv_hist values less than 'R'

	subpartition by range (update_date) 
		....

);

Alas, you can only subpartition by HASH (or LIST in 9iR2) The only solution I can come up with is a 2 table solution -- keeping the unpaid invoices in one table and the paid invoices in another table that is range partitioned on UPDATE_DATE. The difficulties with this solution are coding the row movements (bi-directional) and having to code a partition-view.

Any suggestions would be helpful.

Kevin Toepke
ktoepke_at_trilegiant.com





The information in this electronic mail message is Trilegiant Confidential and may be legally privileged. It is intended solely for the addressee(s). Access to this Internet electronic mail message by anyone else is unauthorized. If you are not the intended recipient, any disclosure, copying, distribution or action taken or omitted to be taken in reliance on it is prohibited and may be unlawful.



The sender believes that this E-mail and any attachments were free of any virus, worm, Trojan horse, and/or malicious code when sent. This message and its attachments could have been infected during transmission. By reading the message and opening any attachments, the recipient accepts full responsibility for taking protective and remedial action about viruses and other defects. Trilegiant Corporation is not liable for any loss or damage arising in any way from this message or its attachments.


-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: Toepke, Kevin M
  INET: ktoepke_at_trilegiant.com

Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051
San Diego, California        -- Public Internet access / Mailing Lists
--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: DENNIS WILLIAMS
  INET: DWILLIAMS_at_LIFETOUCH.COM

Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051
San Diego, California        -- Public Internet access / Mailing Lists
--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: Toepke, Kevin M
  INET: ktoepke_at_trilegiant.com

Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051
San Diego, California        -- Public Internet access / Mailing Lists
--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).
Received on Tue Apr 30 2002 - 13:24:08 CDT

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US