Query performance issue after 19c upgrade

From: Michael Schmitt <mschmitt_at_uchicago.edu>
Date: Wed, 24 Jun 2020 20:08:12 +0000
Message-ID: <CH2PR11MB44879717698CD72D79F055ACAC950_at_CH2PR11MB4487.namprd11.prod.outlook.com>



Hi all,

We are working on an upgrade of Oracle in a PeopleSoft environment from 12.2.0.1 to 19.7

PeopleSoft has an ugly sort of Row level Security option built into the application, and we have found that a few of the queries that use that go from a response time of about 5 seconds until about 7+ hours. Some of the things we have found related to this. It shows up right after we upgrade to 19c (we refresh the DB from PRD then upgrade). None of our 12.2.0.1 instances have the problem. We have created a SQL baseline in 12.2.0.1 and moved it to 19c, 19c immediately creates a different baseline on execution and goes with that one instead of the one from 12.2.0.1. Recollecting stats on all relevant tables has shown no difference. Oracle provided us with the OUTLINE from a SQLT trace of the 12.2. system, but when we try to add that as a hint to the SQL for 19c we get an error (ORA-01799: a column may not be outer-joined to a subquery). Switching optimizer_features_enable has had no impact on improving response.

From what we can tell the 12.2 good run has the following in the execution plan

| 78 | VIEW | VW_LAT_84AD8559 | 1 | 7 | 20 (10)| | | |
| 79 | NESTED LOOPS | | 1 | 31 | 17 (12)| | | |

|* 80 | TABLE ACCESS BY INDEX ROWID BATCHED | PS_NAMES | 1 | 29 | 4 (0)| | | |
|* 81 | INDEX RANGE SCAN | PS_NAMES | 1 | | 3 (0)| | | |

| 82 | SORT AGGREGATE | | 1 | 22 | | | | |
| 83 | FIRST ROW | | 1 | 22 | 3 (0)| | | |
|* 84 | INDEX RANGE SCAN (MIN/MAX) | PS_NAMES | 1 | 22 | 3 (0)| | | |

| 85 | VIEW PUSHED PREDICATE | PS_PERALL_SEC_QRY | 1 | 2 | 13 (16)| | | |
| 86 | SORT UNIQUE | | 1 | 52 | 13 (16)| 2048 | 2048 | 2048 (0)|
|* 87 | FILTER | | | | | | | |

| 88 | NESTED LOOPS | | 1 | 52 | 5 (0)| | | |
| 89 | TABLE ACCESS BY INDEX ROWID | PSOPRDEFN | 1 | 24 | 2 (0)| | | |
|* 90 | INDEX UNIQUE SCAN | PS_PSOPRDEFN | 1 | | 1 (0)| | | |
|* 91 | TABLE ACCESS BY INDEX ROWID BATCHED | PS_SJT_PERSON | 1 | 28 | 3 (0)| | | |
|* 92 | INDEX RANGE SCAN | PSASJT_PERSON | 1 | | 2 (0)| | | |
91 - filter(("SEC"."APPT_TYPE"<>'1' AND "SEC"."FUTURE_FLG"<>'Y')) 92 - access("SEC"."EMPLID"="I"."EMPLID")

While the bad runs from 19c do not get the EMPLID into PD_SJT_PERSON table that has 500K rows

| 66 | VIEW | VW_LAT_84AD8559 | 1 | 7 | | 6381 (1)| | | |
| 67 | MERGE JOIN | | 1 | 115 | | 6378 (1)| | | |
| 68 | VIEW | PS_PERALL_SEC_QRY | 319K| 26M| | 6373 (1)| | | |
| 69 | SORT UNIQUE | | 319K| 15M| 31M| 6373 (1)| 35M| 2109K| |

|* 70 | FILTER | | | | | | | | |

| 71 | NESTED LOOPS | | 452K| 22M| | 1603 (2)| | | |
| 72 | TABLE ACCESS BY INDEX ROWID | PSOPRDEFN | 1 | 24 | | 2 (0)| | | |
|* 73 | INDEX UNIQUE SCAN | PS_PSOPRDEFN | 1 | | | 1 (0)| | | | |* 74 | TABLE ACCESS FULL | PS_SJT_PERSON | 452K| 12M| | 1601 (2)| | | 74 - filter(("SEC"."APPT_TYPE"<>'1' AND "SEC"."FUTURE_FLG"<>'Y'))

The earlier post from Nenad made me think to throw this to the list since we are running the same version. Query and syntax to the view it is joining to is listed below. These queries have likely needed to be cleaned up for awhile and that is what is being look at, but what I am currently struggling with is why I haven't been able to get 19c to use a plan like 12.2.

