Friday, October 06, 2006

SQL Tips for Developers: Performance Improvements with the APPEND hint

In all PeopleSoft products, it is common to find batch programs populating large working storage or reporting tables. When using Oracle RDBMS, the append hint can be used to reduce the overhead and thus improve the performance of the insert operation. Thus

INSERT /*+ APPEND*/ INTO ... SELECT ...

It works by permitting the process to insert the data directly into new data blocks at the end of the object, rather than using space currently allocated to the object. So the new data is appended to the table. This is much faster because it permits Oracle to by-pass some of the processes that occur for each row inserted, such as index maintenance which only occurs when the insert is committed. Significantly, the hint also reduces the volume of redo written.

Every time a piece of data is changed in an Oracle database, the new data is written to the redo logs. This information can then be used to reapply changes to a database during media recovery, or it can be applied to a standby database as a part of a disaster recover solution (Oracle call this technique 'Physical DataGuard'). Every change, even to working storage tables and including indexes, generates redo information.

The reduction in redo can be very significant in systems using DataGuard across a WAN. Bandwidth constraints can cause a backlog of redo information waiting to be transmitted. In most systems the majority of redo is generated by overnight batch processes and it can take time during the day for that backlog to clear and for the DR system to catch up with production. Hence, reducing redo is important.

Therefore the APPEND hint should be used in insert statements when both of the following criteria are met:
  1. The table has been created or truncated prior to the insert. It is not sufficient to delete all the rows because the empty blocks remain allocated to the table.
  2. The table should be populated in a single monolithic insert statement. Multiple statements should be combined using the UNION ALL operator between the queries. Otherwise most of the benefit will be lost during multiple index maintenance phases.
It is easy to demonstrate this with some a simple test. I will create a simple table with a unique index, just as PeopleSoft would. Then I will truncate it and populate it, first without the APPEND hint, and then with it.

CREATE TABLE t
(a NUMBER
,b VARCHAR2(200));

CREATE UNIQUE INDEX t ON t(a);

TRUNCATE TABLE t;
INSERT INTO t
SELECT ROWNUM, RPAD('42',200,'.')
FROM dba_objects;

TRUNCATE TABLE t;
INSERT /*+ APPEND*/ INTO t
SELECT ROWNUM, RPAD('42',200,'.')
FROM dba_objects;

The session statistics show the savings in a number of areas.

Session Stats               No Hint Append Hint
------------------------ ---------- -----------
db block changes 202,926 3,192
db block gets 159,148 4,796
db block gets direct 1,413
db block gets from cache 159,148 3,383
DB time 1,308 828
redo entries 104,842 1,853
redo size 32,391,936 2,838,148

Fewer blocks are changed because they are not written and then rewritten as each row is inserted. Table blocks are only written once during the insert and the index is only maintained when the insert is committed.

Other recommendations:
  • When using the APPEND hint, the insert should be committed immediately. It must be committed before the table can be referenced, otherwise an error will be generated.

  • The data in the table will have been completely replaced by this point, so it is almost certainly appropriate to refresh the optimiser statistics. In Applicaition Engine use the %UpdateStats MetaSQL.

  • The APPEND hint cannot be used in conjuction with the %InsertSelect MetaSQL because the hint MUST be placed between the 'insert' and 'into' keywords. NB: The statement will not fail if you get the hint wrong.

Thursday, August 17, 2006

PeopleTools Platform Flags on Indexes

I have noticed on databases that have been upgraded to PT8.45, that most of the indexes say they will build on some database platforms when they will actually build on either all of them, or none of them.

This is because PSINDEXDEFN still contains flags for platforms that are no longer supported by PeopleSoft/Oracle and can no longer be set individually in Application Designer.
  • PLATFORM_SBS: SQL Base
  • PLATFORM_ALB: Allbase
  • PLATFORM_DB4: DB2/AS400
However, Application Designer still checks the values of these flags and if any flags have different values, then the SOME radio button is selected. However, all six platform flags have the same value.

This is a nuisance because PeopleSoft releases indexes for specific platforms, and some indexes are suppressed on certain platforms. It is not easy to see from the indexes view of Application Designer whether this index will be built. It would be easier if it said ALL or NONE when it means that.

I have fixed this by updating PeopleTools tables as follows. The first query reports on the indexes where the supported platform flags all have the same value and one of the unsupported platform flags are different.

