SQL_PLAN – other_xml

Just a quick follow-up to my previous post on investigating bad plans using AWR & ASH.

In that article, I mentioned

  1. that it was a shame that the ACCESS_PREDICATES and FILTER_PREDICATES columns were not populated (how this cannot be classified as a bug is beyond comprehension) and
  2. that I was using DBA_HIST_SQLBIND to investigate various peeked binds for that particular SQL based on the LAST_CAPTURED column

However, I should also have mentioned that, from 10gR2 onwards, populated in both V$SQL_PLAN and DBA_HIST_SQL_PLAN, there is a very useful column called OTHER_XML.

From the documentation:

OTHER_XML: “Provides extra information specific to an execution step of the execution plan. The content of this column is structured using XML because it allows multiple pieces of information to be stored, including the following:

  • Name of the schema against which the query was parsed.
  • Release number of the Oracle Database that produced the explain plan.
  • Hash value associated with the execution plan.
  • Name (if any) of the outline or the SQL profile used to build the execution plan.
  • Indication of whether or not dynamic sampling was used to produce the plan.
  • The outline data, a set of optimizer hints that can be used to regenerate the same plan.

Here is a sample of the peeked bind section from my sql with the problem plan:


  <peeked_binds>
    <bind nam=”:B3″ pos=”3″ dty=”2″ pre=”0″ scl=”0″ mxl=”22″>c3023102</bind>
    <bind nam=”:B2″ pos=”4″ dty=”1″ csi=”873″ frm=”1″ mxl=”32″>524d46</bind>
    <bind nam=”:B1″ pos=”5″ dty=”12″ mxl=”7″>786d0a1f010101</bind>
    <bind nam=”:B3″ pos=”13″ ppo=”3″ dty=”2″ pre=”0″ scl=”0″ mxl=”22″/>
    <bind nam=”:B2″ pos=”14″ ppo=”4″ dty=”1″ csi=”873″ frm=”1″ mxl=”32″/>
    <bind nam=”:B1″ pos=”15″ ppo=”5″ dty=”12″ mxl=”7″/>
    <bind nam=”:B3″ pos=”16″ ppo=”3″ dty=”2″ pre=”0″ scl=”0″ mxl=”22″/>
    <bind nam=”:B1″ pos=”19″ ppo=”5″ dty=”12″ mxl=”7″/>
    <bind nam=”:B3″ pos=”20″ ppo=”3″ dty=”2″ pre=”0″ scl=”0″ mxl=”22″/>
    <bind nam=”:B5″ pos=”21″ ppo=”1″ dty=”2″ pre=”0″ scl=”0″ mxl=”22″/>
    <bind nam=”:B3″ pos=”22″ ppo=”3″ dty=”2″ pre=”0″ scl=”0″ mxl=”22″/>
    <bind nam=”:B6″ pos=”23″ dty=”2″ pre=”0″ scl=”0″ mxl=”22″>c10d</bind>
    <bind nam=”:B1″ pos=”24″ ppo=”5″ dty=”12″ mxl=”7″/>
    <bind nam=”:B6″ pos=”26″ ppo=”23″ dty=”2″ pre=”0″ scl=”0″ mxl=”22″/>
    <bind nam=”:B1″ pos=”27″ ppo=”5″ dty=”12″ mxl=”7″/>
    <bind nam=”:B1″ pos=”29″ ppo=”5″ dty=”12″ mxl=”7″/>
    <bind nam=”:B3″ pos=”31″ ppo=”3″ dty=”2″ pre=”0″ scl=”0″ mxl=”22″/>
    <bind nam=”:B6″ pos=”32″ ppo=”23″ dty=”2″ pre=”0″ scl=”0″ mxl=”22″/>
    <bind nam=”:B1″ pos=”33″ ppo=”5″ dty=”12″ mxl=”7″/>
  </peeked_binds>

I’m not sure if the repetition of bind names and positions but not values is normal – one for further investigation.