SELECT DISTINCT A.EMPLID, B.LAST_NAME, B.FIRST_NAME, B.MIDDLE_NAME, C.EMAIL_ADDR, E.DESCR, MAX( F.ACAD_LEVEL_BOT), MAX( F.STRM), H.TRNSCR_DESCR, A.INSTITUTION, A.ACAD_CAREER,I.FIRST_NAME, D.DEGR_CHKOUT_STAT, D.PROG_STATUS, J.FERPA FROM

PS_STDNT_ADVR_HIST A, (
PS_SCC_NAMES_QVW B LEFT OUTER JOIN (
PS_NAMES I INNER JOIN
PS_PERALL_SEC_QRY I1 ON (I.EMPLID = I1.EMPLID AND I1.OPRID = 'mschmitt' )) ON B.EMPLID = I.EMPLID AND I.EFFDT =
(SELECT MAX(I_ED.EFFDT)
FROM PS_NAMES I_ED
WHERE I.EMPLID = I_ED.EMPLID AND I.NAME_TYPE = I_ED.NAME_TYPE AND I_ED.EFFDT <= B.EFFDT) AND I.NAME_TYPE = 'PRF' AND I.FIRST_NAME <> B.FIRST_NAME ), PS_EMAIL_ADDRESSES C, (((((PS_ACAD_PROG D LEFT OUTER JOIN PS_TERM_TBL E ON E.STRM = D.EXP_GRAD_TERM ) LEFT OUTER JOIN PS_STDNT_CAR_TERM F ON D.EMPLID = F.EMPLID AND D.ACAD_CAREER = F.ACAD_CAREER AND D.STDNT_CAR_NBR = F.STDNT_CAR_NBR AND F.INSTITUTION = D.INSTITUTION ) LEFT OUTER JOIN PS_ACAD_PLAN G ON D.EMPLID = G.EMPLID AND D.ACAD_CAREER = G.ACAD_CAREER AND D.STDNT_CAR_NBR = G.STDNT_CAR_NBR AND D.EFFSEQ = G.EFFSEQ AND G.PLAN_SEQUENCE = 10 ) LEFT OUTER JOIN PS_ACAD_PLAN_TBL H ON G.ACAD_PLAN = H.ACAD_PLAN ) LEFT OUTER JOIN PS_PERSON_SA J ON D.EMPLID = J.EMPLID ), PS_PERALL_SEC_QRY C1 WHERE ( C.EMPLID = C1.EMPLID AND C1.OPRID = 'mschmitt' AND ( A.EFFDT = (SELECT MAX(A_ED.EFFDT)
FROM
PS_STDNT_ADVR_HIST A_ED
WHERE A.EMPLID = A_ED.EMPLID AND A.INSTITUTION = A_ED.INSTITUTION AND A_ED.EFFDT <= SYSDATE) AND A.ADVISOR_ID = '12274291' AND A.EMPLID = B.EMPLID AND B.EFFDT = (SELECT MAX(B_ED.EFFDT)
FROM PS_SCC_NAMES_QVW B_ED
WHERE B.EMPLID = B_ED.EMPLID AND B.NAME_TYPE = B_ED.NAME_TYPE AND B_ED.EFFDT <= SYSDATE) AND B.NAME_TYPE = 'PRI' AND B.EMPLID = C.EMPLID AND C.E_ADDR_TYPE = 'UCHI' AND A.EMPLID = D.EMPLID AND A.INSTITUTION = D.INSTITUTION AND D.ACAD_CAREER = A.ACAD_CAREER AND D.EFFDT = (SELECT MAX(D_ED.EFFDT)
FROM PS_ACAD_PROG D_ED
WHERE D.EMPLID = D_ED.EMPLID AND D.ACAD_CAREER = D_ED.ACAD_CAREER AND D.STDNT_CAR_NBR = D_ED.STDNT_CAR_NBR AND D_ED.EFFDT <= SYSDATE) AND D.EFFSEQ = (SELECT MAX(D_ES.EFFSEQ)
FROM PS_ACAD_PROG D_ES
WHERE D.EMPLID = D_ES.EMPLID AND D.ACAD_CAREER = D_ES.ACAD_CAREER AND D.STDNT_CAR_NBR = D_ES.STDNT_CAR_NBR AND D.EFFDT = D_ES.EFFDT) AND D.PROG_STATUS IN ('AC','LA','SP') AND G.EFFDT = (SELECT MAX(G_ED.EFFDT)
FROM PS_ACAD_PLAN G_ED
WHERE G.EMPLID = G_ED.EMPLID AND G.ACAD_CAREER = G_ED.ACAD_CAREER AND G.STDNT_CAR_NBR = G_ED.STDNT_CAR_NBR AND G_ED.EFFDT <= D.EFFDT) AND H.EFFDT = (SELECT MAX(H_ED.EFFDT)
FROM PS_ACAD_PLAN_TBL H_ED
WHERE H.INSTITUTION = H_ED.INSTITUTION AND H.ACAD_PLAN = H_ED.ACAD_PLAN AND H_ED.EFFDT <= G.EFFDT) )) GROUP BY A.EMPLID, B.LAST_NAME, B.FIRST_NAME, B.MIDDLE_NAME, C.EMAIL_ADDR, E.DESCR, H.TRNSCR_DESCR, A.INSTITUTION, A.ACAD_CAREER, I.FIRST_NAME, D.DEGR_CHKOUT_STAT, D.PROG_STATUS, J.FERPA ORDER BY 2