column RECNAME format a15
column INDEXID format a5 heading 'IndexID'
column DDLCOUNT format 999 heading 'DDLCnt'
column CUSTKEYORDER format 9999 heading 'CustKeyOrder'
column KEYCOUNT format 999 heading 'KeyCnt'
column PLATFORM_SBS format 999 heading 'SBS'
column PLATFORM_DB2 format 999 heading 'DB2'
column PLATFORM_ORA format 999 heading 'ORA'
column PLATFORM_INF format 999 heading 'INF'
column PLATFORM_DBX format 999 heading 'DBx'
column PLATFORM_ALB format 999 heading 'ALB'
column PLATFORM_SYB format 999 heading 'SYB'
column PLATFORM_MSS format 999 heading 'MSS'
column PLATFORM_DB4 format 999 heading 'DB4'
column ACTIVEFLAG Format 999 heading 'Active'
column CLUSTERFLAG format 999 heading 'ClustFlag'
column UNIQUEFLAG format 999 heading 'UniqueFlag'
column INDEXTYPE format 999 heading 'IndexType'
column IDXCOMMENTS format a60

spool fixindexdefn
SELECT *
FROM PSINDEXDEFN
WHERE PLATFORM_DB2=PLATFORM_DBX
AND PLATFORM_DBX=PLATFORM_INF
AND PLATFORM_INF=PLATFORM_ORA
AND PLATFORM_ORA=PLATFORM_SYB
AND PLATFORM_SYB=PLATFORM_MSS
AND (PLATFORM_ORA!=PLATFORM_SBS
  OR PLATFORM_ORA!=PLATFORM_ALB
  OR PLATFORM_ORA!=PLATFORM_DB4)
;


                                                 Cust
                Index Index Unique Clust          Key  Key  DDL
RECNAME         ID     Type   Flag  Flag Active Order  Cnt  Cnt  SBS  DB2  ORA  INF  DBx  ALB  SYB  MSS  DB4
--------------- ----- ----- ------ ----- ------ ----- ---- ---- ---- ---- ---- ---- ---- ---- ---- -
IDXCOMMENTS
------------------------------------------------------------
PSGATEWAYDEL    A         4      0     0      1     1    1    0    1    1    1    1    1    1    1    1    0
for clearlisting

PSLOCALEOPTNDFN _         1      1     1      1     0    3    0    1    1    1    1    1    1    1    1    0


PSLOCK          _         1      1     1      1     0    1    0    1    1    1    1    1    1    1    1    0


The following SQL commands set the SQL flags for the unsupported platforms to the value for the supported platforms. The version number on the record definition is updated so that PeopleSoft reaches the object.

UPDATE PSVERSION
SET VERSION = VERSION + 1
WHERE OBJECTTYPENAME IN('SYS','RDM');

UPDATE PSLOCK
SET VERSION = VERSION + 1
WHERE OBJECTTYPENAME IN('SYS','RDM');

UPDATE PSRECDEFN
SET VERSION = (
  SELECT VERSION
  FROM PSVERSION
  WHERE OBJECTTYPENAME = 'RDM')
WHERE RECNAME IN (
  SELECT RECNAME
  FROM PSINDEXDEFN
  WHERE PLATFORM_DB2=PLATFORM_DBX
  AND PLATFORM_DBX=PLATFORM_INF
  AND PLATFORM_INF=PLATFORM_ORA
  AND PLATFORM_ORA=PLATFORM_SYB
  AND ( PLATFORM_ORA!=PLATFORM_SBS
    OR PLATFORM_ORA!=PLATFORM_ALB
    OR PLATFORM_ORA!=PLATFORM_DB4)
);

UPDATE psindexdefn
SET PLATFORM_DB4=PLATFORM_ORA
WHERE PLATFORM_DB2=PLATFORM_DBX
AND PLATFORM_DBX=PLATFORM_INF
AND PLATFORM_INF=PLATFORM_ORA
AND PLATFORM_ORA=PLATFORM_SYB
AND PLATFORM_SYB=PLATFORM_MSS
AND PLATFORM_ORA!=PLATFORM_DB4;

UPDATE psindexdefn
SET PLATFORM_ALB=PLATFORM_ORA
WHERE PLATFORM_DB2=PLATFORM_DBX
AND PLATFORM_DBX=PLATFORM_INF
AND PLATFORM_INF=PLATFORM_ORA
AND PLATFORM_ORA=PLATFORM_SYB
AND PLATFORM_SYB=PLATFORM_MSS
AND PLATFORM_ORA!=PLATFORM_ALB;