But bind variable 1 is what I was talking about previously as my date bind with the data skew and we can convert the values back out of their raw value using, for example, the overloaded DBMS_STATS.CONVERT_RAW_VALUE.

So, from above, taking my B1 bind of “786d0a1f010101″:

declare
l_date date;
begin
dbms_stats.convert_raw_value(rawval => '786d0a1f010101', resval => l_date);
dbms_output.put_line('dt: '||to_char(l_date,'DD/MM/YYYY HH24:MI:SS'));
end;
/

dt: 31/10/2009 00:00:00

Some other posts regarding OTHER_XML:
Kerry Osborne using OTHER_XML to create test scripts with bind variables
Randolf Geist using OTHER_XML to get outlines / create profiles

Varying IN lists – last bit

So, just a final say on this series of blog entries.

The first is that often you start down one workaround and then you find something that doesn’t quite work so you workaround that and before you know it you’re along way from where you’d like to be.

What started as a simple desire to reduce the impact of dynamically generated varying IN lists (some not using bind variables) from a couple of applications was severely complicated by ODP.NET’s lack of support / interoperability with Oracle UDTs and the OCI limit of 4000 characters in a VARCHAR2 bind.

As a result, the current choice is between the original situation – lots of similar SQL – and inserting the values into a GLOBAL TEMPORARY TABLE and then using a query which has a WHERE … IN subquery selecting from that GTT. More on that down below…

When I wrote previously, also under consideration was using a global packaged variable. However this was eliminated as a possibility due to at least three frustrating issues. First up was an idea to use a function that would convert an associative array (supported by ODP.NET) to a similar UDT (just using a FOR LOOP that puts the values from one into the other). Using a bit of PL/SQL to demonstrate (8i hence the lack of SYS_REFCURSOR and the need to declare a REF CURSOR in a package):


CREATE OR REPLACE TYPE tt_number AS TABLE OF NUMBER;
/


CREATE OR REPLACE PACKAGE pkg_types
AS
--
TYPE refcursor IS REF CURSOR;
TYPE aa_number IS TABLE OF NUMBER INDEX BY BINARY_INTEGER;
--
END pkg_types;
/


CREATE OR REPLACE FUNCTION f_tt_convert_error_demo (
i_associative_array IN pkg_types.aa_number
)
RETURN tt_number
AS
--
vt_number tt_number := tt_number();
--
BEGIN
--
FOR i IN i_associative_array.FIRST .. i_associative_array.LAST
LOOP
--
vt_number.EXTEND();
vt_number(i) := i;
--
END LOOP;
--
RETURN vt_number;
--
END;
/


declare
v_number number;
v_cursor pkg_types.refcursor;
va_number pkg_types.aa_number;
begin
for i in 1 .. 10
loop
va_number(i) := i;
end loop;
open v_cursor for
select *
from table(cast(f_tt_convert_error_demo(va_number) as tt_number));
loop
fetch v_cursor into v_number;
exit when v_cursor%NOTFOUND;
dbms_output.put_line(v_number);
end loop;
close v_cursor;
end;

I should have known, but this cannot work due to an error “PLS-00425: in SQL, function argument and return types must be SQL type”.

Incidentally, if you try dynamic SQL, you’ll get a “PLS-00457: expressions have to be of SQL types” instead.

Secondly, just because you can do something in SQL doesn’t mean that the same statement will work in a PL/SQL routine (and vice versa from memory – it tends to be features that are relative new). Following on from SQL above:


CREATE OR REPLACE FUNCTION f_tt_error_demo
RETURN tt_number
AS
--
vt_number tt_number := tt_number();
--
BEGIN
--
FOR i IN 1 .. 10
LOOP
--
vt_number.EXTEND();
vt_number(i) := i;
--
END LOOP;
--
RETURN vt_number;
--
END;
/


SQL> select value(t)
2 from table (cast (f_tt_error_demo as tt_number)) t
3 /
VALUE(T)
----------
1
2
3
4
5
6
7
8
9
10


