Tuesday, December 9, 2014

Hotsos Symposium Speakers and Topics 2015

WOOT-WOOT!  


The selections have been made!  Check out the list and start drawing up your strategy to get the most out of the Symposium. Another great one!!

Who's your favorite? 

http://www.hotsos.com/sym15/sym_speakers.html


Monday, December 8, 2014

Selecting one row



If the table is small do I really need an index to select just one row?

Yes you do.  Here is a simple test you can use yourself to prove this to anyone one who asks.

If I have a small table with say 100 rows that all fit in a single block, it seems reasonable that a full table scan to find the one row is just fine.  After all it’s just one block so what does it matter?  Here is a simple table and some code to fill it with just 100 rows, and they all fit in one 8K block.

CREATE TABLE ONEHUNDREDROWS (ID NUMBER, FILLER VARCHAR2(2))
/

BEGIN
  FOR X IN 1..100 LOOP
      INSERT INTO ONEHUNDREDROWS VALUES (X,'AA');
  END LOOP;
END;
/
Once the table is created you can run this to see that all the rows are in one block, this returns the distinct block numbers in all the ROWIDs for the table:
SQL> SELECT distinct dbms_rowid.rowid_block_number(ROWID, 'BIGFILE') BLOCK from onehundredrows;

          BLOCK
---------------
       26209107
Now here is a block of code to select one row from this table, 5000 times.  The block will time how much elapsed and CPU time are consumed when doing this.   The select used after running the block will show use the resources used.  Of particular interest to us is the BUFFERs column, this shows how many LIOs were done.  Make sure STATISTICS_LEVEL is set to all. 
ALTER SESSION SET STATISTICS_LEVEL=ALL
/

create or replace procedure one_row_test is
   l_start_time pls_integer;
   l_start_cpu  pls_integer;
   y varchar2(2);
begin
   l_start_time := DBMS_UTILITY.GET_TIME;
   l_start_cpu  := DBMS_UTILITY.GET_CPU_TIME;
   for i in 1 .. 5000 loop
      select filler into y from onehundredrows where id = 42;
   end loop;
   DBMS_OUTPUT.put_line ('******* Select one row 5000 times *******');
   DBMS_OUTPUT.put_line ('Times in hundredths of a second');
   DBMS_OUTPUT.put_line ('**** TIME   - '||to_char(DBMS_UTILITY.get_time - l_start_time));
   DBMS_OUTPUT.put_line ('**** CPU    - '||to_char(DBMS_UTILITY.GET_CPU_TIME - l_start_cpu));
end;
/

EXEC ONE_ROW_TEST

SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY_CURSOR('9mxb9qk546vu6',NULL,'ALLSTATS LAST'))
/

Here is a run doing a full table scan:

SQL> EXEC ONE_ROW_TEST
******* Select one row 5000 times *******
Times in hundredths of a second
**** TIME   - 26
**** CPU    - 25
SQL>
SQL>
SQL> SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY_CURSOR('9mxb9qk546vu6',NULL,'ALLSTATS LAST'))
  2  /

PLAN_TABLE_OUTPUT
---------------------------------------------------------------------------------------------------------------------------------
SQL_ID  9mxb9qk546vu6, child number 0
-------------------------------------
SELECT FILLER FROM ONEHUNDREDROWS WHERE ID = 42

Plan hash value: 35615928

----------------------------------------------------------------------------------------------
| Id  | Operation         | Name           | Starts | E-Rows | A-Rows |   A-Time   | Buffers |
----------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |                |      1 |        |      1 |00:00:00.01 |       7 |
|*  1 |  TABLE ACCESS FULL| ONEHUNDREDROWS |      1 |      1 |      1 |00:00:00.01 |       7 |
----------------------------------------------------------------------------------------------

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

   1 - filter("ID"=42)

Note
-----
   - dynamic statistics used: dynamic sampling (level=2)

Notice that the buffers is 7 for the full scan even though all 100 rows fit in one block, the scan has to go all the way to the high water mark of the table.  

Now let’s run the same thing but this time there will be an index on the ID column:


SQL> create index one_id on onehundredrows(id)
  2  /
SQL>
SQL>
SQL> EXEC ONE_ROW_TEST
******* Select one row 5000 times *******
Times in hundredths of a second
**** TIME   - 22
**** CPU    - 22
SQL>
SQL>
SQL> SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY_CURSOR('9mxb9qk546vu6',NULL,'ALLSTATS LAST'))
  2  /

