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: PLAN_TABLE gotcha in 10g

Re: PLAN_TABLE gotcha in 10g

From: Mladen Gogala <mladen_at_wangtrading.com>
Date: Wed, 5 May 2004 17:30:35 -0400
Message-ID: <20040505213035.GA3975@mladen.wangtrading.com>

On 05/05/2004 05:08:03 PM, Daniel Fink wrote:
> I've been working with some sql in a new 10g db doing the
> typical 'explain plan for ' syntax. Today, I decided to preserve
> some of the plans, so I set statement_ids and commited them. Lo
> and behold, they were not there when I went back later in the
> day. In 10g, a PLAN_TABLE$ table is created and given the PUBLIC
> synonym PLAN_TABLE. Convenient, now I don't have to run utlxplan
> for every user. Just be disciplined and use distinct
> statement_ids. Unfortunately, the PLAN_TABLE$ is a global
> temporary table, so my records are deleted when the session
> ends! ARGH! FYI, this table is created with the catplan.sql
> script that is called by catalog.sql.

Of course, you can explain plan into your own table. It would go like this:

create table plan_for_dan as select * from plan_table where rownum<0;

and then:

EXPLAIN PLAN
   SET STATEMENT_ID = 'df1'
   INTO PLAN_FOR_DAN
 FOR
SELECT ename FROM scott.emp;

To link things with the classic setup, you can create a synonym PLAN_TABLE for "PLAN_FOR_DAN". Did you notice that the word PLAN rhymes with your name? That gives the suggested table name some special allure.

>
> Okay, Pete. Where's the doc on this one? ;)

Coming with the next weekly tip.

-- 
Mladen Gogala
Oracle DBA



Note:
This message is for the named person's use only.  It may contain confidential, proprietary or legally privileged information.  No confidentiality or privilege is waived or lost by any mistransmission.  If you receive this message in error, please immediately delete it and all copies of it from your system, destroy any hard copies of it and notify the sender.  You must not, directly or indirectly, use, disclose, distribute, print, or copy any part of this message if you are not the intended recipient. Wang Trading LLC and any of its subsidiaries each reserve the right to monitor all e-mail communications through its networks.
Any views expressed in this message are those of the individual sender, except where the message states otherwise and the sender is authorized to state them to be the views of any such entity.

----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com
----------------------------------------------------------------
To unsubscribe send email to:  oracle-l-request_at_freelists.org
put 'unsubscribe' in the subject line.
--
Archives are at http://www.freelists.org/archives/oracle-l/
FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------
Received on Wed May 05 2004 - 16:27:44 CDT

Original text of this message

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