SQL> declare
2 begin
3 for a in (select VALUE(t) num
4 from table (cast (f_tt_error_demo as tt_number)) t)
5 loop
6 dbms_output.put_line(a.num);
7 end loop;
8 end;
9 /
declare
*
ERROR at line 1:
ORA-06550: line 0, column 0:
PLS-00382: expression is of wrong type
ORA-06550: line 3, column 13:
PL/SQL: SQL Statement ignored
ORA-06550: line 6, column 28:
PLS-00364: loop index variable 'A' use is invalid
ORA-06550: line 6, column 7:
PL/SQL: Statement ignored

but, with dynamic sql:


SQL> declare
2 v_number number;
3 v_cursor pkg_types.refcursor;
4 begin
5 open v_cursor for
6 ' select value(t) '||
7 ' from table (cast (f_tt_error_demo as tt_number)) t ';
8 loop
9 fetch v_cursor into v_number;
10 exit when v_cursor%NOTFOUND;
11 dbms_output.put_line(v_number);
12 end loop;
13 close v_cursor;
14 end;
15 /
1
2
3
4
5
6
7
8
9
10
PL/SQL procedure successfully completed.

Thirdly, the above are distilled code examples of further errors that I came across while trying to put together a bit of example code for this blog entry to show the real problem that I had.

I actually wanted to use the function in a subquery like this:


create table error_demo
as
select rownum col1
from all_objects
where rownum < 11
1 select *
2 from error_demo
3 where col1 IN (select value(t) num
4* from table (cast (f_tt_error_demo as tt_number)) t)
SQL> /
COL1
----------
1
2
3
4
5
6
7
8
9
10
10 rows selected.


SQL> declare
2 v_number number;
3 v_cursor pkg_types.refcursor;
4 begin
5 open v_cursor for
6 select col1
7 from error_demo
8 where col1 IN (select *
9 from table (cast (f_tt_error_demo as tt_number)) t);
10 loop
11 fetch v_cursor into v_number;
12 exit when v_cursor%NOTFOUND;
13 dbms_output.put_line(v_number);
14 end loop;
15 close v_cursor;
16 end;
17 /
from table (cast (f_tt_error_demo as tt_number)) t);
*
ERROR at line 9:
ORA-06550: line 9, column 37:
PLS-00220: simple name required in this context
ORA-06550: line 6, column 4:
PL/SQL: SQL Statement ignored

“PLS-00220: simple name required in this context” – that’s a new one for me, first time I’ve had that error, I think.

But again, with dynamic sql:


SQL> ed
Wrote file afiedt.buf
1 declare
2 v_number number;
3 v_cursor pkg_types.refcursor;
4 begin
5 open v_cursor for
6 ' select col1 '||
7 ' from error_demo '||
8 ' where col1 IN (select * '||
9 ' from table (cast (f_tt_error_demo as tt_number)) t)';
10 loop
11 fetch v_cursor into v_number;
12 exit when v_cursor%NOTFOUND;
13 dbms_output.put_line(v_number);
14 end loop;
15 close v_cursor;
16* end;
SQL> /
1
2
3
4
5
6
7
8
9
10
PL/SQL procedure successfully completed.

So, as I mentioned way up above, these issues really have reduced it down to a choice between inserting the values in a GTT and then using that GTT in an IN subquery SELECT, or just to revert back to the IN lists as they were.

On the GTT front, we can bulk insert the values for the IN list from the application into the GTT using a simple procedure which accepts an associative array (like pkg_types.aa_number above).
One important note is that the GTT as to be created as “ON COMMIT PRESERVE ROWS”, otherwise the application will raise error “ORA-08103: object no longer exists”. This rings a bell from previous experiences using a JDBC app.

However this then requires another sort of workaround to delete the rows in the GTT as the first step in the procedure which bulk inserts the rows….

So, this leaves it all in a funny place where you’ve got to weigh up the evils of all the IN lists with the inefficiency, phaffing around and the general “bad smell” of the GTT approach.