UPDATE psindexdefn
SET PLATFORM_SBS=PLATFORM_ORA
WHERE PLATFORM_DB2=PLATFORM_DBX
AND PLATFORM_DBX=PLATFORM_INF
AND PLATFORM_INF=PLATFORM_ORA
AND PLATFORM_ORA=PLATFORM_SYB
AND PLATFORM_SYB=PLATFORM_MSS
AND PLATFORM_ORA!=PLATFORM_SBS;

COMMIT;
spool off


The platform flags now say 'ALL'. Not a tremendous change, but at least I can immediately see that these indexes do build on all platforms without having to open each one.

Thursday, June 15, 2006

Additional Batch Timings from Application Engine

I am doing some Application Engine development at the moment as a part of a project to replatform to Oracle. I go through an iterative process of changing SQL Server specific SQL (in a custom AE program) to run on Oracle, and then running the process until it fails again. However, not only must the processes run correctly on Oracle, but the new code needs to be efficient as possible in order to meet performance targets. So, I need to know how long each step in the AE program took to execute.

Application Engine batch timings are very useful metrics when tuning processes, but they are only written when the program ends, and they are only written to the timings tables in the database when a program completes successfully. I am repeatedly restarting the same process, gradually moving towards the end, so I will never get a complete timings report.

However, Application Engine programs writes a status string to table PSPRCSRQSTSTRNG which contains the step about to be executed. The value of this string can be seen in Process Monitor in the Process Detail page.

desc PSPRCSRQSTSTRNG
Name Null? Type
-------------------- -------- ---------------
PRCSINSTANCE NOT NULL NUMBER(38)
RQSTSTRINGTYPE NOT NULL VARCHAR2(2)
PRCSRQSTSTRING NOT NULL VARCHAR2(254)

I created a table to which a trigger logs what steps are executed. I have also used a sequence number to produce a reliable primary key on that table because values in the string will repeat when Application Engine is in a loop or when a process is restarted process in which case it keeps the same process instance number. The sequence number is generated by an Oracle Sequence to avoid locking problems caused by using a table to generate a sequence (as PeopleSoft generally does). I am not worried by gaps in the sequence.

CREATE TABLE dmk_prcsrqststrng_log
(prcsinstance NUMBER NOT NULL
,sequence_nbr NUMBER NOT NULL
,rqststringtype VARCHAR2(2) NOT NULL
,prcsrqststring VARCHAR2(254) NOT NULL
,datestamp DATE NOT NULL
,datetimestamp TIMESTAMP NOT NULL
,CONSTRAINT dmk_prcsrqststrng_log_pk
PRIMARY KEY (prcsinstance, sequence_nbr)
);

CREATE SEQUENCE dmk_prcsrqststrng_seq;

A trigger on PSPRCSRQSTSTRNG writes new values for PRCSRQSTSTRING to the log table. I have used an autonomous transaction in case the update rolls back after an error, and so that I can see the log record before Application Engine commits. I am also storing two timestamps when the audit record is written. The Oracle date type is only accurate to the second, but I have also used the newer timestamp datatype. On Oracle 9.2 (on Windows) I get millisecond accuracy, but on Oracle 10.2 I get microsecond accuracy.

CREATE OR REPLACE TRIGGER dmk_prcsrqststrng_log
AFTER INSERT OR UPDATE OR DELETE
ON sysadm.psprcsrqststrng
FOR EACH ROW
DECLARE
PRAGMA autonomous_transaction;
BEGIN
IF INSERTING OR UPDATING THEN
INSERT INTO dmk_prcsrqststrng_log
(prcsinstance
,sequence_nbr
,rqststringtype
,prcsrqststring
,datestamp
,datetimestamp)
VALUES
(:new.prcsinstance
,dmk_prcsrqststrng_seq.nextval
,:new.rqststringtype
,:new.prcsrqststring
,SYSDATE
,SYSTIMESTAMP);
ELSIF DELETING THEN
INSERT INTO dmk_prcsrqststrng_log
(prcsinstance
,sequence_nbr
,rqststringtype
,prcsrqststring
,datestamp
,datetimestamp)
VALUES
(:old.prcsinstance
,dmk_prcsrqststrng_seq.nextval
,:old.rqststringtype
,''
,SYSDATE
,SYSTIMESTAMP);
END IF;
COMMIT;
EXCEPTION
WHEN OTHERS THEN NULL;
END;
/
show errors

Unfortunately, the status record is not always updated or deleted when the Application Engine program ends. Therefore, another trigger is required to delete the process record when the application updates its status to no longer processing.