PLAN_TABLE_OUTPUT
---------------------------------------------------------------------------------------------------------------------------------
SQL_ID  9mxb9qk546vu6, child number 0
-------------------------------------
SELECT FILLER FROM ONEHUNDREDROWS WHERE ID = 42

Plan hash value: 3262481358

--------------------------------------------------------------------------------------------------------
| Id  | Operation                   | Name           | Starts | E-Rows | A-Rows |   A-Time   | Buffers |
--------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |                |      1 |        |      1 |00:00:00.01 |       2 |
|   1 |  TABLE ACCESS BY INDEX ROWID| ONEHUNDREDROWS |      1 |      1 |      1 |00:00:00.01 |       2 |
|*  2 |   INDEX RANGE SCAN          | ONE_ID         |      1 |      1 |      1 |00:00:00.01 |       1 |
--------------------------------------------------------------------------------------------------------

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

   2 - access("ID"=42)

Note
-----
   - dynamic statistics used: dynamic sampling (level=2)


The LIOs for this one is 2.  You may say that what is the big deal from 7 to 2?  True enough on a one run bases, this isn’t much to worry about.  But imagine doing this millions of times.  Now that extra 5 LIOs start to add up.

Also notice that in just 5000 look ups the time goes from 22 to 26 centiseconds, about an 18% increase.  Again doesn’t seem like much but it adds up.  Also what happens if this table does grow over time?  The full scan will continue to look at more and more blocks taking more and more time and resources.  The index scan will likely stay about the same for a long time before it starts to change.  The table could easily be about 10 times the size and the index would still be about the same for LIOs and time.

If the index on ID is unique that the time drops a bit more down to 20 centiseconds, so yes it’s even better to have a unique index just to select a single row from a small table.

SQL> drop index one_id
  2  /

SQL> create unique index one_id on onehundredrows(id)
  2  /

SQL> EXEC ONE_ROW_TEST
******* Select one row 5000 times *******
Times in hundredths of a second
**** TIME   - 20
**** CPU    - 20
SQL> SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY_CURSOR('9mxb9qk546vu6',NULL,'ALLSTATS LAST'));

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------
SQL_ID  9mxb9qk546vu6, child number 0
-------------------------------------
SELECT FILLER FROM ONEHUNDREDROWS WHERE ID = 42

Plan hash value: 3462298723

--------------------------------------------------------------------------------------------------------
| Id  | Operation                   | Name           | Starts | E-Rows | A-Rows |   A-Time   | Buffers |
--------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |                |      1 |        |      1 |00:00:00.01 |       2 |
|   1 |  TABLE ACCESS BY INDEX ROWID| ONEHUNDREDROWS |      1 |      1 |      1 |00:00:00.01 |       2 |
|*  2 |   INDEX UNIQUE SCAN         | ONE_ID         |      1 |      1 |      1 |00:00:00.01 |       1 |
--------------------------------------------------------------------------------------------------------

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

   2 - access("ID"=42)

Tuesday, October 21, 2014

2014 East Coast Oracle Users Conference



Hey everyone!  I'll be speaking at this conference with a host of other great speakers.  Come on down and join the fun!



2014 East Coast Oracle Users Conference (ECO) 
November 4 &5 
Sheraton Imperial Hotel & Convention Center 
 Raleigh/Durham, NC

Friday, October 3, 2014

CAGE MATCH: IN vs OR


Many of us know that an IN list is turned into a set of OR’ed predicates by the optimizer.  Up until 11 an IN list and an OR list were pretty much the same.  But in 11 there was a subtle shift that changed the game.

This example is from the Hotsos “Optimizing Oracle SQL, Intensive” course.  When originally written this was to demonstrate how ANDs and ORs work with regard to “short circuit logic”.    That is, when a FALSE is found in an AND list it stops and when a TRUE is found in an OR list is stops.  But something odd started to happen in 11:

First we have a little function.  It writes a line to the screen and returns the word “match”.  The line it writes tells us that it ran for a particular row. The data we use for this is equally complex, a table with 2 columns and 2 rows; a string and a number, the number to represent each row.


create or replace function test_po(a number) return varchar2
is
begin
 dbms_output.put_line('function executed for row '||a);
 return 'match';
end;
/
SQL> desc pred_order
 Name          Null?    Type
 ------------- -------- ------------
 COL1                   VARCHAR2(10)
 COL2                   NUMBER
