Home » RDBMS Server » Performance Tuning » SQL statment running for ever (Oracle server 11g Enterprise Edition Release 11.1.0.7.0 - 64bit , Linux x86_64 GNU/Linux )
SQL statment running for ever [message #464871] Sat, 10 July 2010 02:13 Go to next message
samiraly
Messages: 57
Registered: June 2009
Member

Hello The follwing sql statment is running for hours , first i got an error telling that "unable to extend temp segment " as shown in the screen shot attached , then i added newa datafile to the temp tablespace and it is now running for 2 hours to finish ,
SELECT
      T10.CONFLICT_ID,
      T10.LAST_UPD,
      T10.CREATED,
      T10.LAST_UPD_BY,
      T10.CREATED_BY,
      T10.MODIFICATION_NUM,
      T10.ROW_ID,
      T4.ATTRIB_49,
      T33.CUST_STAT_CD,
      T4.ATTRIB_45,
      T4.ATTRIB_50,
      T33.ALIAS_NAME,
      T33.X_ATTRIB_123,
      T33.X_CCB_DT_ERSTE_AKTIVIERUNG,
      T33.X_CCB_DT_ERSTER_DIENST,
      T33.X_CCB_HIERARCHIE_STUFE,
      T33.X_ATTRIB_108,
      T33.X_CCB_KUNDENNUMMER,
      T33.X_CCB_STATUS,
      T4.ATTRIB_24,
      T33.CMPT_FLG,
      T33.BASE_CURCY_CD,
      T33.HIST_SLS_CURCY_CD,
      T4.ATTRIB_42,
      T16.LOGIN,
      T4.ATTRIB_12,
      T33.DUNS_NUM,
      T23.KEY_VALUE,
      T33.DESC_TEXT,
      T33.DIVISION,
      T33.ENTERPRISE_FLAG,
      T33.CREATED,
      T33.FRGHT_TERMS_INFO,
      T13.COMMENTS,
      T33.X_ATTRIB_124,
      T33.URL,
      T33.INTEGRATION_ID,
      T33.INT_ORG_FLG,
      T33.PR_BL_OU_ID,
      T22.NAME,
      T33.X_KONDITIONENMODELL,
      T4.ATTRIB_48,
      T33.DEDUP_KEY_UPD_DT,
      T33.X_LETZTE_AKTIVITAET_DATUM,
      T33.X_LETZTER_BESUCH_DATUM,
      T33.LOC,
      T33.LOCATION_LEVEL,
      T33.MAIN_FAX_PH_NUM,
      T33.MAIN_PH_NUM,
      T4.ATTRIB_21,
      T33.X_ATTRIB_101,
      T33.NAME,
      T33.PO_PAY_CURCY_CD,
      T33.PAR_OU_ID,
      T7.NAME,
      T33.PAR_DUNS_NUM,
      T33.PRTNR_FLG,
      T4.ATTRIB_37,
      T4.ATTRIB_38,
      T4.ATTRIB_34,
      T10.NAME,
      T33.X_POTENTIAL,
      T12.NAME,
      T33.CURR_PRI_LST_ID,
      T11.COUNTRY,
      T11.ZIPCODE,
      T11.STATE,
      T33.PR_ADDR_ID,
      T33.PR_REP_DNRM_FLG,
      T33.PR_REP_MANL_FLG,
      T33.PR_REP_SYS_FLG,
      T33.PR_REP_ASGN_TYPE,
      T33.PR_BL_ADDR_ID,
      T33.PR_BL_PER_ID,
      T33.PR_MKT_SEG_ID,
      T33.PR_CRDT_AREA_ID,
      T33.PR_INDUST_ID,
      T33.X_PR_OPTY_ID,
      T33.BU_ID,
      T33.PR_ORG_PAY_PRFL_ID,
      T33.PR_POSTN_ID,
      T33.PR_SRV_AGREE_ID,
      T33.PR_SHIP_ADDR_ID,
      T33.PR_SHIP_PER_ID,
      T33.PR_SYN_ID,
      T33.PR_TERR_ID,
      T33.X_VERTRAGSPARTNER_ID,
      T33.REFERENCE_CUST_FLG,
      T33.X_REFERENZKUNDE,
      T33.REGION,
      T14.FST_NAME,
      T14.LAST_NAME,
      T1.X_REGION,
      T32.ATTRIB_41,
      T1.X_KANAL,
      T19.OWN_INST_ID,
      T19.INTEGRATION_ID,
      T33.X_SUMME_S0,
      T33.X_SUMME_VERTRAEGE,
      T33.SURVEY_TYPE_CD,
      T4.ATTRIB_05,
      T33.PTNTL_SLS_CURCY_CD,
      T33.CONTRACT_VIS_FLG,
      T33.X_BAN,
      T33.X_ATTRIB_133,
      T6.AGREE_NUM,
      T33.X_VOID,
      T33.X_VO,
      T29.LOW,
      T4.ATTRIB_57,
      T33.X_ATTRIB_109,
      T33.X_WIEDERVORLAGE,
      T33.X_SCELETON_CONTRACT,
      T33.ACTIVE_FLG,
      T33.X_READONLY,
      T4.ATTRIB_66,
      T33.X_DOUBLE_CHK_FLG,
      T11.LAST_UPD,
      T33.OU_TYPE_CD,
      T33.X_TYPE_2,
      T33.X_MAIL_SERVER,
      T27.NAME,
      T15.ROW_ID,
      T28.ROW_STATUS,
      T24.LOGIN,
      T30.ATTRIB_03,
      T30.ATTRIB_08,
      T30.ATTRIB_35,
      T30.ATTRIB_34,
      T30.ATTRIB_16,
      T30.ATTRIB_06,
      T30.ATTRIB_49,
      T30.ATTRIB_47,
      T3.ROW_ID,
      T30.ATTRIB_18,
      T30.ATTRIB_19,
      T30.ATTRIB_17,
      T30.ATTRIB_05,
      T30.ATTRIB_13,
      T30.ATTRIB_07,
      T30.ATTRIB_43,
      T30.ATTRIB_10,
      T30.ATTRIB_04,
      T30.ATTRIB_12,
      T30.ATTRIB_09,
      T30.ATTRIB_26,
      T3.CITY,
      T3.COUNTRY,
      T3.ZIPCODE,
      T3.STATE,
      T3.ADDR,
      T30.ATTRIB_45,
      T18.ADDR,
      T5.NAME,
      T2.ADDR,
      T21.PAR_BU_ID,
      T17.NAME,
      T17.SIC,
      T33.ROW_ID,
      T33.PAR_ROW_ID,
      T33.MODIFICATION_NUM,
      T33.CREATED_BY,
      T33.LAST_UPD_BY,
      T33.CREATED,
      T33.LAST_UPD,
      T33.CONFLICT_ID,
      T33.PAR_ROW_ID,
      T19.ROW_ID,
      T19.PAR_ROW_ID,
      T19.MODIFICATION_NUM,
      T19.CREATED_BY,
      T19.LAST_UPD_BY,
      T19.CREATED,
      T19.LAST_UPD,
      T19.CONFLICT_ID,
      T19.PAR_ROW_ID,
      T4.ROW_ID,
      T4.PAR_ROW_ID,
      T4.MODIFICATION_NUM,
      T4.CREATED_BY,
      T4.LAST_UPD_BY,
      T4.CREATED,
      T4.LAST_UPD,
      T4.CONFLICT_ID,
      T4.PAR_ROW_ID,
      T15.ROW_ID,
      T28.ROW_ID,
      T26.ROW_ID,
      T3.ROW_ID,
      T18.ROW_ID,
      T5.ROW_ID,
      T2.ROW_ID,
      T31.ROW_ID,
      T9.ROW_ID,
      T25.ROW_ID,
      T17.ROW_ID
   FROM 
       SIEBEL.S_POSTN T1,
       SIEBEL.S_ADDR_ORG T2,
       SIEBEL.S_ADDR_ORG T3,
       SIEBEL.S_ORG_EXT_X T4,
       SIEBEL.S_OPTY T5,
       SIEBEL.S_DOC_AGREE T6,
       SIEBEL.S_ORG_EXT T7,
       SIEBEL.S_POSTN T8,
       SIEBEL.S_PARTY T9,
       SIEBEL.S_PARTY T10,
       SIEBEL.S_ADDR_ORG T11,
       SIEBEL.S_PRI_LST T12,
       SIEBEL.S_ASGN_GRP T13,
       SIEBEL.S_CONTACT T14,
       SIEBEL.S_PARTY T15,
       SIEBEL.S_USER T16,
       SIEBEL.S_INDUST T17,
       SIEBEL.S_ADDR_ORG T18,
       SIEBEL.S_ORG_EXT_SS T19,
       SIEBEL.S_LST_OF_VAL T20,
       SIEBEL.S_ORG_EXT T21,
       SIEBEL.S_ORG_EXT T22,
       SIEBEL.S_DQ_ORG_KEY T23,
       SIEBEL.S_USER T24,
       SIEBEL.S_ORG_INDUST T25,
       SIEBEL.S_PARTY T26,
       SIEBEL.S_ORG_EXT T27,
       SIEBEL.S_ACCNT_POSTN T28,
       SIEBEL.S_LST_OF_VAL T29,
       SIEBEL.S_ADDR_ORG_X T30,
       SIEBEL.S_ORG_BU T31,
       SIEBEL.S_CONTACT_X T32,
       SIEBEL.S_ORG_EXT T33
   WHERE 
      T4.ATTRIB_42 = T16.ROW_ID (+) AND
      T33.PR_BL_OU_ID = T22.PAR_ROW_ID (+) AND
      T33.PAR_OU_ID = T7.PAR_ROW_ID (+) AND
      T33.PR_ADDR_ID = T11.ROW_ID (+) AND
      T33.PR_POSTN_ID = T1.PAR_ROW_ID (+) AND
      T1.PR_EMP_ID = T14.PAR_ROW_ID (+) AND
      T1.PR_EMP_ID = T32.PAR_ROW_ID (+) AND
      T1.PR_TERR_ID = T13.ROW_ID (+) AND
      T10.ROW_ID = T23.ACCNT_ID (+) AND
      T4.ATTRIB_34 = T29.VAL (+) AND T29.ACTIVE_FLG (+) = 'Y' AND T29.TYPE (+) = 'PARTNER_VT_KANAL' AND
      T33.CURR_PRI_LST_ID = T12.ROW_ID (+) AND
      T33.X_SCELETON_CONTRACT = T6.ROW_ID (+) AND
      T10.ROW_ID = T33.PAR_ROW_ID AND
      T10.ROW_ID = T19.PAR_ROW_ID (+) AND
      T10.ROW_ID = T4.PAR_ROW_ID (+) AND
      T33.X_TYPE_2 = T20.NAME (+) AND T20.TYPE (+) = 'ACCOUNT_TYPE_2' AND T20.LANG_ID (+) = :1 AND
      T33.X_VERTRAGSPARTNER_ID = T15.ROW_ID (+) AND
      T33.X_VERTRAGSPARTNER_ID = T27.PAR_ROW_ID (+) AND
      T28.POSITION_ID = :2 AND T33.ROW_ID = T28.OU_EXT_ID AND
      T26.ROW_ID = T28.POSITION_ID AND
      T28.POSITION_ID = T8.PAR_ROW_ID (+) AND
      T8.PR_EMP_ID = T24.PAR_ROW_ID (+) AND
      T33.PR_ADDR_ID = T3.ROW_ID (+) AND
      T33.PR_ADDR_ID = T30.PAR_ROW_ID (+) AND
      T33.PR_SHIP_ADDR_ID = T18.ROW_ID (+) AND
      T33.X_PR_OPTY_ID = T5.ROW_ID (+) AND
      T33.PR_BL_ADDR_ID = T2.ROW_ID (+) AND
      T33.BU_ID = T31.BU_ID (+) AND T33.ROW_ID = T31.ORG_ID (+) AND
      T31.BU_ID = T9.ROW_ID (+) AND
      T31.BU_ID = T21.PAR_ROW_ID (+) AND
      T33.PR_INDUST_ID = T25.INDUST_ID (+) AND T33.ROW_ID = T25.OU_ID (+) AND
      T33.PR_INDUST_ID = T17.ROW_ID (+) AND
      ((T10.ROW_ID IS NOT NULL) AND
      (T33.INT_ORG_FLG != 'Y' OR T33.PRTNR_FLG = 'Y'))
   ORDER BY
      T28.POSITION_ID, T20.VAL





Bind variable 1: DEU
Bind variable 2: 1-1CWC



your cooporation is highly appreciated

Thanks.
Re: SQL statment running for ever [message #464872 is a reply to message #464871] Sat, 10 July 2010 02:21 Go to previous messageGo to next message
samiraly
Messages: 57
Registered: June 2009
Member

FYI
temp table space was 8 GB and after this error i added another 8 GB
Re: SQL statment running for ever [message #464881 is a reply to message #464872] Sat, 10 July 2010 03:51 Go to previous messageGo to next message
cookiemonster
Messages: 13959
Registered: September 2008
Location: Rainy Manchester
Senior Member
Post an explain plan.
Do all those outer-joins really need to be outer-joins?
I suspect they're the main problem.
Re: SQL statment running for ever [message #464890 is a reply to message #464881] Sat, 10 July 2010 07:47 Go to previous messageGo to next message
samiraly
Messages: 57
Registered: June 2009
Member


Thank you for fast response here is explain plan

Explained.

SQL> select Operation , Object_name ,  optimizer from plan_table;

OPERATION				 OBJECT_NAME	      OPTIMIZER
---------------------------------------- -------------------- --------------------
INDEX					 S_ADDR_ORG_X_U1      ANALYZED
TABLE ACCESS				 S_DOC_AGREE	      ANALYZED
INDEX					 S_DOC_AGREE_P1       ANALYZED
INDEX					 S_PARTY_P1	      ANALYZED
TABLE ACCESS				 S_PARTY	      ANALYZED
TABLE ACCESS				 S_ORG_EXT_X	      ANALYZED
INDEX					 S_ORG_EXT_X_U2
TABLE ACCESS				 S_LST_OF_VAL	      ANALYZED
INDEX					 S_LST_OF_VAL_U1      ANALYZED
TABLE ACCESS				 S_USER 	      ANALYZED
INDEX					 S_USER_P1	      ANALYZED

OPERATION				 OBJECT_NAME	      OPTIMIZER
---------------------------------------- -------------------- --------------------
TABLE ACCESS				 S_ORG_EXT	      ANALYZED
INDEX					 S_ORG_EXT_U3	      ANALYZED
TABLE ACCESS				 S_POSTN	      ANALYZED
INDEX					 S_POSTN_U2	      ANALYZED
TABLE ACCESS				 S_CONTACT_X	      ANALYZED
INDEX					 S_CONTACT_X_U1       ANALYZED
TABLE ACCESS				 S_ADDR_ORG	      ANALYZED
INDEX					 S_ADDR_ORG_P1	      ANALYZED
TABLE ACCESS				 S_CONTACT	      ANALYZED
INDEX					 S_CONTACT_U2	      ANALYZED
TABLE ACCESS				 S_ORG_EXT	      ANALYZED

OPERATION				 OBJECT_NAME	      OPTIMIZER
---------------------------------------- -------------------- --------------------
INDEX					 S_ORG_EXT_U3	      ANALYZED
TABLE ACCESS				 S_ASGN_GRP	      ANALYZED
INDEX					 S_ASGN_GRP_P1	      ANALYZED
TABLE ACCESS				 S_ADDR_ORG	      ANALYZED
INDEX					 S_ADDR_ORG_P1	      ANALYZED
TABLE ACCESS				 S_ADDR_ORG	      ANALYZED
INDEX					 S_ADDR_ORG_P1	      ANALYZED
INDEX					 S_PARTY_P1	      ANALYZED
TABLE ACCESS				 S_USER 	      ANALYZED
INDEX					 S_USER_U2	      ANALYZED
TABLE ACCESS				 S_ORG_EXT	      ANALYZED

OPERATION				 OBJECT_NAME	      OPTIMIZER
---------------------------------------- -------------------- --------------------
INDEX					 S_ORG_EXT_P1	      ANALYZED
TABLE ACCESS				 S_PRI_LST	      ANALYZED
INDEX					 S_PRI_LST_P1	      ANALYZED
TABLE ACCESS				 S_ORG_INDUST	      ANALYZED
INDEX					 S_ORG_INDUST_U1      ANALYZED
TABLE ACCESS				 S_ORG_EXT	      ANALYZED
INDEX					 S_ORG_EXT_U3	      ANALYZED
TABLE ACCESS				 S_ORG_BU	      ANALYZED
INDEX					 S_ORG_BU_F4	      ANALYZED
TABLE ACCESS				 S_ADDR_ORG	      ANALYZED
INDEX					 S_ADDR_ORG_P1	      ANALYZED

OPERATION				 OBJECT_NAME	      OPTIMIZER
---------------------------------------- -------------------- --------------------
TABLE ACCESS				 S_OPTY 	      ANALYZED
INDEX					 S_OPTY_P1	      ANALYZED
TABLE ACCESS				 S_ORG_EXT	      ANALYZED
INDEX					 S_ORG_EXT_U3	      ANALYZED
INDEX					 S_PARTY_P1	      ANALYZED
TABLE ACCESS				 S_ADDR_ORG_X	      ANALYZED
NESTED LOOPS
NESTED LOOPS
INDEX					 S_PARTY_P1	      ANALYZED
TABLE ACCESS				 S_ACCNT_POSTN	      ANALYZED
INDEX					 S_ACCNT_POSTN_M1

OPERATION				 OBJECT_NAME	      OPTIMIZER
---------------------------------------- -------------------- --------------------
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS

OPERATION				 OBJECT_NAME	      OPTIMIZER
---------------------------------------- -------------------- --------------------
NESTED LOOPS
HASH JOIN
TABLE ACCESS				 S_ORG_EXT_SS	      ANALYZED
HASH JOIN
INDEX					 S_DQ_ORG_KEY_U1      ANALYZED
HASH JOIN
TABLE ACCESS				 S_LST_OF_VAL	      ANALYZED
INDEX					 S_LST_OF_VAL_U1      ANALYZED
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS

OPERATION				 OBJECT_NAME	      OPTIMIZER
---------------------------------------- -------------------- --------------------
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
HASH JOIN
TABLE ACCESS				 S_INDUST	      ANALYZED
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
SELECT STATEMENT					      ALL_ROWS

OPERATION				 OBJECT_NAME	      OPTIMIZER
---------------------------------------- -------------------- --------------------
SORT
NESTED LOOPS
HASH JOIN
TABLE ACCESS				 S_POSTN	      ANALYZED
INDEX					 S_POSTN_U2	      ANALYZED
NESTED LOOPS
NESTED LOOPS

95 rows selected.

SQL> 
Re: SQL statment running for ever [message #464891 is a reply to message #464890] Sat, 10 July 2010 09:04 Go to previous messageGo to next message
Michel Cadot
Messages: 68716
Registered: March 2007
Location: Saint-Maur, France, https...
Senior Member
Account Moderator
Never heard about dbms_xplan?
Do you think this is a plan? I understand you cannot improve the statement by yourself if you think this is an execution plan.

Regards
Michel
Re: SQL statment running for ever [message #464902 is a reply to message #464891] Sat, 10 July 2010 09:54 Go to previous messageGo to next message
rahulvb
Messages: 924
Registered: October 2009
Location: Somewhere Near Equator.
Senior Member
Please use follwing statement to get the explain plan.

select * from table(dbms_xplan.display);


If you are still not clear please search for dbms_xplan example.
Re: SQL statment running for ever [message #464914 is a reply to message #464902] Sat, 10 July 2010 13:11 Go to previous messageGo to next message
samiraly
Messages: 57
Registered: June 2009
Member

Hello
Here is output thank you for help

SQL> set linesize 400
SQL> select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 3820162769

---------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation						     | Name		| Rows	| Bytes | Cost (%CPU)| Time	|
---------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT					     |			|   291 |   519K|   140   (3)| 00:00:02 |
|   1 |  SORT ORDER BY						     |			|   291 |   519K|   140   (3)| 00:00:02 |
|   2 |   NESTED LOOPS OUTER					     |			|   291 |   519K|   139   (2)| 00:00:02 |
|*  3 |    HASH JOIN RIGHT OUTER				     |			|   291 |   514K|   136   (2)| 00:00:02 |
|   4 |     TABLE ACCESS BY INDEX ROWID 			     | S_POSTN		|     1 |    18 |     1   (0)| 00:00:01 |
|*  5 |      INDEX UNIQUE SCAN					     | S_POSTN_U2	|     1 |	|     1   (0)| 00:00:01 |

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|   6 |     NESTED LOOPS OUTER					     |			|   291 |   509K|   135   (2)| 00:00:02 |
|   7 |      NESTED LOOPS OUTER 				     |			|   291 |   506K|   134   (2)| 00:00:02 |
|   8 |       NESTED LOOPS OUTER				     |			|   291 |   495K|   133   (2)| 00:00:02 |
|   9 |        NESTED LOOPS OUTER				     |			|   291 |   477K|   130   (2)| 00:00:02 |
|  10 | 	NESTED LOOPS OUTER				     |			|   291 |   472K|   127   (2)| 00:00:02 |
|* 11 | 	 HASH JOIN RIGHT OUTER				     |			|   291 |   469K|   124   (2)| 00:00:02 |
|  12 | 	  TABLE ACCESS FULL				     | S_INDUST 	|   163 |  5542 |     2   (0)| 00:00:01 |
|  13 | 	  NESTED LOOPS OUTER				     |			|   291 |   459K|   121   (1)| 00:00:02 |
|  14 | 	   NESTED LOOPS OUTER				     |			|   291 |   453K|   119   (2)| 00:00:02 |
|  15 | 	    NESTED LOOPS OUTER				     |			|   291 |   446K|   116   (2)| 00:00:02 |
|  16 | 	     NESTED LOOPS OUTER 			     |			|   291 |   443K|   110   (2)| 00:00:02 |

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|  17 | 	      NESTED LOOPS OUTER			     |			|   291 |   431K|   107   (2)| 00:00:02 |
|  18 | 	       NESTED LOOPS OUTER			     |			|   291 |   422K|   104   (1)| 00:00:02 |
|  19 | 		NESTED LOOPS OUTER			     |			|   291 |   417K|   103   (1)| 00:00:02 |
|  20 | 		 NESTED LOOPS OUTER			     |			|   291 |   408K|   102   (1)| 00:00:02 |
|* 21 | 		  HASH JOIN RIGHT OUTER 		     |			|   291 |   360K|    96   (2)| 00:00:02 |
|  22 | 		   TABLE ACCESS BY INDEX ROWID		     | S_LST_OF_VAL	|     5 |   220 |     1   (0)| 00:00:01 |
|* 23 | 		    INDEX RANGE SCAN			     | S_LST_OF_VAL_U1	|     5 |	|     1   (0)| 00:00:01 |
|* 24 | 		   HASH JOIN RIGHT OUTER		     |			|   291 |   347K|    95   (2)| 00:00:02 |
|  25 | 		    INDEX FULL SCAN			     | S_DQ_ORG_KEY_U1	|     1 |   101 |     1   (0)| 00:00:01 |
|* 26 | 		    HASH JOIN RIGHT OUTER		     |			|   291 |   319K|    93   (0)| 00:00:02 |
|  27 | 		     TABLE ACCESS FULL			     | S_ORG_EXT_SS	|     1 |   137 |     2   (0)| 00:00:01 |

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|  28 | 		     NESTED LOOPS			     |			|	|	|	     |		|
|  29 | 		      NESTED LOOPS			     |			|   291 |   280K|    91   (0)| 00:00:02 |
|  30 | 		       NESTED LOOPS OUTER		     |			|   915 |   819K|    82   (0)| 00:00:01 |
|  31 | 			NESTED LOOPS OUTER		     |			|   915 |   804K|    80   (0)| 00:00:01 |
|  32 | 			 NESTED LOOPS OUTER		     |			|   915 |   699K|    61   (0)| 00:00:01 |
|  33 | 			  NESTED LOOPS OUTER		     |			|   915 |   691K|    60   (0)| 00:00:01 |
|  34 | 			   NESTED LOOPS OUTER		     |			|   915 |   663K|    51   (0)| 00:00:01 |
|  35 | 			    NESTED LOOPS OUTER		     |			|   915 |   645K|    50   (0)| 00:00:01 |
|  36 | 			     NESTED LOOPS OUTER 	     |			|   915 |   621K|    49   (0)| 00:00:01 |
|  37 | 			      NESTED LOOPS OUTER	     |			|   915 |   598K|    40   (0)| 00:00:01 |
|  38 | 			       NESTED LOOPS OUTER	     |			|   915 |   570K|    30   (0)| 00:00:01 |

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|  39 | 				NESTED LOOPS OUTER	     |			|   915 |   547K|    12   (0)| 00:00:01 |
|  40 | 				 NESTED LOOPS		     |			|   915 |   524K|    11   (0)| 00:00:01 |
|  41 | 				  NESTED LOOPS		     |			|   915 | 37515 |     2   (0)| 00:00:01 |
|* 42 | 				   INDEX UNIQUE SCAN	     | S_PARTY_P1	|     1 |     9 |     1   (0)| 00:00:01 |
|  43 | ID				   TABLE ACCESS BY INDEX ROW | S_ACCNT_POSTN	|   915 | 29280 |     1   (0)| 00:00:01 |
|* 44 | 				    INDEX RANGE SCAN	     | S_ACCNT_POSTN_M1 |   915 |	|     1   (0)| 00:00:01 |
|* 45 | D				  TABLE ACCESS BY INDEX ROWI | S_ORG_EXT	|     1 |   546 |     1   (0)| 00:00:01 |
|* 46 | 				   INDEX UNIQUE SCAN	     | S_ORG_EXT_P1	|     1 |	|     1   (0)| 00:00:01 |
|  47 | 				 TABLE ACCESS BY INDEX ROWID | S_PRI_LST	|     1 |    26 |     1   (0)| 00:00:01 |
|* 48 | 				  INDEX UNIQUE SCAN	     | S_PRI_LST_P1	|     1 |	|     1   (0)| 00:00:01 |
|  49 | 				TABLE ACCESS BY INDEX ROWID  | S_ORG_INDUST	|     1 |    26 |     1   (0)| 00:00:01 |

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|* 50 | 				 INDEX RANGE SCAN	     | S_ORG_INDUST_U1	|     1 |	|     1   (0)| 00:00:01 |
|  51 | 			       TABLE ACCESS BY INDEX ROWID   | S_ORG_EXT	|     1 |    31 |     1   (0)| 00:00:01 |
|* 52 | 				INDEX UNIQUE SCAN	     | S_ORG_EXT_U3	|     1 |	|     1   (0)| 00:00:01 |
|* 53 | 			      TABLE ACCESS BY INDEX ROWID    | S_ORG_BU 	|     1 |    26 |     1   (0)| 00:00:01 |
|* 54 | 			       INDEX RANGE SCAN 	     | S_ORG_BU_F4	|     1 |	|     1   (0)| 00:00:01 |
|  55 | 			     TABLE ACCESS BY INDEX ROWID     | S_ADDR_ORG	|     1 |    26 |     1   (0)| 00:00:01 |
|* 56 | 			      INDEX UNIQUE SCAN 	     | S_ADDR_ORG_P1	|     1 |	|     1   (0)| 00:00:01 |
|  57 | 			    TABLE ACCESS BY INDEX ROWID      | S_OPTY		|     1 |    21 |     1   (0)| 00:00:01 |
|* 58 | 			     INDEX UNIQUE SCAN		     | S_OPTY_P1	|     1 |	|     1   (0)| 00:00:01 |
|  59 | 			   TABLE ACCESS BY INDEX ROWID	     | S_ORG_EXT	|     1 |    31 |     1   (0)| 00:00:01 |
|* 60 | 			    INDEX UNIQUE SCAN		     | S_ORG_EXT_U3	|     1 |	|     1   (0)| 00:00:01 |

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|* 61 | 			  INDEX UNIQUE SCAN		     | S_PARTY_P1	|     1 |     9 |     1   (0)| 00:00:01 |
|  62 | 			 TABLE ACCESS BY INDEX ROWID	     | S_ADDR_ORG_X	|     1 |   117 |     1   (0)| 00:00:01 |
|* 63 | 			  INDEX RANGE SCAN		     | S_ADDR_ORG_X_U1	|     1 |	|     1   (0)| 00:00:01 |
|  64 | 			TABLE ACCESS BY INDEX ROWID	     | S_DOC_AGREE	|     1 |    17 |     1   (0)| 00:00:01 |
|* 65 | 			 INDEX UNIQUE SCAN		     | S_DOC_AGREE_P1	|     1 |	|     1   (0)| 00:00:01 |
|* 66 | 		       INDEX UNIQUE SCAN		     | S_PARTY_P1	|     1 |	|     1   (0)| 00:00:01 |
|  67 | 		      TABLE ACCESS BY INDEX ROWID	     | S_PARTY		|     1 |    69 |     1   (0)| 00:00:01 |
|  68 | 		  TABLE ACCESS BY INDEX ROWID		     | S_ORG_EXT_X	|     1 |   168 |     1   (0)| 00:00:01 |
|* 69 | 		   INDEX RANGE SCAN			     | S_ORG_EXT_X_U2	|     1 |	|     1   (0)| 00:00:01 |
|* 70 | 		 TABLE ACCESS BY INDEX ROWID		     | S_LST_OF_VAL	|     1 |    34 |     1   (0)| 00:00:01 |
|* 71 | 		  INDEX RANGE SCAN			     | S_LST_OF_VAL_U1	|     1 |	|     1   (0)| 00:00:01 |

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|  72 | 		TABLE ACCESS BY INDEX ROWID		     | S_USER		|     1 |    18 |     1   (0)| 00:00:01 |
|* 73 | 		 INDEX UNIQUE SCAN			     | S_USER_P1	|     1 |	|     1   (0)| 00:00:01 |
|  74 | 	       TABLE ACCESS BY INDEX ROWID		     | S_ORG_EXT	|     1 |    31 |     1   (0)| 00:00:01 |
|* 75 | 		INDEX UNIQUE SCAN			     | S_ORG_EXT_U3	|     1 |	|     1   (0)| 00:00:01 |
|  76 | 	      TABLE ACCESS BY INDEX ROWID		     | S_POSTN		|     1 |    41 |     1   (0)| 00:00:01 |
|* 77 | 	       INDEX UNIQUE SCAN			     | S_POSTN_U2	|     1 |	|     1   (0)| 00:00:01 |
|  78 | 	     TABLE ACCESS BY INDEX ROWID		     | S_CONTACT_X	|     1 |    11 |     1   (0)| 00:00:01 |
|* 79 | 	      INDEX RANGE SCAN				     | S_CONTACT_X_U1	|     1 |	|     1   (0)| 00:00:01 |
|  80 | 	    TABLE ACCESS BY INDEX ROWID 		     | S_ADDR_ORG	|     1 |    26 |     1   (0)| 00:00:01 |
|* 81 | 	     INDEX UNIQUE SCAN				     | S_ADDR_ORG_P1	|     1 |	|     1   (0)| 00:00:01 |
|  82 | 	   TABLE ACCESS BY INDEX ROWID			     | S_CONTACT	|     1 |    20 |     1   (0)| 00:00:01 |

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|* 83 | 	    INDEX UNIQUE SCAN				     | S_CONTACT_U2	|     1 |	|     1   (0)| 00:00:01 |
|  84 | 	 TABLE ACCESS BY INDEX ROWID			     | S_ORG_EXT	|     1 |    11 |     1   (0)| 00:00:01 |
|* 85 | 	  INDEX UNIQUE SCAN				     | S_ORG_EXT_U3	|     1 |	|     1   (0)| 00:00:01 |
|  86 | 	TABLE ACCESS BY INDEX ROWID			     | S_ASGN_GRP	|     1 |    19 |     1   (0)| 00:00:01 |
|* 87 | 	 INDEX UNIQUE SCAN				     | S_ASGN_GRP_P1	|     1 |	|     1   (0)| 00:00:01 |
|  88 |        TABLE ACCESS BY INDEX ROWID			     | S_ADDR_ORG	|     1 |    61 |     1   (0)| 00:00:01 |
|* 89 | 	INDEX UNIQUE SCAN				     | S_ADDR_ORG_P1	|     1 |	|     1   (0)| 00:00:01 |
|  90 |       TABLE ACCESS BY INDEX ROWID			     | S_ADDR_ORG	|     1 |    42 |     1   (0)| 00:00:01 |
|* 91 |        INDEX UNIQUE SCAN				     | S_ADDR_ORG_P1	|     1 |	|     1   (0)| 00:00:01 |
|* 92 |      INDEX UNIQUE SCAN					     | S_PARTY_P1	|     1 |     9 |     1   (0)| 00:00:01 |
|  93 |    TABLE ACCESS BY INDEX ROWID				     | S_USER		|     1 |    18 |     1   (0)| 00:00:01 |

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|* 94 |     INDEX UNIQUE SCAN					     | S_USER_U2	|     1 |	|     1   (0)| 00:00:01 |
---------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access("T28"."POSITION_ID"="T8"."PAR_ROW_ID"(+))
   5 - access("T8"."PAR_ROW_ID"(+)='1-1CWC')
  11 - access("T33"."PR_INDUST_ID"="T17"."ROW_ID"(+))
  21 - access("T33"."X_TYPE_2"="T20"."NAME"(+))
  23 - access("T20"."TYPE"(+)='ACCOUNT_TYPE_2' AND "T20"."LANG_ID"(+)='DEU')

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
       filter("T20"."LANG_ID"(+)='DEU')
  24 - access("T10"."ROW_ID"="T23"."ACCNT_ID"(+))
  26 - access("T10"."ROW_ID"="T19"."PAR_ROW_ID"(+))
  42 - access("T26"."ROW_ID"='1-1CWC')
  44 - access("T28"."POSITION_ID"='1-1CWC')
  45 - filter("T33"."INT_ORG_FLG"<>'Y' OR "T33"."PRTNR_FLG"='Y')
  46 - access("T33"."ROW_ID"="T28"."OU_EXT_ID")
  48 - access("T33"."CURR_PRI_LST_ID"="T12"."ROW_ID"(+))
  50 - access("T33"."ROW_ID"="T25"."OU_ID"(+) AND "T33"."PR_INDUST_ID"="T25"."INDUST_ID"(+))
  52 - access("T33"."PR_BL_OU_ID"="T22"."PAR_ROW_ID"(+))
  53 - filter("T33"."BU_ID"="T31"."BU_ID"(+))

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
  54 - access("T33"."ROW_ID"="T31"."ORG_ID"(+))
  56 - access("T33"."PR_SHIP_ADDR_ID"="T18"."ROW_ID"(+))
  58 - access("T33"."X_PR_OPTY_ID"="T5"."ROW_ID"(+))
  60 - access("T33"."X_VERTRAGSPARTNER_ID"="T27"."PAR_ROW_ID"(+))
  61 - access("T33"."X_VERTRAGSPARTNER_ID"="T15"."ROW_ID"(+))
  63 - access("T33"."PR_ADDR_ID"="T30"."PAR_ROW_ID"(+))
  65 - access("T33"."X_SCELETON_CONTRACT"="T6"."ROW_ID"(+))
  66 - access("T10"."ROW_ID"="T33"."PAR_ROW_ID")
  69 - access("T10"."ROW_ID"="T4"."PAR_ROW_ID"(+))
  70 - filter("T29"."ACTIVE_FLG"(+)='Y')
  71 - access("T29"."TYPE"(+)='PARTNER_VT_KANAL' AND "T4"."ATTRIB_34"="T29"."VAL"(+))

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
  73 - access("T4"."ATTRIB_42"="T16"."ROW_ID"(+))
  75 - access("T33"."PAR_OU_ID"="T7"."PAR_ROW_ID"(+))
  77 - access("T33"."PR_POSTN_ID"="T1"."PAR_ROW_ID"(+))
  79 - access("T1"."PR_EMP_ID"="T32"."PAR_ROW_ID"(+))
  81 - access("T33"."PR_BL_ADDR_ID"="T2"."ROW_ID"(+))
  83 - access("T1"."PR_EMP_ID"="T14"."PAR_ROW_ID"(+))
  85 - access("T31"."BU_ID"="T21"."PAR_ROW_ID"(+))
  87 - access("T1"."PR_TERR_ID"="T13"."ROW_ID"(+))
  89 - access("T33"."PR_ADDR_ID"="T3"."ROW_ID"(+))
  91 - access("T33"."PR_ADDR_ID"="T11"."ROW_ID"(+))
  92 - access("T31"."BU_ID"="T9"."ROW_ID"(+))

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
  94 - access("T8"."PR_EMP_ID"="T24"."PAR_ROW_ID"(+))

144 rows selected.

SQL> 
Re: SQL statment running for ever [message #464916 is a reply to message #464914] Sat, 10 July 2010 13:17 Go to previous messageGo to next message
BlackSwan
Messages: 26766
Registered: January 2009
Location: SoCal
Senior Member
big query against 33 tables & many outer joins is slow
It is what it is.
I am glad I no longer have to support Siebel
Re: SQL statment running for ever [message #464920 is a reply to message #464916] Sat, 10 July 2010 14:12 Go to previous messageGo to next message
samiraly
Messages: 57
Registered: June 2009
Member

Smile you are glad that you no lonnger support sieble and i am sad i have to support sieble , so any clue
i had enlarget database buffer cash to minimize disk reads , by the way idid select count for this query more than 5 milion rows should be retrieved

Smile THANKS
Re: SQL statment running for ever [message #464931 is a reply to message #464871] Sun, 11 July 2010 00:18 Go to previous message
rleishman
Messages: 3728
Registered: October 2005
Location: Melbourne, Australia
Senior Member
If you are running out of TEMP space, then it is either the HASH joins or the ORDER BY that is using up all of that space.

Note that the innermost table in your Explain Plan at step 42 has the filter:
 42 - access("T26"."ROW_ID"='1-1CWC')

So for you to run out of TEMP space, it means that this filter is not very selective (selects lots of data).

I can also see from your plan that most of your joins are on Unique keys, but some of them are performing Range Scans and some Hash Joins. Are you sure that these joins are unique? Or are you joining many-to-many there somewhere. If so, that would probably explain the TEMP segment blowing out: many-to-many join generates millions of rows, ORDER BY tries to sort all of them.

If you remove the ORDER BY do you get the right results (albeit unsorted), or are there duplicates?

Ross Leishman
Previous Topic: Query Performance trace
Next Topic: Tools for Database Tuning v/s Instance Tuning
Goto Forum:
  


Current Time: Thu Nov 28 20:24:24 CST 2024