CREATE OR REPLACE TRIGGER dmk_prcsrqststrng_del
AFTER UPDATE OF runstatus ON sysadm.psprcsrqst
FOR EACH ROW
WHEN (new.runstatus != 7 AND old.runstatus = 7
AND new.prcstype IN ('Application Engine'))
DECLARE
PRAGMA autonomous_transaction;
BEGIN
DELETE FROM psprcsrqststrng WHERE prcsinstance = :new.prcsinstance;
COMMIT;
EXCEPTION WHEN OTHERS THEN NULL;
END;
/
show errors

This table can be used is various ways.

i) A simple report can be written to show the last 10 steps for each process instance, and their duration. I can run this while the program is executing to see how far it has got, and how long the current step has been executing.

COLUMN ranking FORMAT 990 HEADING 'Rank'
COLUMN sequence_nbr FORMAT 990 HEADING 'Seq'
COLUMN prcsrqststring FORMAT a25
COLUMN ratio FORMAT 90.0 HEADING '%'
COLUMN sum_duration FORMAT 999,990.000000 HEADING 'Total|Duration'
COLUMN duration FORMAT 99,990.000000
COLUMN avg_duration FORMAT 99,990.000000 HEADING 'Average|Duration'
COLUMN max_duration FORMAT 99,990.000000 HEADING 'Maximum|Duration'
COLUMN datetimestamp FORMAT a25
COLUMN executions FORMAT 990 HEADING 'Execs'
BREAK ON REPORT ON PRCSINSTANCE SKIP 1

SELECT y.prcsinstance
, y.sequence_nbr
, y.prcsrqststring
, y.datetimestamp
, (TO_DATE(TO_CHAR(y.nextdatetimestamp,'YYYYMMDDHH24MISS'),'YYYYMMDDHH24MISS')
-TO_DATE(TO_CHAR(y.datetimestamp,'YYYYMMDDHH24MISS'),'YYYYMMDDHH24MISS'))*86400
+TO_NUMBER(TO_CHAR(y.nextdatetimestamp,'xFF'))
-TO_NUMBER(TO_CHAR(y.datetimestamp,'xFF')) duration
FROM (
SELECT x.prcsinstance
, x.sequence_nbr
, x.prcsrqststring
, x.datetimestamp
, CASE WHEN x.prcsrqststring = '' THEN x.nextdatetimestamp
ELSE NVL(x.nextdatetimestamp,SYSTIMESTAMP)
END as nextdatetimestamp
, x.ranking
FROM (
SELECT x.prcsinstance
, x.sequence_nbr
, x.prcsrqststring
, x.datetimestamp
, LEAD(x.datetimestamp,1) OVER (PARTITION BY x.prcsinstance ORDER BY x.sequence_nbr) AS nextdatetimestamp
, RANK() OVER (ORDER BY x.datetimestamp desc) AS ranking
FROM dmk_prcsrqststrng_log x
) x
) y
WHERE y.ranking <= 10 ORDER BY prcsinstance, sequence_nbr; PRCSINSTANCE Seq PRCSRQSTSTRING DATETIMESTAMP DURATION ------------ ---- ------------------------------ ------------------------- -------------- 242797 688 Main 15-JUN-06 09.56.49.000721 15.227588 689 XXXIF_PAY_FI.WRITEOUT.Step01 15-JUN-06 09.57.04.228309 15.233425 690 XXX_GEN_MD5.MAIN.Step01 15-JUN-06 09.57.19.461734 45.355060 691 XXXIF_PAY_FI.WRITEOUT.Step03 15-JUN-06 09.58.04.816794 2,738.654582 242814 681 XXXIF_PAYA.Z_DelOld.? 14-JUN-06 18.00.14.747175 8.575205 682 14-JUN-06 18.00.23.322380

242815 683 Main 14-JUN-06 18.01.15.606713 19.816770
684 XXXIF_PAYH.Insert.Ins01 14-JUN-06 18.01.35.423483 15.516303
685 XXXIF_PAYH.Insert.Ins04 14-JUN-06 18.01.50.939786 15.160971
686 XXXIF_PAYH.Process.Hire 14-JUN-06 18.02.06.100757 163.917761
687 14-JUN-06 18.04.50.018518

ii) I can also aggregate the time for all the steps to determine what steps account for the longest execution time.