CREATE OR REPLACE FORCE EDITIONABLE VIEW "SYSADM"."PS_PERALL_SEC_QRY" ("OPRID" , "EMPLID") AS
  SELECT DISTINCT OPR.OPRID,SEC.EMPLID FROM PS_SJT_PERSON SEC, PSOPRDEFN OPR WHE RE SEC.APPT_TYPE <> '1' AND SEC.FUTURE_FLG <> 'Y' AND ((EXISTS ( SELECT 'X' FROM PS_SJT_CLASS_ALL CLS , PS_SJT_OPR_CLS SOC WHERE CLS.SCRTY_SET_CD = 'PPLJOB' AND CLS.SCRTY_TYPE_CD = SEC.SCRTY_TYPE_CD AND CLS.SCRTY_KEY1 = SEC.SCRTY_KEY1 AND C LS.SCRTY_KEY2 = SEC.SCRTY_KEY2 AND CLS.SCRTY_KEY3 = SEC.SCRTY_KEY3 AND CLS.TREE = 'Y' AND SOC.OPRID=OPR.OPRID AND SOC.CLASSID = CLS.CLASSID AND SOC.CLASSID = OP R.ROWSECCLASS AND SOC.SEC_RSC_FLG = '1' ) OR EXISTS ( SELECT 'X' FROM PS_SJT_CLA SS_ALL CLS , PS_SJT_OPR_CLS SOC WHERE CLS.SCRTY_SET_CD = 'PPLJOB' AND CLS.SCRTY_ TYPE_CD = SEC.SCRTY_TYPE_CD AND CLS.SCRTY_KEY1 = SEC.SCRTY_KEY1 AND CLS.SCRTY_KE Y2 = SEC.SCRTY_KEY2 AND CLS.SCRTY_KEY3 = SEC.SCRTY_KEY3 AND CLS.TREE = 'N' AND S OC.OPRID=OPR.OPRID AND SOC.CLASSID = CLS.CLASSID ) OR EXISTS ( SELECT 'X' FROM P S_SJT_CLASS_ALL CLS , PS_SJT_OPR_CLS SOC WHERE CLS.SCRTY_SET_CD = 'PPLJOB' AND C LS.SCRTY_TYPE_CD = SEC.SCRTY_TYPE_CD AND CLS.SCRTY_KEY1 = SEC.SCRTY_KEY1 AND CLS .SCRTY_KEY2 = SEC.SCRTY_KEY2 AND CLS.SCRTY_KEY3 = SEC.SCRTY_KEY3 AND CLS.TREE = 'Y' AND SOC.OPRID=OPR.OPRID AND SOC.CLASSID = CLS.CLASSID AND SOC.CLASSID = OPR. ROWSECCLASS AND SOC.SEC_RSC_FLG = '3' )) OR (EXISTS ( SELECT 'X' FROM PS_SJT_CLA SS_ALL CLS , PS_SJT_OPR_CLS SOC WHERE CLS.SCRTY_SET_CD = 'PPLPOI' AND CLS.SCRTY_ TYPE_CD = SEC.SCRTY_TYPE_CD AND CLS.SCRTY_KEY1 = SEC.SCRTY_KEY1 AND CLS.SCRTY_KE Y2 = SEC.SCRTY_KEY2 AND CLS.SCRTY_KEY3 = SEC.SCRTY_KEY3 AND CLS.TREE = 'Y' AND S OC.OPRID=OPR.OPRID AND SOC.CLASSID = CLS.CLASSID AND SOC.CLASSID = OPR.ROWSECCLA SS AND SOC.SEC_RSC_FLG = '1' ) OR EXISTS ( SELECT 'X' FROM PS_SJT_CLASS_ALL CLS , PS_SJT_OPR_CLS SOC WHERE CLS.SCRTY_SET_CD = 'PPLPOI' AND CLS.SCRTY_TYPE_CD = S EC.SCRTY_TYPE_CD AND CLS.SCRTY_KEY1 = SEC.SCRTY_KEY1 AND CLS.SCRTY_KEY2 = SEC.SC RTY_KEY2 AND CLS.SCRTY_KEY3 = SEC.SCRTY_KEY3 AND CLS.TREE = 'N' Thanks in advance

--
http://www.freelists.org/webpage/oracle-l
Received on Wed Jun 24 2020 - 22:08:12 CEST

Original text of this message