This is the third of a series of five articles that examine the challenges posed by typical queries on the journal line table (PS_JRNL_LN).
PeopleSoft does not partition tables by default. Application Designer does not support partitioning, mainly because different databases implement partitioning differently. Thus, it is always left to the customer to implement as a customisation. In this article, I am only going to discuss partitioning on Oracle.
Interval Partitioning
This is the sample query that I started with.
SELECT A.FISCAL_YEAR, A.ACCOUNTING_PERIOD, B.BUSINESS_UNIT, B.JOURNAL_ID, TO_CHAR(B.JOURNAL_DATE,'YYYY-MM-DD'), B.LEDGER, B.ACCOUNT
, B.PRODUCT, B.PROJECT_ID, B.CHARTFIELD1, B.CHARTFIELD2, B.CURRENCY_CD, B.AFFILIATE, SUM( B.MONETARY_AMOUNT), B.FOREIGN_CURRENCY
, SUM( B.FOREIGN_AMOUNT), A.REVERSAL_CD, A.REVERSAL_ADJ_PER, A.JRNL_HDR_STATUS, TO_CHAR(A.POSTED_DATE,'YYYY-MM-DD'), A.OPRID, A.DESCR254
, B.DEPTID, A.SOURCE, B.ALTACCT, TO_CHAR(CAST((A.DTTM_STAMP_SEC) AS TIMESTAMP),'YYYY-MM-DD-HH24.MI.SS.FF'), B.LINE_DESCR
FROM PS_JRNL_HEADER A, PS_JRNL_LN B
WHERE (A.BUSINESS_UNIT = B.BUSINESS_UNIT
AND A.JOURNAL_ID = B.JOURNAL_ID
AND A.JOURNAL_DATE = B.JOURNAL_DATE
AND A.UNPOST_SEQ = B.UNPOST_SEQ
AND A.JRNL_HDR_STATUS IN('P','V','U')
AND A.FISCAL_YEAR IN (2024)
AND A.ACCOUNTING_PERIOD BETWEEN 1 AND 12
AND B.CHARTFIELD1 IN ('1234567','1234568','1234569')
AND B.LEDGER IN ('LEDGER'))
GROUP BY A.FISCAL_YEAR, A.ACCOUNTING_PERIOD, B.BUSINESS_UNIT, B.JOURNAL_ID, B.JOURNAL_DATE, B.LEDGER, B.ACCOUNT, B.PRODUCT
, B.PROJECT_ID, B.CHARTFIELD1, B.CHARTFIELD2, B.CURRENCY_CD, B.AFFILIATE, B.FOREIGN_CURRENCY, A.REVERSAL_CD, A.REVERSAL_ADJ_PER
, A.JRNL_HDR_STATUS, A.POSTED_DATE, A.OPRID, A.DESCR254, B.DEPTID, A.SOURCE, B.ALTACCT, A.DTTM_STAMP_SEC, B.LINE_DESCR
It would have been desirable to have been able to partition PS_JRNL_LN by FISCAL_YEAR. However, that column is only present on the parent table, PS_JRNL_HEADER. Oracle can do referential partitioning, where the child table is partitioned by an attribute of a column in the parent table. The parent table must also be partitioned similarly, thus producing a 1:1 mapping of partitions between the parent and child tables. However, this feature also requires the presence of an enforced foreign key constraint between parent and child tables.
PeopleSoft has never implemented or supported database-enforced referential integrity constraints (again, mainly because it was done differently on different databases). Although it is tempting to add a foreign key constraint between these tables, that would be a customisation to PeopleSoft that Oracle would not support. The application would then have to insert parent rows before child rows and delete child rows before deleting parent rows. It has never been tested against these constraints.
Therefore, it is only possible to consider partitioning by a column on PS_JRNL_LN. A column in the unique key is an obvious choice.
- Depending on how BUSINESS_UNIT is set up and used, you might be able to list sub-partition by this column, and split journal lines down into several subpartitions. However, it is almost inevitable that the volumes will be heavily skewed.
- It is tempting to range partition on JOURNAL_ID. Although this column usually contains an entirely numeric value, it is in fact defined as a character (VARCHAR2) data type. Therefore, it is not possible to interval partition upon it. Periodically, it would be necessary to add partitions manually.
- The alternative is to interval range partition on JOURNAL_DATE. I chose to define a monthly interval. I specified the first few partitions for whole years because at this customer, these partitions contained less data after archiving. Thereafter, Oracle automatically creates monthly partitions as data is inserted.
CREATE TABLE PS_JRNL_LN
(BUSINESS_UNIT VARCHAR2(5 CHAR) NOT NULL
,JOURNAL_ID VARCHAR2(10 CHAR) NOT NULL
,JOURNAL_DATE DATE NOT NULL
,UNPOST_SEQ NUMBER(*,0) NOT NULL
,JOURNAL_LINE NUMBER(9,0) NOT NULL
,LEDGER VARCHAR2(10 CHAR) NOT NULL
...
) PARTITION BY RANGE (JOURNAL_DATE) INTERVAL (NUMTOYMINTERVAL(1, 'MONTH'))
(PARTITION JRNL_LN_2016 VALUES LESS THAN (TO_DATE('2017-01-01', 'YYYY-MM-DD'))
,PARTITION JRNL_LN_2017 VALUES LESS THAN (TO_DATE('2018-01-01', 'YYYY-MM-DD'))
,PARTITION JRNL_LN_2018 VALUES LESS THAN (TO_DATE('2019-01-01', 'YYYY-MM-DD'))
,PARTITION JRNL_LN_2019 VALUES LESS THAN (TO_DATE('2020-01-01', 'YYYY-MM-DD'))
)
/
Renaming Partitions
rem rename_jrnl_ln_partitions.sql
rem requires https://github.com/davidkurtz/psscripts/blob/master/psftapi.sql
spool rename_jrnl_ln_partitions.lst
set serveroutput on
DECLARE
l_high_value DATE;
l_sql CLOB;
l_new_partition_name VARCHAR2(30);
BEGIN
psft_ddl_lock.set_ddl_permitted(TRUE);
FOR i IN (
select /*+LEADING(r upt upkc utc)*/ r.recname, upt.table_name, utp.partition_name, utp.high_value, upt.interval interval_size
from sysadm.psrecdefn r
INNER JOIN user_part_tables upt ON upt.table_name = DECODE(r.sqltablename,' ','PS_'||r.recname,r.sqltablename)
AND upt.partitioning_type = 'RANGE' and upt.interval IS NOT NULL
INNER JOIN user_part_key_columns upkc ON upkc.name = upt.table_name AND upkc.object_Type = 'TABLE' and upkc.column_position = 1
INNER JOIN user_tab_columns utc ON utc.table_name = upkc.name AND utc.column_name = upkc.column_name
INNER JOIN user_tab_partitions utp ON utp.table_name = upt.table_name AND utp.partition_name like 'SYS_P%'
WHERE r.recname = 'JRNL_LN' AND r.rectype = 0
AND (utc.data_type = 'DATE' OR utc.data_type like 'TIMESTAMP%')
) LOOP
l_sql := 'SELECT '||i.high_value||'-'||i.interval_size||' FROM DUAL';
EXECUTE IMMEDIATE l_sql INTO l_high_value;
l_new_partition_name := i.recname||'_'||TO_CHAR(l_high_value,'YYYYMM');
l_sql := 'ALTER TABLE '||i.table_name||' RENAME PARTITION '||i.partition_name||' TO '||l_new_partition_name;
IF i.partition_name != l_new_partition_name THEN
dbms_output.put_line(l_sql);
EXECUTE IMMEDIATE l_sql;
END IF;
END LOOP;
FOR i IN (
select /*+LEADING(r upi upkc utc)*/ r.recname, upi.index_name, uip.partition_name, uip.high_value, upi.interval interval_size
from sysadm.psrecdefn r
INNER JOIN user_part_indexes upi ON upi.table_name = DECODE(r.sqltablename,' ','PS_'||r.recname,r.sqltablename)
AND upi.partitioning_type = 'RANGE' and upi.interval IS NOT NULL
INNER JOIN user_part_key_columns upkc ON upkc.name = upi.index_name AND upkc.object_Type = 'INDEX' and upkc.column_position = 1
INNER JOIN user_tab_columns utc ON utc.table_name = upi.table_name AND utc.column_name = upkc.column_name
INNER JOIN user_ind_partitions uip ON uip.index_name = upi.index_name
AND (uip.partition_name like 'SYS_P%' OR SUBSTR(uip.partition_name,1+LENGTH(r.recname),1) != SUBSTR(upi.index_name,3,1))
WHERE r.recname = 'JRNL_LN' AND r.rectype = 0
AND (utc.data_type = 'DATE' OR utc.data_type like 'TIMESTAMP%')
) LOOP
l_sql := 'SELECT '||i.high_value||'-'||i.interval_size||' FROM DUAL';
EXECUTE IMMEDIATE l_sql INTO l_high_value;
l_new_partition_name := i.recname||SUBSTR(i.index_name,3,1)||TO_CHAR(l_high_value,'YYYYMM');
l_sql := 'ALTER INDEX '||i.index_name||' RENAME PARTITION '||i.partition_name||' TO '||l_new_partition_name;
IF i.partition_name != l_new_partition_name THEN
dbms_output.put_line(l_sql);
EXECUTE IMMEDIATE l_sql;
END IF;
END LOOP;
psft_ddl_lock.set_ddl_permitted(FALSE);
END;
/
spool off
No comments :
Post a Comment