SELECT *
FROM ( /*rank lines in report, also calculate ration to report*/
SELECT RANK() OVER (ORDER BY sum_duration DESC) AS ranking
, d.*
, 100*ratio_to_report(sum_duration) OVER () AS ratio
FROM ( /*calculate sum and durations*/
SELECT c.prcsrqststring
, SUM(c.duration) sum_duration
, COUNT(*) executions
, AVG(c.duration) avg_duration
, MAX(c.duration) max_duration
FROM (
SELECT b.prcsrqststring
, (TO_DATE(TO_CHAR(b.nextdatetimestamp
,'YYYYMMDDHH24MISS'),'YYYYMMDDHH24MISS')
-TO_DATE(TO_CHAR(b.datetimestamp
,'YYYYMMDDHH24MISS'),'YYYYMMDDHH24MISS'))*86400
+TO_NUMBER(TO_CHAR(b.nextdatetimestamp,'xFF'))
-TO_NUMBER(TO_CHAR(b.datetimestamp,'xFF')) duration
FROM (
SELECT a.prcsinstance
, a.sequence_nbr
, a.prcsrqststring
, a.datetimestamp
, LEAD(a.datetimestamp,1)
OVER (PARTITION BY a.prcsinstance
ORDER BY a.sequence_nbr) AS nextdatetimestamp
, RANK() OVER (ORDER BY a.datetimestamp desc) AS ranking
FROM dmk_prcsrqststrng_log a
) b
WHERE b.nextdatetimestamp IS NOT NULL
AND prcsrqststring != ''
) c
GROUP BY c.prcsrqststring
HAVING SUM(c.duration) > 0
) d
) e
WHERE ranking <= 10 ;

                                    Total                 Average        Maximum
Rank PRCSRQSTSTRING Duration Execs Duration Duration %
---- ------------------------------ --------------- ----- -------------- -------------- -----
1 XXXIF_PAYC.ADDR_LD.060 11,509.840101 15 767.322673 980.808154 29.0
2 XXXIF_PAYC.ADDR_LD.050 7,476.656270 15 498.443751 679.516699 18.8
3 XXXIF_PAYC.ADDR_LD.020 3,669.344222 14 262.096016 669.283625 9.2
4 XXXIF_PAYC.ASGN_LD.076 3,076.882638 13 236.683280 2,729.356869 7.7
5 XXXIF_PAYC.ASGN_LD.010 2,721.361198 15 181.424080 332.187057 6.8
6 XXXIF_PAYC.PURGE.020 2,644.848544 1 2,644.848544 2,644.848544 6.7
7 XXXIF_PAYC.ASGN_LD.020 624.892364 15 41.659491 155.971344 1.6
8 XXXIF_PAYC.ADDR_LD.010 623.354434 14 44.525317 136.919156 1.6
9 XXXIF_PAYC.ASGN_LD.030 583.222200 10 58.322220 425.172493 1.5
10 XXXIF_PAYC.ASGN_LD.060 543.455165 14 38.818226 125.473966 1.4

This method, although useful, is not foolproof. The status string is only updated if AE Restart is enabled, and then not for for every step followed by a COMMIT. I haven't yet been able to work out all the criteria for this.

Tuesday, May 16, 2006

Identifying Candidate Records for the Lookup Exclusion Table

Recently, I wrote about the lookup exclusion table, and then I started to think about identifying automatic lookups that should suppressed. The following query will identify all the records that are used as look-up records.

SELECT DISTINCT r.recname
FROM pspnlfield p
, psrecfielddb f
, psrecdefn r
WHERE p.fieldname = f.fieldname
AND p.recname = f.recname
AND r.recname = f.edittable

I started on the basis that this is a performance issue. I took a minimalist approach that I would only suppress lookups that were consuming a significant amount of tine. So I looked at whether it was possible to use performance Monitor data to identify long running lookups. When you capture a PMU either through sampling or a performance trace you get a heirarchy of the following transactions when you performance a lookup.
  • 401:Entry and exit for Component search and processing on AppSrv
  • 403:Modal component/secondary page/lookup page from a Level 1
  • 408:All SQL calls excluding PMUs 406 and 407
Note: Transaction 408 is only collected if you have verbose trace enabled for PSAPPSRV. Be aware that this level of tracing can have an impact on performance.

Performance monitor transactions are held in the table PSPMTRANSHIST. This table can become rather large, I found it easier to extract the transaction types that are of interest to me into another table, and then analyse that data.


DROP TABLE dmktranshist;

CREATE TABLE dmktranshist PCTFREE 0 as
SELECT pm_trans_defn_id
, pm_instance_id, pm_parent_inst_id, pm_top_inst_id
, pm_context_value1, pm_context_value2, pm_context_value3
, pm_metric_value7
--, pm_addtnl_descr
, pm_trans_duration
FROM pspmtranshist
WHERE pm_trans_defn_set = 1
AND pm_trans_defn_id IN(401,403,408)
AND ( pm_trans_defn_id = 401
OR (pm_trans_defn_id = 403 AND pm_context_value3 = 'Launch Look up Page')
OR (pm_trans_defn_id = 408 AND pm_metric_value7 LIKE 'SELECT PS%' AND SUBSTR(pm_metric_value7,10,1) = '_')
);