SQL> select * from pred_order;
 COL1             COL2
 ---------- ----------
 aaaaa               1
 match               2

Here’s a query that selects from this table:

select *
from pred_order
where test_po(col2) in ('xxxxx','yyyyy')
and col1 = 'zzzzz'

Now when we execute this plan in 10 or before (and using IO costing), the output would look like below.  Notice that the function was executed twice for each row, and you can see that in the plan the function is shown twice in the OR list that the IN list was converted to.  So that makes sense:

SQL> alter session set "_optimizer_cost_model"=io;
SQL>
SQL> @pred1
function executed for row 1
function executed for row 1
function executed for row 2
function executed for row 2
SQL>
SQL> @hxplan
Enter .sql file name (without extension): pred1
Enter the display level (TYPICAL, ALL, BASIC, SERIAL) [TYPICAL]  :
Plan hash value: 1987733821

----------------------------------------------------------------
| Id  | Operation         | Name       | Rows  | Bytes | Cost  |
----------------------------------------------------------------
|   0 | SELECT STATEMENT  |            |     1 |     9 |     2 |
|*  1 |  TABLE ACCESS FULL| PRED_ORDER |     1 |     9 |     2 |
----------------------------------------------------------------

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

   1 - filter(("TEST_PO"("COL2")='xxxxx' OR "TEST_PO"("COL2")='yyyyy')
              AND "COL1"='zzzzz')

Note
-----
   - cpu costing is off (consider enabling it)
SQL>

However do the same thing in 11 or 12 and the output different.  The plan stays the same but the function appears to be only run once:

SQL> @pred1
function executed for row 1
function executed for row 2
SQL>
SQL> @hxplan
Enter .sql file name (without extension): pred1
Enter the display level (TYPICAL, ALL, BASIC, SERIAL) [TYPICAL]  :
Plan hash value: 1987733821

----------------------------------------------------------------
| Id  | Operation      | Name       | Rows  | Bytes | Cost  |
----------------------------------------------------------------
|   0 | SELECT STATEMENT  |            |     1 |     9 |     2 |
|*  1 |  TABLE ACCESS FULL| PRED_ORDER |     1 |     9 |     2 |
----------------------------------------------------------------

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

   1 - filter(("TEST_PO"("COL2")='xxxxx' OR "TEST_PO"("COL2")='yyyyy')
           AND "COL1"='zzzzz')

Note
-----
   - cpu costing is off (consider enabling it)
SQL>

What I’m pretty sure is happening is some sort of “result cache” is being done.  It sees that it’s the same call with the same value being passed in so it either automatically created a result cache or behind the scenes is putting in a bind like value for the second call.  It does make the comparison, I put the word “match” way down the list and is did find it, so it’s does really do the comparison it just doesn’t make the function call over and over again.

That’s cool.  But watch what happens if I manually change the query to ORs instead of the IN list:

SQL> get pred1_new
  1  select *
  2    from pred_order
  3   where (test_po(col2)='xxxxx' or test_po(col2)='yyyyy')
  4*    and col1 = 'zzzzz'
SQL>
SQL>
SQL> @pred1_new
function executed for row 1
function executed for row 1
function executed for row 2
function executed for row 2
SQL>
SQL> @hxplan
Enter .sql file name (without extension): pred1_new
Enter the display level (TYPICAL, ALL, BASIC, SERIAL) [TYPICAL]  :
Plan hash value: 1987733821

----------------------------------------------------------------
| Id  | Operation         | Name       | Rows  | Bytes | Cost  |
----------------------------------------------------------------
|   0 | SELECT STATEMENT  |            |     1 |     9 |     2 |
|*  1 |  TABLE ACCESS FULL| PRED_ORDER |     1 |     9 |     2 |
----------------------------------------------------------------

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

   1 - filter(("TEST_PO"("COL2")='xxxxx' OR "TEST_PO"("COL2")='yyyyy')
              AND "COL1"='zzzzz')

Note
-----
   - cpu costing is off (consider enabling it)
SQL>

We are right back to it running the function twice!  HA!  So with the IN list it recognizes that it’s the same call over and over, but when I manually separate it out, the optimizer can’t see that is the same call over and over.

*** BTW – If you’re use CPU costing (which you should be), the optimizer moves the AND predicate (COL1= ‘zzzzz’) first and you see nothing.  This is another part of the exercise to see how predicates move around with CPU costing.