It also leaves two open questions. Firstly, should we have another look at a higher level at the application design to reconsider why these IN lists are being constructed / are required in the first place? And secondly, when will ODP.NET provide the same support for Oracle UDTs as it does for JDBC?

Varying IN lists – part III

… continued …

OK, so the varying in list solution is not working for binds where the length > 4000 characters and ODP.NET does not seem to support Oracle collections to the same extent as JDBC (although some results on a Google search indicate that this may have been present in a Beta release but withdrawn). What are the alternatives?

We can return to the previous situation with many similar SQL statments with different length IN lists stuffing up the shared pool.

We could use a routine just before the select in the application to insert the previous IN list argument values into a GLOBAL TEMPORARY TABLE and then change the SQL so that the IN list subquery selects from that. It’s not nice, it’s not the ideal solution but it’s a possibility. An alternative is to the GTT is to use a global variable in a package. Not dissimilar to the GTT approach. Both have a nasty “smell” about them.

In both cases, the general approach is that the application would first have to insert values into the GLOBAL TEMPORARY TABLE or into the global packaged variable (either individual values or in the latter, using the ODP.NET support for associative arrays). Then we would write a query that would have a subquery to either select from the GTT or call a function which would change the associative array to a SQL type.

It sounds a bit daft whichever the method.

(Incidentally I lose track of what I’m meant to call things. Associative arrays used to be called index-by tables which used to be called PLSQL tables. These are part of the Oracle collections framework which includes SQL User Defined Types (UDTs)? That latter are what we need to use in SQL using the TABLE and CAST operators and those are what ODP.NET does not support.)

An initial runstats examination shows that the packaged variable approach is more scalable. This is mainly because a packaged variable is a memory structure whereas inserts into a GTT generate some redo and so runstats picks up on that. In terms of clock speed, the packaged variable approach seems slightly faster.

Hopefully, I will expand this a bit later with proper example code.

Varying IN lists – part II

I have blogged before about a solution to varying in lists being issued by an application.

The problem related to hard parsing – when these varying in lists used literals rather than binds (resolved by the cursor_sharing paramter) – and to shared pool usage – with every distinct number of binds in an in list requiring a shared pool entry (or parse if absent therefrom).

Having gently guided the application developers down the path of this type of approach, I was feeling pretty pleased with progress. However, two problems have subsequently presented themselves which underline why the initial approach was taken and why the standard solutions approach is not a silver bullet in all circumstances.

One of the applications concerned uses ODP (Oracle Data Provider for .NET). This is one of those situations where my understanding (or lack thereof) leaves me feeling very vulnerable.
ODP sits on top of OCI in a way that is, at this time, beyond my comprehension in terms of driver internals.

The varying in list “design pattern” uses a single delimited string as a single bind variable. As a result, no matter the length of the single bind, there is only a single statement per x binds for that base bit of SQL.

However, OCI has a limt of 4000 for a VARCHAR2 argument. Therefore, depending on the length of each argument in the delimited string, we are severely limited in the number of arguments that can be passed in.

This brings me back to an old bug raised against the current application. In the old varying IN list approach, the application was limited to something like 1000 arguments in the IN list. There are obvious question marks against the application design of any application which is dynamically building such IN lists – where are the arguments in the IN lists coming from? What is the application object to relational mapping such that this is happening? Can we present alternative structures / entities to avoid these scenarios? etc.

However, by pushing the varying IN list solution, the limit of 1000 arguments is now considered a “nice-to-have”. Because at 8 digits, the maximum number of arguments is now closer to 250!

As the length of the single bind variable reaches the 4000 limit, the error raised is “ORA-01460: unimplemented or unreasonable conversion requested”. We have tried a LONG and CLOB alternative and both are met with the same result (although an erroneous implementation of a workaround can never be ruled out).