CREATE UNIQUE INDEX dmktranshist1
ON dmktranshist(pm_instance_id) PCTFREE 0;

CREATE INDEX dmktranshist2
ON dmktranshist(pm_trans_defn_id, pm_parent_inst_id, pm_metric_value7)
PCTFREE 0 COMPRESS 1;

CREATE INDEX dmktranshist3
ON dmktranshist(pm_trans_defn_id, pm_context_value3)
PCTFREE 0 COMPRESS 1;

ANALYZE TABLE dmktranshist ESTIMATE STATISTICS FOR ALL COLUMNS;


I have constructed two queries to identify component look-ups that are acocunting for a large amount of response time. This first query simply sums the duration and counts the number of executions of each lookup record. Details of the component and page are also available on the table.

COLUMN pm_instance_id    FORMAT 999999999999999
COLUMN pm_parent_inst_id FORMAT 999999999999999
COLUMN pm_top_inst_id FORMAT 999999999999999
COLUMN component FORMAT a25 HEADING 'Component'
COLUMN page FORMAT a35 HEADING 'Page'
COLUMN pm_context_value3 HEADING 'Context'
ttitle 'Total Time grouped by Lookup Record'
SELECT
-- a.pm_context_value1 component,
-- a.pm_context_value2 page,
a.pm_context_value3
, SUM(b.pm_trans_duration)/1000 duration
, COUNT(*) num_lookups
, SUM(b.pm_trans_duration)/1000/COUNT(*) avg_duration
FROM dmktranshist a
, dmktranshist b
WHERE a.pm_trans_defn_id = 401
AND b.pm_trans_defn_id = 403
AND a.pm_top_inst_id = b.pm_top_inst_id
AND a.pm_instance_id = b.pm_parent_inst_id
AND b.pm_context_value3 = 'Launch Look up Page'
GROUP BY a.pm_context_value3 --,a.pm_context_value1 ,a.pm_context_value2
--HAVING SUM(b.pm_trans_duration)>=50000 /*use this restrict runs to top lookups.*/
ORDER BY 2 DESC
/

Total Time grouped by Lookup Record
Context
--------------------------------------------------------------------
DURATION NUM_LOOKUPS AVG_DURATION
---------- ----------- ------------
Click Prompt Button/Hyperlink for Field DEPOSIT_CONTROL.BANK_CD
.849 1 .849
Click Prompt Button/Hyperlink for Field DEPOSIT_CONTROL.BANK_ACCT_KEY
.319 1 .319
...

The other query additionally retrieves the SQL that was run, but this data is only available if the PMU trace was at Verbose level on the PSAPPSRV process.
ttitle 'SQL run by lookup - only with verbose or debug level tracing'

SELECT a.pm_context_value1 component
, a.pm_context_value2 page
, a.pm_context_value3
, c.pm_metric_value7
, b.pm_trans_duration/1000 duration
FROM dmktranshist a, dmktranshist b, dmktranshist c
WHERE a.pm_trans_defn_id = 401
AND b.pm_trans_defn_id = 403
AND c.pm_trans_defn_id = 408
AND a.pm_top_inst_id = b.pm_top_inst_id
AND b.pm_top_inst_id = c.pm_top_inst_id
AND c.pm_top_inst_id = a.pm_top_inst_id
AND a.pm_instance_id = b.pm_parent_inst_id
AND b.pm_instance_id = c.pm_parent_inst_id
AND b.pm_context_value3 = 'Launch Look up Page'
AND c.pm_metric_value7 LIKE 'SELECT PS%'
AND SUBSTR(c.pm_metric_value7,10,1) = '_'
AND c.pm_instance_id = (
SELECT MAX(c1.pm_instance_id)
FROM dmktranshist c1
WHERE c1.pm_parent_inst_id = c.pm_parent_inst_id
AND c1.pm_top_inst_id = c.pm_top_inst_id
AND c1.pm_metric_value7 LIKE 'SELECT PS%'
AND c1.pm_trans_defn_id = 408
AND SUBSTR(c1.pm_metric_value7,10,1) = '_')
/