So the bottom line?  INs do have an edge over ORs when it comes to a function call in particular.   There is another advantage which this demo doesn’t show which is the IN list will sort the list, this is very useful for index scans with the IN-List Iterator step, maybe another post about that someday. 

Thursday, September 18, 2014

Fun with your WITH!


Here’s a new feature that might have slipped under the radar for you with 12c.  You can now have PL/SQL functions defined in the WITH clause.  First off this brings some cool functionality to your select statements, but even cooler is that your statement will run faster, a lot faster potential. 

Here’s a simple test to show this.  The ORD9 table has 103,120 rows in 1,390 blocks.  The GMT_ORDER_DATE column represents the order data in the number of seconds since midnight 1 January of the year the order was placed. It has no indexes and does have full (100%) stats.  I have a function defined below which returns a date as it relates to the UNIX epoch.  (Why you would really want to do this, I’m not sure, but it’s here mostly to have it do something.)

create or replace function rtn_date_convert (p_unix_gmt in number)
  return date
  as
   v_date  date;
  begin
     v_date := to_date('01/01/1970','mm/dd/yyyy') + (p_unix_gmt/86400) ;
     RETURN v_date;
  end ;
/

Now I have a select which uses this function as such:


select count(*) from ord9 where rtn_date_convert(gmt_order_date) > sysdate - 3650
/

Next I have a query that does the same thing but has the function defined within a with clause:


with function rtn_date_convert2 (p_unix_gmt in number)
  return date
  as
   v_date  date;
  begin
     v_date := to_date('01/01/1970','mm/dd/yyyy') + (p_unix_gmt/86400) ;
     RETURN v_date;
  end ;
select count(*) from ord9
where rtn_date_convert2(gmt_order_date) > sysdate - 3650
/

I run each several times (more then 10).  Each query “does the same thing”, the plans are identical.  They both do a full scan on the ORD9 table then do an aggregation of the data, just as you’d expect.  LIOs and other stats are the same between the plans; however the one with the internal function runs consistently in less than half the time of the external one (this is output from our harness tool which captures stats and trace files about SQL statements):


                                   withfun:    withfun:
TYPE  NAME                         externalfun internalfun DIFFERENCE
----- ---------------------------- ----------- ----------- ----------
Latch cache buffers chains               2,960       2,964         -4
      row cache objects                    157         151          6
      shared pool                           18          17          1
                                                                    
Stats buffer is pinned count                 0           0          0
      consistent gets                    1,326       1,326          0
      db block changes                       0           0          0
      db block gets                          0           0          0
      execute count                          5           5          0
      index fast full scans (full)           0           0          0
      parse count (hard)                     0           0          0
      parse count (total)                    6           6          0
      physical reads                         0           0          0
      physical writes                        0           0          0
      redo size                              0           0          0
      session logical reads              1,326       1,326          0
      session pga memory                     0           0          0
      session pga memory max                 0           0          0
      session uga memory                     0           0          0
      session uga memory max                 0           0          0
      sorts (disk)                           0           0          0
      sorts (memory)                         0           0          0
      sorts (rows)                           0           0          0
      table fetch by rowid                   0           0          0
      table scan blocks gotten           1,316       1,316          0
      table scans (long tables)              0           0          0
      table scans (short tables)             1           1          0
                                                                     
Time  elapsed time (centiseconds)           63          29         34

withfun:externalfun
STAT #565587040 id=1 cnt=1 pid=0 pos=1 obj=0 op='SORT AGGREGATE (cr=1326 pr=0 pw=0 time=621435 us)'
STAT #565587040 id=2 cnt=103120 pid=1 pos=1 obj=102779 op='TABLE ACCESS FULL ORD9 (cr=1326 pr=0 pw=0 time=608109 us cost=282 size=824960 card=103120)'


withfun:internalfun
STAT #407419720 id=1 cnt=1 pid=0 pos=1 obj=0 op='SORT AGGREGATE (cr=1326 pr=0 pw=0 time=284779 us)'
STAT #407419720 id=2 cnt=103120 pid=1 pos=1 obj=102779 op='TABLE ACCESS FULL ORD9 (cr=1326 pr=0 pw=0 time=272208 us cost=282 size=824960 card=103120)'

 These tests were run on a Windows 12.1.0.1 database, which interestingly had optimizer_features_enable set to 11.2.0.2.