One of the frustrations here is that the application developers would love to use a more appropriate interface. The natural choice, IMHO, is to provide some sort of array of the arguments concerned. If we were using JDBC, then using proper Oracle collections (CREATE TYPE…. AS TABLE OF) and the appropriate JDBC structures would be fantastic.

However, for some reason, ODP does not yet support the same functionality. According to the documentation, ODP.NET supports associative arrays/index-by tables/plsql tables but not SQL types. Which raises the question, why has this functionality been absent from ODP.NET for so long?

… more …

Varying IN lists

In his column in the current edition of Oracle magazine, Tom Kyte wrote about the recurring issue of varying in lists and provided some solutions for this.

This ties in nicely with a recommendation I had already made at my current client where there is a significant usage of IN lists within dynamic SQL issued by applications on top of the 8.1.7.4 DB. So, if we were using bind variables for these IN lists, then if there were 1 -> n arguments in the IN lists, we would probably find n similar queries in the shared pool, each with a different number of arguments in that IN list.

However, these dynamic varying IN lists are not using bind variables.

 As a result, there is a fair amount of SQL ageing out of the shared pool as these sequence-generated ids creep upwards with every day bringing a new range of ids and, not surprisingly, we are doing too much hard parsing.

So, there is a two-pronged recommendation, firstly to change the CURSOR_SHARING to FORCE in order to do some auto-binding for certain users (to be set using an AFTER LOGON trigger) and, secondly, to use a better approach for IN lists, as detailed in the link above.

The advantages should hopefully be a reduction in hard parsing and, within the application, the end of the limit on the number of arguments in the dynamic string-concatenated IN list.

I have been using an approach very similar to the 8i approach that Tom describes in his column.

An example of the transition, using a two-argument IN list, is from:

select n.slug, n.id
from news n
where n.status=15
and n.sectionid in ('42299, 42295')

to

select n.slug, n.id
from news n
where n.status=15
and n.sectionid in
(
  select * from table ( cast ( f_numinlist('42299, 42295') as tt_number))
)

and, in the above example, ‘42299, 42295′ should be bound as a single bind (this is for an application with varying numbers of arguments and, as Tom points out in his article, if there is a finite number of arguments, then the best approach might be to just individually bind each item).

However, on implementing this approach, there was a very definite performance impact.
An explain plan for the original code looked like this:

SQL> select n.slug, n.id
  2 from news n
  3 where n.status=15
  4 and n.sectionid in ('42299, 42295')
  5 /
Execution Plan
----------------------------------------------------------
  0 SELECT STATEMENT Optimizer=CHOOSE (Cost=4 Card=48 Bytes=1488)
  1 0 INDEX (RANGE SCAN) OF 'I_NEWS_001' (NON-UNIQUE) (Cost=4 Card=48 Bytes=1488)

An explain plan for the revised statement revealed the following:

SQL> l
  1 select n.slug, n.id
  2 from news n
  3 where n.status=15
  4 and n.sectionid in
  5 (
  6 select * from table ( cast ( f_numinlist('42299, 42295') as tt_number))
  7* )
SQL> /
Execution Plan
----------------------------------------------------------
  0 SELECT STATEMENT Optimizer=CHOOSE (Cost=5365 Card=192277 Bytes=8460188)
  1 0 HASH JOIN (Cost=5365 Card=192277 Bytes=8460188)
  2 1 VIEW OF 'VW_NSO_1' (Cost=14 Card=4072 Bytes=52936)
  3 2 SORT (UNIQUE) (Cost=14 Card=4072)
  4 3 COLLECTION ITERATOR (PICKLER FETCH)
  5 1 INDEX (FAST FULL SCAN) OF 'I_NEWS_001' (NON-UNIQUE) (Cost=841 Card=306123 Bytes=9489813)