Component Page
------------------------- -----------------------------------
Context
--------------------------------------------------------------------
PM_METRIC_VALUE7
--------------------------------------------------------------------
DURATION
----------
PAYMENT_EXPRESS.GBL PAYMENT_EXPRESS1
Click Prompt Button/Hyperlink for Field DEPOSIT_CONTROL.BANK_CD
SELECT PS_BANK_AR_BD_VW A
.849

PAYMENT_EXPRESS.GBL PAYMENT_EXPRESS1
Click Prompt Button/Hyperlink for Field DEPOSIT_CONTROL.BANK_ACCT_KEY
SELECT PS_BANK_AR_D_VW A
.319

Suppressing the automatic lookup saves the user from waiting for an unnecessary query. The question is what is the criteria for adding a record to the lookup exclusion table.
  • Certainly if a lookup record returns more than 300 rows it should not be executed automatically, because only the first 300 rows will be returned, and then the user will probably not have the row they are looking for and they will have to add search criteria and repeat the search.
  • There is a good case for suppressing the automatic lookup when it returns more than 100 rows. The results will return up to 3 pages of 100 rows per page. Then the user may well have to navigate to a different page in order to find what they are looking for.
  • Having discussed this issue with a few people, there is some support for the suggestion that the automatic search should be supressed for records with more than 25-50 rows. If there are more rows than this, the user is likely to have to scroll down the page the desired row.
The number of rows that a lookup record may retrieve is therefore a good criteria for deciding whether to suppress the automatic lookup. So I have constructed the following SQL script to identify all candidate records and count the number of rows that each returns. First I need a table in which to store the results.

CREATE TABLE lux_cand
(recname VARCHAR2(15) NOT NULL
,sqltablename VARCHAR2(18)
,rectype NUMBER NOT NULL
,num_lookups NUMBER NOT NULL
,num_rows NUMBER
,lead_key VARCHAR2(18)
,num_lead_keys NUMBER
,lastupddttm DATE )
/

CREATE UNIQUE INDEX lux_cand ON lux_cand(recname)
/


Then all the records with lookup exclusion fields will be copied into our new working storage table.

INSERT INTO lux_cand (recname, sqltablename, rectype, lead_key, num_lookups)
SELECT r.recname
, CASE WHEN r.rectype IN(0,1,6) THEN /*regular records*/
DECODE(r.sqltablename,' ','PS_'r.recname,r.sqltablename)
END
, r.rectype
, k.fieldname
, count(*) num_lookups
FROM pspnlfield p
, psrecfielddb f
, psrecdefn r
LEFT OUTER JOIN pskeydefn k
ON k.recname = r.recname
AND k.indexid = '_'
AND k.keyposn = 1
WHERE p.fieldname = f.fieldname
AND p.recname = f.recname
AND f.edittable > ' '
AND r.recname = f.edittable
GROUP BY r.recname, r.rectype, k.fieldname
, DECODE(r.sqltablename,' ','PS_'r.recname,r.sqltablename)
/

COMMIT
/

/*if SETID is a key, the we will group by SETID*/
UPDATE lux_cand l
SET l.lead_key = 'SETID'
WHERE l.lead_key IS NULL
AND EXISTS(
SELECT 'x'
FROM psrecfielddb k
WHERE k.recname = l.recname
AND k.fieldname = 'SETID'
AND MOD(k.useedit,2) = 1 /*bit 1 of useedit is set to one for key columns*/
);

/*store first defined key column*/
UPDATE lux_cand l
SET l.lead_key = (
SELECT k.fieldname
FROM psrecfielddb k
WHERE k.recname = l.recname
AND MOD(k.useedit,2) = 1
AND k.fieldnum = (
SELECT MIN(k1.fieldnum)
FROM psrecfielddb k1
WHERE k1.recname = k.recname
AND MOD(k1.useedit,2) = 1 ))
WHERE l.lead_key IS NULL
;

/*clear sqltablename where table does not exist*/
UPDATE lux_cand l
SET l.sqltablename = ''
WHERE l.sqltablename IS NOT NULL
AND l.rectype = 0
AND NOT EXISTS(
SELECT 'x'
FROM user_tables o
WHERE o.table_name = l.sqltablename) ;

/*clear sqltablename where the view does not exist*/
UPDATE lux_cand l
SET l.sqltablename = ''
WHERE l.sqltablename IS NOT NULL
AND l.rectype IN(1,6)
AND NOT EXISTS(
SELECT 'x'
FROM user_views o
WHERE o.view_name = l.sqltablename)
/

/*deliberately exclude this view from the test, it takes a long time to count the rows and it should be on the lookup exclusion table regardless*/
UPDATE lux_cand l
SET l.lastupddttm = SYSDATE, l.num_rows = 301
WHERE l.recname IN('PSFIELDRECDVW')
AND l.lastupddttm IS NULL
/

COMMIT
/

/*count number of rows in each table*/
DECLARE
l_num_rows INTEGER;
l_lead_keys INTEGER;
BEGIN
FOR l IN (
SELECT l.* FROM lux_cand l
WHERE l.lastupddttm IS NULL
AND l.sqltablename IS NOT NULL
ORDER BY SIGN(l.rectype) /*do tables first*/
, case when 'PS_'l.recname = l.sqltablename then 0 else 1 end /*tools tables last*/
, l.rectype /*order by rectype*/
, l.recname
) LOOP
l_num_rows := 0;
l_lead_keys := 0;
IF l.lead_key = 'SETID' THEN /*count max rows per setid*/
EXECUTE IMMEDIATE 'SELECT MAX(num_rows), COUNT(*) FROM (SELECT COUNT(*) num_rows FROM 'l.sqltablename' GROUP BY 'l.lead_key')' INTO l_num_rows, l_lead_keys;
UPDATE lux_cand
SET num_rows = NVL(l_num_rows,0)
, num_lead_keys = NVL(l_lead_keys,0)
, lastupddttm = SYSDATE
WHERE recname = l.recname;
ELSE /*count number of rows*/
EXECUTE IMMEDIATE 'SELECT COUNT(*) FROM 'l.sqltablename' WHERE rownum <= 301' INTO l_num_rows; UPDATE lux_cand SET num_rows = NVL(l_num_rows,0) , lastupddttm = SYSDATE WHERE recname = l.recname;
END IF;
COMMIT;
END LOOP;
END;
/


Now, the table LUX_CAND contains a list of all the tables and view used as lookups, and the number of rows that they return (I cannot do anything about PeopleSoft dynamic views). The next thing is to add any record that returns too many rows into the lookup exclusion table.

/*put records with too many rows into the exclusion table*/
INSERT INTO psrecxl
SELECT recname FROM lux_cand WHERE num_rows > 100
MINUS
SELECT recname FROM psrecxl
/

Don't worry about an negative effects of having a large number records in the lookup exclusion table. This information is cached by the application server. Although there is no version number on PSRECXL, when you save an update to the lookup exclusion table, there is component PeopleCode that updates the SYS and PPC version numbers, which causes the application server to recache this table, so that changes take effect immediately. So when updating PSRECXL with this script, it is also necessary to increment the version numbers.

UPDATE PSVERSION SET VERSION = VERSION + 1 WHERE OBJECTTYPENAME IN('SYS','PPC');
UPDATE PSLOCK SET VERSION = VERSION + 1 WHERE OBJECTTYPENAME IN('SYS','PPC');
COMMIT;

On my Financials 8.4 demo system I found 4089 records being used as lookup records. Of those 557 have over 300 rows, 1058 have over 100 rows, and 1711 records return over 25 rows.
On balance, I think that I would be prepared to add all 1711 records to the lookup exclusion table. It would save unecessary searches.

Saturday, May 06, 2006

Lookup Exclusion Table

One of the catchphrases that I have adopted (I think from Cary Milsap of Hotsos) is 'the fastest way to do something is not to do it at all'. Instead of making something take less time by tuning, it is much better make it take no time at all by not doing it in the first place!

This applies to PeopleSoft as much as anything else. In this posting I want to draw attention to the Lookup exclusion table. Lots of fields in PeopleSoft applications have lookups associated with them, indicated by the magnifying glass icon.

Click on image to enlarge
When you click on that you are taken to a lookup dialogue, but normally the search fires automatically. Sometimes the operator must wait a while for the SQL queries to return the data. If there is a lot of data only 300 rows are retrieved into the component buffer, and only the first 100 rows of that set are shown. For example, here is an example from Application Hire in HR illustrated with the demo database.

Click on image to enlarge
These results are usually useless to the operator who must enter criteria into the lookup search dialogue and search again. It would be better if the first automatic search could be suppressed. Fortunately, this can be done by putting the prompt table associated with the field on the lookup exclusion table.

Click on image to enlarge
Now the user goes straight into a waiting page and is prompted to enter search criteria to find the relavent data. Even better, the benefit to the user is immediate. You don't have to restart any servers for this configuration setting to be recognised, and for the behaviour of the lookup to change.

Click on image to enlarge
The lookup exclusion table is a very simple and quick way of improving performance by cutting out unnecessary work. It is also much easier to implement these changes because there are only configuration, rather than customisation.