My initial thoughts were that a hash join was probably not the most efficient mechanism. I don’t want to digress into a discussion on joining mechanisms partly because my knowledge is less than comprehensive and also because there are far, far better sources out there. I refer the reader to the Oracle documentation – 8i, 9iR2, and 10gR2 – and, of course, to Jonathan Lewis’s book on the CBO.
I also suspected that the problem was probably related to the number of rows that the CBO thought were in the dynamic IN list collection.The reason is right there in the autotrace, but a quick trace of the CBO decision making using event 10053 confirmed the following:

Table stats Table: KOKBF$ Alias: KOKBF$
TOTAL :: (NOT ANALYZED) CDN: 4072 NBLKS: 100 TABLE_SCAN_CST: 2 AVG_ROW_LEN: 100
Column: KOKBC$ Col#: 1 Table: KOKBF$ Alias: KOKBF$
NO STATISTICS (using defaults)
NDV: 127 NULLS: 0 DENS: 7.8585e-03
***************************************
SINGLE TABLE ACCESS PATH
TABLE: KOKBF$ ORIG CDN: 4072 CMPTD CDN: 4072
Access path: tsc Resc: 2 Resp: 2
BEST_CST: 2.00 PATH: 2 Degree: 1

Basically, the CBO is using a default of 4072 rows in the collection generated from the IN list. I have seen a similar problem with GLOBAL TEMPORARY TABLES and which was helped by using a DYNAMIC_SAMPLING hint. Unfortunately, I believe that the latter was introduced in 9i and certainly any attempts to use it in the above problem on my version were less than fruitful.  Same with the CARDINALITY hint.

Anyway, I took the easy route to the solution. I quickly created a normal heap table with 2 rows in it to see how the CBO would react in those circumstances:


SQL> create table domtest
2 (col1 number);

Table created.


SQL>
SQL> insert into domtest values (42299);

1 row created.


SQL>
SQL> insert into domtest values (42295);

1 row created.


SQL>
SQL> begin
2 dbms_stats.gather_table_stats(USER,'DOMTEST');
3 end;
4 /

PL/SQL procedure successfully completed.


SQL>
SQL> set autotrace trace explain
SQL>
SQL> select n.slug, n.id
2 from news n
3 where n.status=15
4 and n.sectionid in
5 (
6 select * from domtest
7 );

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=11 Card=94 Bytes=4136)
1 0 NESTED LOOPS (Cost=11 Card=94 Bytes=4136)
2 1 VIEW OF 'VW_NSO_1' (Cost=3 Card=2 Bytes=26)
3 2 SORT (UNIQUE) (Cost=3 Card=2 Bytes=10)
4 3 TABLE ACCESS (FULL) OF 'DOMTEST' (Cost=1 Card=2 Bytes=10)
5 1 INDEX (RANGE SCAN) OF 'I_NEWS_001' (NON-UNIQUE) (Cost=4 Card=306123 Bytes=9489813)

Under these circumstances, a nested loop seemed more in line with what I was expecting previously.So, I decided to try a nested loop hint, the syntax being


/*+ ordered use_nl (--table / alias--) */

and which says that the table specified should be used as the inner table on the nested loop – so, this should drive off the entries in the IN list array.


SQL> select /*+ ordered use_nl (n) */
2 n.slug, n.id
3 from news n
4 where n.status=15
5 and n.sectionid in
6 (
7 select * from table ( cast ( f_numinlist('42299, 42295') as tt_number))
8 )
9 /


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=16302 Card=192277 Bytes=8460188)
1 0 NESTED LOOPS (Cost=16302 Card=192277 Bytes=8460188)
2 1 VIEW OF 'VW_NSO_1' (Cost=14 Card=4072 Bytes=52936)
3 2 SORT (UNIQUE) (Cost=14 Card=4072)
4 3 COLLECTION ITERATOR (PICKLER FETCH)
5 1 INDEX (RANGE SCAN) OF 'I_NEWS_001' (NON-UNIQUE) (Cost=4 Card=306123 Bytes=9489813)

The numbers are still a little off because the CBO is still using a default on 4072 rows but it runs like a dream.

Follow

Get every new post delivered to your Inbox.

Join 69 other followers