Saturday, September 22, 2018

Orace block dump @ various stages of the transaction

Goal: See what happens during a Transaction (TX)... learn from block dump.

Step 1: Get to know your table - block map [thanks to Arup Nanda - http://arup.blogspot.com/2011/01/more-on-interested-transaction-lists.html]


SQL> select
dbms_rowid.rowid_relative_fno(rowid) File#,
dbms_rowid.rowid_block_number(rowid) Block#,
count(1)
from T1_TEST1
group by
dbms_rowid.rowid_relative_fno(rowid),
dbms_rowid.rowid_block_number(rowid)
order by
1,2  2    3    4    5    6    7    8    9   10  ;

     FILE#     BLOCK#   COUNT(1)
---------- ---------- ----------
      1012      55571         65
      1012      55572         59
      1012      55573         59
      1012      55574         59
      1012      55575         59
      1012      55576         59
      1012      55577         59
      1012      55578         60
      1012      55579         59
      1012      55580         59
      1012      55581         59
      1012      55582         59
      1012      55584         59
      1012      55585         59
      1012      55586         59
      1012      55587         59
      1012      55588         59
      1012      55589         59
      1012      55590         59
      1012      55591         59
      1012      55592         59
...
      1012      55750         59
      1012      55751         59
      1012      55752         59
      1012      55753         59
      1012      55754         59
      1012      55755         59
      1012      55756         59
      1012      55757         59
      1012      55758         59
      1012      55759         59
      1012      55760         59
      1012      55761         59
      1012      55762         59
      1012      55763         59
      1012      55764         59
      1012      55765         59
      1012      55766         59
      1012      55767         59
      1012      55768         40

189 rows selected.


Step 2: Pick the block we wanted to update and then find out its high/low value which will be used in the preference clause.

select min(OBJECT_ID), max(OBJECT_ID)
from T1_TEST1
where dbms_rowid.rowid_block_number(rowid) = 55572;

MIN(OBJECT_ID) MAX(OBJECT_ID)
-------------- --------------
        104344         149818


Step 3: For keeping this test simple, I will pick the second block and its min [104344]. value.

Step 4: Will dump the preimage of the block.



set lines 300 pages 3000
select a.sid,a.serial#,b.pid,b.spid,b.tracefile from v$session a,v$process b where a.paddr=b.addr and a.username='SCOTT';

alter system dump datafile 1012 block min 55572 block max 55572;

Step 5: Update the chosen record..

update T1_TEST1 set object_name='22SEP18_CHANGED' where object_id=104344;

Step 6: Will dump the postimage of the block.

alter system dump datafile 1012 block min 55572 block max 55572;

Step 7: Will perform commit and take a dump of the block.

commit;
alter system dump datafile 1012 block min 55572 block max 55572;

>>> done , the trace file is recovered @ all the three steps. I managed to remove the duplicate copies of the trace entries and kept only relevant parts in all 3 traces.
Let us do the examination.

Observations:
1) In the preimage dump of the block, we only had 1 buffer copy


Dump of buffer cache at level 4 for pdb=0 tsn=1013 rdba=-50276076
BH (0x9df6a158) file#: 1012 rdba: 0xfd00d914 (1012/55572) class: 1 ba: 0x9d104000
...
hash: [0xa95592e0,0xa95592e0] lru: [0x9df6a388,0x9df6a108]
...
st: XCURRENT md: NULL fpin: 'kdswh11: kdst_fetch' fscn: 0x0.31ee4e tch: 2

flags: only_sequential_access

Block dump from disk:
buffer tsn: 1013 rdba: 0xfd00d914 (1012/55572)

scn: 0x0.2cf023 seq: 0x02 flg: 0x04 tail: 0xf0230602

frmt: 0x02 chkval: 0xd066 type: 0x06=trans data


What we notice in this trace is, we had only the current version of the block available in memory. There were no active transaction in the block.

2) The same block dump on DML, had 2 versions of the block. 1 the pre-modification version which is the CR (consistent Read version) aka actually the step 1's current version and the actual current version which is the modified block version (this block actually is flagged as privte).


Current:
BH (0x9df61e18) file#: 1012 rdba: 0xfd00d914 (1012/55572) class: 1 ba: 0x9d032000
..
hash: [0x9df6a210,0xa95592e0] lru: [0x9df62048,0x9df61dc8]
..
use: [NULL] wait: [NULL]
st: XCURRENT md: NULL fpin: 'kdswh11: kdst_fetch' fscn: 0x0.31ee4e tch: 2 txn: 0xa530acb8   //// look here the block has a TXN associated
flags: private

Apart from this we had the past image of the block (CR)..

BH (0x9df6a158) file#: 1012 rdba: 0xfd00d914 (1012/55572) class: 1 ba: 0x9d104000
..
hash: [0xa95592e0,0x9df61ed0] lru: [0x9df627c8,0x9df6e348]

lru-flags: moved_to_tail
..
cr: [scn: 0x0.31ef05],[xid: 0x0.0.0],[uba: 0x0.0.0],[cls: 0x0.31ef05],[sfl: 0x0],[lc: 0x0.2cf023]
flags: only_sequential_access


Rest all resembles.

3) Post the commit, I noticed the following sections in the block dump trace shows changes...

Pre commit#
ckptq: [NULL] fileq: [NULL]

objq: [0x9df6a3b0,0x9df69d70] objaq: [0x9df6a3c0,0x9df69d80]

use: [NULL] wait: [NULL]
                /// entry is found here alone
st: XCURRENT md: NULL fpin: 'kdswh11: kdst_fetch' fscn: 0x0.31ee4e tch: 2 txn: 0xa530acb8

flags: private

LRBA: [0x0.0.0] LSCN: [0x0.0] HSCN: [0xffff.ffffffff] HSUB: [65535]


Post Commit#
obj-flags: object_ckpt_list //// a new line post commit.From what I have read is the object checkpoint queue, the object post commit gets into the checkpoint queue.

ckptq: [0x9df941d8,0x9df6e398] fileq: [0xa9d30cb8,0xa9d30cb8]
        //// The block getting into checkpoint queue and also it gets a LRBA value (low redo block address)
objq: [0x7f0ea940,0x7f0ea940] objaq: [0x9df6a3c0,0x9df69d80]

st: XCURRENT md: NULL fpin: 'kdswh11: kdst_fetch' fscn: 0x0.31ee4e tch: 2
 //// No Transaction entry, meaning the transaction is completed.
flags: buffer_dirty
                            //// Oracle announces now the buffer as dirty, earlier the buffer was private now it has become dirty   
LRBA: [0x7e.119ef.0] LSCN: [0x0.31ef32] HSCN: [0x0.31ef61] HSUB: [1]   
One unique identification is the block dump didnt show use of ITL at any stage.
Since there were ckpt or events that can kick off DBW to write dirt list or cold buffers, the block isnt written to the disk yet.

Thanks


Friday, September 14, 2018

Walkthrough Adaptive cursor sharing functionality - 12.1.0.1

Goal: TEST Adaptive cursor sharing functionality

create table scott.tst_acs (id,nam) tablespace test_assm
as
select decode(mod(object_id,3),0,9999999,object_id) id,object_name nam
from dba_objects
order by id;

create index scott.tst_acs_idx on scott.tst_acs (id);

exec dbms_stats.gather_table_stats('SCOTT','TST_ACS');

set lines 300
set pages 3000
col owner for a10
col table_name for a10
col index_name for a20
col INDEX_TYPE for a10
select a.owner,a.table_name,a.num_rows,a.last_analyzed,b.index_name,b.index_type,b.uniqueness,b.clustering_factor,b.num_rows
from dba_tables a,dba_indexes b
where a.owner=b.owner
and a.table_name=b.table_name
and a.table_name like 'TST_%'
and a.owner='SCOTT'
order by owner,table_name,index_name;

alter session set nls_date_format='DD/MM/YYYY HH24:MI:SS';

OWNER      TABLE_NAME   NUM_ROWS LAST_ANALYZED       INDEX_NAME           INDEX_TYPE UNIQUENES CLUSTERING_FACTOR   NUM_ROWS
---------- ---------- ---------- ------------------- -------------------- ---------- --------- ----------------- ----------
SCOTT      TST_ACS         91830 14/09/2018 20:45:44 TST_ACS_IDX          NORMAL     NONUNIQUE               447      91830

Query to use to examine ACS usage:

query 1 - selecting only the indexed column.

var objid number;
exec :objid:=&numbr;

value: 9999999

---ideally this should contribute to 1/3 of the table.

select count(id)
from tst_acs
where id=:objid;

select sql_id,child_number,is_bind_sensitive,is_bind_aware,is_shareable,plan_hash_value,executions from v$sql where sql_id='0j06tw291x3m5';

SQL> select sql_id,child_number,is_bind_sensitive,is_bind_aware,is_shareable,plan_hash_value,executions from v$sql where sql_id='0j06tw291x3m5';

SQL_ID        CHILD_NUMBER I I I PLAN_HASH_VALUE EXECUTIONS
------------- ------------ - - - --------------- ----------
0j06tw291x3m5            0 Y N Y      1292819319          1

SQL>

select * from table(dbms_xplan.display_cursor(sql_id=>'0j06tw291x3m5',cursor_child_no=>0,format=>'ADVANCED'));

SQL> select * from table(dbms_xplan.display_cursor(sql_id=>'0j06tw291x3m5',cursor_child_no=>0,format=>'ADVANCED'));

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SQL_ID  0j06tw291x3m5, child number 0
-------------------------------------
select count(id) from tst_acs where id=:objid

Plan hash value: 1292819319

---------------------------------------------------------------------------------
| Id  | Operation         | Name        | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |             |       |       |     1 (100)|          |
|   1 |  SORT AGGREGATE   |             |     1 |     6 |            |          |
|*  2 |   INDEX RANGE SCAN| TST_ACS_IDX |     1 |     6 |     1   (0)| 00:00:01 |
---------------------------------------------------------------------------------

Query Block Name / Object Alias (identified by operation id):
-------------------------------------------------------------

   1 - SEL$1
   2 - SEL$1 / TST_ACS@SEL$1

Outline Data
-------------

  /*+
      BEGIN_OUTLINE_DATA
      IGNORE_OPTIM_EMBEDDED_HINTS
      OPTIMIZER_FEATURES_ENABLE('12.1.0.1')
      DB_VERSION('12.1.0.1')
      ALL_ROWS
      OUTLINE_LEAF(@"SEL$1")
      INDEX(@"SEL$1" "TST_ACS"@"SEL$1" ("TST_ACS"."ID"))
      END_OUTLINE_DATA
  */

Peeked Binds (identified by position):
--------------------------------------

   1 - :OBJID (NUMBER): 9999999

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

   2 - access("ID"=:OBJID)

Column Projection Information (identified by operation id):
-----------------------------------------------------------

   1 - (#keys=0) COUNT("ID")[22]
   2 - "ID"[NUMBER,22]


50 rows selected.


=====> it picked index range scan this itself.

select sql_id,child_number,is_bind_sensitive,is_bind_aware,is_shareable,plan_hash_value,executions,rows_processed,BUFFER_GETS,DISK_READS,PHYSICAL_READ_REQUESTS,PHYSICAL_READ_BYTES,PHYSICAL_WRITE_REQUESTS,PHYSICAL_WRITE_BYTES,OPTIMIZED_PHY_READ_REQUESTS from v$sql where sql_id='0j06tw291x3m5';


SQL_ID        CHILD_NUMBER I I I PLAN_HASH_VALUE EXECUTIONS ROWS_PROCESSED BUFFER_GETS DISK_READS PHYSICAL_READ_REQUESTS PHYSICAL_READ_BYTES PHYSICAL_WRITE_REQUESTS PHYSICAL_WRITE_BYTES OPTIMIZED_PHY_READ_REQUESTS
------------- ------------ - - - --------------- ---------- -------------- ----------- ---------- ---------------------- ------------------- ----------------------- -------------------- ---------------------------
0j06tw291x3m5            0 Y N Y      1292819319          1              1          74          0                      0    0                        0                    0                           0



Even with a different bind it it still able to reuse the cursor...



SQL> select sql_id,child_number,is_bind_sensitive,is_bind_aware,is_shareable,plan_hash_value,executions,rows_processed from v$sql where sql_id='0j06tw291x3m5';

SQL_ID        CHILD_NUMBER I I I PLAN_HASH_VALUE EXECUTIONS ROWS_PROCESSED
------------- ------------ - - - --------------- ---------- --------------
0j06tw291x3m5            0 Y N Y      1292819319          2              2


--------------ignore here - put it wrong sqlid
select * from v$sql_cs_statistics
where sql_id='8ja94dx96jtxq'
order by child_number;

select * from v$sql_cs_selectivity
where sql_id='8ja94dx96jtxq'
order by child_number;

select * from v$sql_cs_histogram where sql_id='8ja94dx96jtxq';


SQL> select * from v$sql_cs_histogram where sql_id='8ja94dx96jtxq';

no rows selected

SQL> select * from v$sql_cs_statistics
where sql_id='8ja94dx96jtxq'
order by child_number;  2    3

no rows selected

SQL> select * from v$sql_cs_selectivity
where sql_id='8ja94dx96jtxq'
order by child_number;  2    3

no rows selected

SQL>

=> so none of this kicked off. Looking @ v$sql_shared_cursor I noticed oracle generated new cursor, the only difference I observed was

--------------ignore here - put it wrong sqlid.

Ideally we will have v$sql_cs_histogram kicking in.

SQL> select * from v$sql_shared_cursor where sql_id='0j06tw291x3m5';

SQL_ID        ADDRESS          CHILD_ADDRESS    CHILD_NUMBER U S O O S L F E B P I S T A B D L T B I I R L I O E M U T N F A P T D L D B P C S C P T M B M R O P M F L P L A F L R L H P B U REASON                                                  CON_ID
------------- ---------------- ---------------- ------------ - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -------------------------------------------------------------------------------- ----------
0j06tw291x3m5 000000007D8C2BE0 000000007D8ACD70            0 N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N Y N N N N N N N N N <ChildNode><ChildNumber>0</ChildNumber><ID>40</ID><reason>Bind mismatch(25)</rea              0
0j06tw291x3m5 000000007D8C2BE0 00000000A1890930            1 N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N            
                                                  0

The only difference is L which translates to LOAD_OPTIMIZER_STATS set to Y for cursor 0 and N for cursor 1.
But this ideally should be the case for a new cursor, so why the next one didnt pickup the load_optimizer_state column.
As per oracle document... "A hard parse is forced to initialize extended cursor sharing", which is the case with first parsing fine, but why for second case.

Let us examine what happens with a new cursor (changed sqltext), what all are set/unset.

new sqltext:

select count(nam)
from tst_acs
where id=:objid;



SQL> select * from v$sql_shared_cursor where sql_id='65ma369shw3s2';

SQL_ID        ADDRESS          CHILD_ADDRESS    CHILD_NUMBER U S O O S L F E B P I S T A B D L T B I I R L I O E M U T N F A P T D L D B P C S C P T M B M R O P M F L P L A F L R L H P B U REASON                                                  CON_ID
------------- ---------------- ---------------- ------------ - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -------------------------------------------------------------------------------- ----------
65ma369shw3s2 000000007D5A5AC0 000000007DB1EA08            0 N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N                                                              0


Hmm this means that oracle is intelligently marking the old child cursor when it creates the new child cursor with the reason for it in the new child cursor. Where the cursor 0 is updated with L (LOAD_OPTIMIZER_STATS set to Y and bind mismatch).
May be we can selectively remove that cursor and retry this to confirm.


select * from v$sql_cs_statistics
where sql_id='65ma369shw3s2'
order by child_number;

select * from v$sql_cs_selectivity
where sql_id='65ma369shw3s2'
order by child_number;

select * from v$sql_cs_histogram where sql_id='65ma369shw3s2';

select * from table(dbms_xplan.display_cursor(sql_id=>'65ma369shw3s2',cursor_child_no=>0,format=>'ADVANCED'));


SQL> select * from v$sql_shared_cursor where sql_id='65ma369shw3s2';

SQL_ID        ADDRESS          CHILD_ADDRESS    CHILD_NUMBER U S O O S L F E B P I S T A B D L T B I I R L I O E M U T N F A P T D L D B P C S C P T M B M R O P M F L P L A F L R L H P B U REASON                                                  CON_ID
------------- ---------------- ---------------- ------------ - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -------------------------------------------------------------------------------- ----------
65ma369shw3s2 000000007D5A5AC0 000000007DB1EA08            0 N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N                                                              0

SQL> select sql_id,child_number,is_bind_sensitive,is_bind_aware,is_shareable,plan_hash_value,executions,rows_processed from v$sql where sql_id='65ma369shw3s2';

SQL_ID        CHILD_NUMBER I I I PLAN_HASH_VALUE EXECUTIONS ROWS_PROCESSED
------------- ------------ - - - --------------- ---------- --------------
65ma369shw3s2            0 Y N Y      2961755162          1              1

SQL> select * from v$sql_cs_statistics
where sql_id='65ma369shw3s2'
order by child_number;  2    3

no rows selected

SQL> select * from v$sql_cs_selectivity
where sql_id='65ma369shw3s2'
order by child_number;  2    3

no rows selected

SQL> select * from v$sql_cs_histogram where sql_id='65ma369shw3s2';

ADDRESS          HASH_VALUE SQL_ID        CHILD_NUMBER  BUCKET_ID      COUNT     CON_ID
---------------- ---------- ------------- ------------ ---------- ---------- ----------
000000007D5A5AC0 1896746754 65ma369shw3s2            0          0          1          0
000000007D5A5AC0 1896746754 65ma369shw3s2            0          1          0          0
000000007D5A5AC0 1896746754 65ma369shw3s2            0          2          0          0

SQL> select * from table(dbms_xplan.display_cursor(sql_id=>'65ma369shw3s2',cursor_child_no=>0,format=>'ADVANCED'));

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SQL_ID  65ma369shw3s2, child number 0
-------------------------------------
select count(nam) from tst_acs where id=:objid

Plan hash value: 2961755162

----------------------------------------------------------------------------------------------------
| Id  | Operation                            | Name        | Rows  | Bytes | Cost (%CPU)| Time     |
----------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                     |             |       |       |     2 (100)|          |
|   1 |  SORT AGGREGATE                      |             |     1 |    30 |            |          |
|   2 |   TABLE ACCESS BY INDEX ROWID BATCHED| TST_ACS     |     1 |    30 |     2   (0)| 00:00:01 |
|*  3 |    INDEX RANGE SCAN                  | TST_ACS_IDX |     1 |       |     1   (0)| 00:00:01 |
----------------------------------------------------------------------------------------------------

Query Block Name / Object Alias (identified by operation id):
-------------------------------------------------------------

   1 - SEL$1
   2 - SEL$1 / TST_ACS@SEL$1
   3 - SEL$1 / TST_ACS@SEL$1

Outline Data
-------------

  /*+
      BEGIN_OUTLINE_DATA
      IGNORE_OPTIM_EMBEDDED_HINTS
      OPTIMIZER_FEATURES_ENABLE('12.1.0.1')
      DB_VERSION('12.1.0.1')
      ALL_ROWS
      OUTLINE_LEAF(@"SEL$1")
      INDEX_RS_ASC(@"SEL$1" "TST_ACS"@"SEL$1" ("TST_ACS"."ID"))
      BATCH_TABLE_ACCESS_BY_ROWID(@"SEL$1" "TST_ACS"@"SEL$1")
      END_OUTLINE_DATA
  */

Peeked Binds (identified by position):
--------------------------------------

   1 - :OBJID (NUMBER): 98

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

   3 - access("ID"=:OBJID)

Column Projection Information (identified by operation id):
-----------------------------------------------------------

   1 - (#keys=0) COUNT("NAM")[22]
   2 - "NAM"[VARCHAR2,128]
   3 - "TST_ACS".ROWID[ROWID,10]


54 rows selected.

SQL>



Looking at this report, oracle now has populated the sql_cs_histogram with 0,1,2 bucket details.

Let us continue testing both the scenarios we spoke...

The cursor is no more in sqlarea. So we decided to run the query again to put it back in shared pool.

SQL> select sql_id,child_number,is_bind_sensitive,is_bind_aware,is_shareable,plan_hash_value,executions from v$sql where sql_id='0j06tw291x3m5';

SQL_ID        CHILD_NUMBER I I I PLAN_HASH_VALUE EXECUTIONS
------------- ------------ - - - --------------- ----------
0j06tw291x3m5            0 Y N Y      1292819319          1

SQL> select sid,serial#,username,status,state,sql_id,event,seconds_in_wait from v$session where username='SCOTT';

       SID    SERIAL# USERNAME                       STATUS   STATE               SQL_ID        EVENT                     SECONDS_IN_WAIT
---------- ---------- ------------------------------ -------- ------------------- ------------- ---------------------------------------------------------------- ---------------
        29        553 SCOTT                          INACTIVE WAITING             0j06tw291x3m5 SQL*Net message from client                                                     40

SQL> select * from v$sql_shared_cursor where sql_id='0j06tw291x3m5';

SQL_ID        ADDRESS          CHILD_ADDRESS    CHILD_NUMBER U S O O S L F E B P I S T A B D L T B I I R L I O E M U T N F A P T D L D B P C S C P T M B M R O P M F L P L A F L R L H P B U REASON                                                  CON_ID
------------- ---------------- ---------------- ------------ - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -------------------------------------------------------------------------------- ----------
0j06tw291x3m5 000000007DD472C8 000000007D1E4770            0 N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N                                                              0

From the above it is evident when we had our next parse only oracle decided to create a new cursor with comments added to the existing one. So it is evident we should look at the previous cursor comments to know the reason for creation of this cursor.

=============> Move on to original topic....

Let us load more data to the table...

insert into scott.TST_ACS
select 9999999,object_id from dba_objects;


SQL>
SQL> insert into scott.TST_ACS
select 9999999,object_id from dba_objects;  2

91834 rows created.

SQL> insert into scott.TST_ACS
select 9999999,object_id from dba_objects;  2

91834 rows created.

SQL> commit;

Commit complete.

SQL>
SQL>
SQL> exec dbms_stats.gather_table_stats('SCOTT','TST_ACS');

PL/SQL procedure successfully completed.

SQL> select a.owner,a.table_name,a.num_rows,a.last_analyzed,b.index_name,b.index_type,b.uniqueness,b.clustering_factor,b.num_rows
  2  from dba_tables a,dba_indexes b
  3  where a.owner=b.owner
  4  and a.table_name=b.table_name
  5  and a.table_name like 'TST_%'
  6  and a.owner='SCOTT'
  7  order by owner,table_name,index_name;

OWNER      TABLE_NAME   NUM_ROWS LAST_ANAL INDEX_NAME           INDEX_TYPE UNIQUENES CLUSTERING_FACTOR   NUM_ROWS
---------- ---------- ---------- --------- -------------------- ---------- --------- ----------------- ----------
SCOTT      TST_ACS        367332 15-SEP-18 TST_ACS_IDX          NORMAL     NONUNIQUE              1088     367332

SQL>


Let us purge the existing cursor...

exec sys.dbms_shared_pool.purge('&address, &hash_value','c');

SQL> select sql_id,child_number,is_bind_sensitive,is_bind_aware,is_shareable,plan_hash_value,executions from v$sql where sql_id='0j06tw291x3m5';

SQL_ID        CHILD_NUMBER I I I PLAN_HASH_VALUE EXECUTIONS
------------- ------------ - - - --------------- ----------
0j06tw291x3m5            0 Y N Y      1292819319          1

SQL> select address, hash_value from v$sqlarea
where sql_id='0j06tw291x3m5';  2

ADDRESS          HASH_VALUE
---------------- ----------
000000007DD472C8 2451476069

SQL>
SQL>
SQL> exec sys.dbms_shared_pool.purge('&address, &hash_value','c');
Enter value for address: 000000007DD472C8
Enter value for hash_value: 2451476069

PL/SQL procedure successfully completed.

SQL> select sql_id,child_number,is_bind_sensitive,is_bind_aware,is_shareable,plan_hash_value,executions from v$sql where sql_id='0j06tw291x3m5';

no rows selected

SQL>

select * from v$sql_cs_statistics
where sql_id='0j06tw291x3m5'
order by child_number;

select * from v$sql_cs_selectivity
where sql_id='0j06tw291x3m5'
order by child_number;

select * from v$sql_cs_histogram where sql_id='0j06tw291x3m5';


SQL> select * from v$sql_cs_statistics
where sql_id='0j06tw291x3m5'
order by child_number;  2    3

no rows selected

SQL> select * from v$sql_cs_selectivity
where sql_id='0j06tw291x3m5'
order by child_number;  2    3

no rows selected

SQL> select * from v$sql_cs_histogram where sql_id='0j06tw291x3m5';

ADDRESS          HASH_VALUE SQL_ID        CHILD_NUMBER  BUCKET_ID      COUNT     CON_ID
---------------- ---------- ------------- ------------ ---------- ---------- ----------
000000007DD472C8 2451476069 0j06tw291x3m5            0          0          0          0
000000007DD472C8 2451476069 0j06tw291x3m5            0          1          1          0
000000007DD472C8 2451476069 0j06tw291x3m5            0          2          0          0

SQL>

==> Last time I made a mistake to query a wrong sql. Anyway now it looks like the histogram gets populated for all bind sqls.


SQL> select sql_id,child_number,is_bind_sensitive,is_bind_aware,is_shareable,plan_hash_value,executions from v$sql where sql_id='0j06tw291x3m5';

SQL_ID        CHILD_NUMBER I I I PLAN_HASH_VALUE EXECUTIONS
------------- ------------ - - - --------------- ----------
0j06tw291x3m5            0 Y N Y      2221297138          2

SQL> select * from v$sql_cs_statistics
where sql_id='0j06tw291x3m5'
order by child_number;  2    3

no rows selected

SQL> select * from v$sql_cs_selectivity
where sql_id='0j06tw291x3m5'
order by child_number;  2    3

no rows selected

SQL> select * from v$sql_cs_histogram where sql_id='0j06tw291x3m5';

ADDRESS          HASH_VALUE SQL_ID        CHILD_NUMBER  BUCKET_ID      COUNT     CON_ID
---------------- ---------- ------------- ------------ ---------- ---------- ----------
000000007DD472C8 2451476069 0j06tw291x3m5            0          0          1          0
000000007DD472C8 2451476069 0j06tw291x3m5            0          1          1          0            <<< INEFFICIENT
000000007DD472C8 2451476069 0j06tw291x3m5            0          2          0          0

SQL> select * from v$sql_shared_cursor where sql_id='0j06tw291x3m5';

SQL_ID        ADDRESS          CHILD_ADDRESS    CHILD_NUMBER U S O O S L F E B P I S T A B D L T B I I R L I O E M U T N F A P T D L D B P C S C P T M B M R O P M F L P L A F L R L H P B U REASON                                                  CON_ID
------------- ---------------- ---------------- ------------ - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -------------------------------------------------------------------------------- ----------
0j06tw291x3m5 000000007DD472C8 000000007D1E4770            0 N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N Y N N N N N N N N N                                                              0

SQL> select sql_id,child_number,is_bind_sensitive,is_bind_aware,is_shareable,plan_hash_value,executions,rows_processed,BUFFER_GETS,DISK_READS,PHYSICAL_READ_REQUESTS,PHYSICAL_READ_BYTES,PHYSICAL_WRITE_REQUESTS,PHYSICAL_WRITE_BYTES,OPTIMIZED_PHY_READ_REQUESTS from v$sql where sql_id='0j06tw291x3m5';

SQL_ID        CHILD_NUMBER I I I PLAN_HASH_VALUE EXECUTIONS ROWS_PROCESSED BUFFER_GETS DISK_READS PHYSICAL_READ_REQUESTS PHYSICAL_READ_BYTES PHYSICAL_WRITE_REQUESTS PHYSICAL_WRITE_BYTES OPTIMIZED_PHY_READ_REQUESTS
------------- ------------ - - - --------------- ---------- -------------- ----------- ---------- ---------------------- ------------------- ----------------------- -------------------- ---------------------------
0j06tw291x3m5            0 Y N Y      2221297138          2              2        2270          0                      0    0                        0                    0                           0

SQL> select * from table(dbms_xplan.display_cursor(sql_id=>'0j06tw291x3m5',cursor_child_no=>0,format=>'ADVANCED'));

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SQL_ID  0j06tw291x3m5, child number 0
-------------------------------------
select count(id) from tst_acs where id=:objid

Plan hash value: 2221297138

------------------------------------------------------------------------------
| Id  | Operation          | Name    | Rows  | Bytes | Cost (%CPU)| Time     |
------------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |         |       |       |   313 (100)|          |
|   1 |  SORT AGGREGATE    |         |     1 |     6 |            |          |
|*  2 |   TABLE ACCESS FULL| TST_ACS |   302K|  1773K|   313   (1)| 00:00:01 |
------------------------------------------------------------------------------

Query Block Name / Object Alias (identified by operation id):
-------------------------------------------------------------

   1 - SEL$1
   2 - SEL$1 / TST_ACS@SEL$1

Outline Data
-------------

  /*+
      BEGIN_OUTLINE_DATA
      IGNORE_OPTIM_EMBEDDED_HINTS
      OPTIMIZER_FEATURES_ENABLE('12.1.0.1')
      DB_VERSION('12.1.0.1')
      ALL_ROWS
      OUTLINE_LEAF(@"SEL$1")
      FULL(@"SEL$1" "TST_ACS"@"SEL$1")
      END_OUTLINE_DATA
  */

Peeked Binds (identified by position):
--------------------------------------

   1 - :OBJID (NUMBER): 9999999

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

   2 - filter("ID"=:OBJID)

Column Projection Information (identified by operation id):
-----------------------------------------------------------

   1 - (#keys=0) COUNT("ID")[22]
   2 - (rowset=200) "ID"[NUMBER,22]


50 rows selected.

SQL>


===> But still other views arent populated.. examining with max object_id which should have 1 hit...


SQL> select sql_id,child_number,is_bind_sensitive,is_bind_aware,is_shareable,plan_hash_value,executions,rows_processed,BUFFER_GETS,DISK_READS,PHYSICAL_READ_REQUESTS,PHYSICAL_READ_BYTES,PHYSICAL_WRITE_REQUESTS,PHYSICAL_WRITE_BYTES,OPTIMIZED_PHY_READ_REQUESTS from v$sql where sql_id='0j06tw291x3m5';

SQL_ID        CHILD_NUMBER I I I PLAN_HASH_VALUE EXECUTIONS ROWS_PROCESSED BUFFER_GETS DISK_READS PHYSICAL_READ_REQUESTS PHYSICAL_READ_BYTES PHYSICAL_WRITE_REQUESTS PHYSICAL_WRITE_BYTES OPTIMIZED_PHY_READ_REQUESTS
------------- ------------ - - - --------------- ---------- -------------- ----------- ---------- ---------------------- ------------------- ----------------------- -------------------- ---------------------------
0j06tw291x3m5            0 Y N N      2221297138          2              2        2270          0                      0    0                        0                    0                           0
0j06tw291x3m5            1 Y Y Y      1292819319          1              1           3          0                      0    0                        0                    0                           0

SQL> select sql_id,child_number,is_bind_sensitive,is_bind_aware,is_shareable,plan_hash_value,executions from v$sql where sql_id='0j06tw291x3m5';

SQL_ID        CHILD_NUMBER I I I PLAN_HASH_VALUE EXECUTIONS
------------- ------------ - - - --------------- ----------
0j06tw291x3m5            0 Y N N      2221297138          2
0j06tw291x3m5            1 Y Y Y      1292819319          1


==> New cursor is created as expected, plan changed. Also the first cursor is marked not sharable.

select * from table(dbms_xplan.display_cursor(sql_id=>'0j06tw291x3m5',cursor_child_no=>1,format=>'ADVANCED'));


SQL> select * from table(dbms_xplan.display_cursor(sql_id=>'0j06tw291x3m5',cursor_child_no=>1,format=>'ADVANCED'));

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SQL_ID  0j06tw291x3m5, child number 1
-------------------------------------
select count(id) from tst_acs where id=:objid

Plan hash value: 1292819319

---------------------------------------------------------------------------------
| Id  | Operation         | Name        | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |             |       |       |     3 (100)|          |
|   1 |  SORT AGGREGATE   |             |     1 |     6 |            |          |
|*  2 |   INDEX RANGE SCAN| TST_ACS_IDX |     1 |     6 |     3   (0)| 00:00:01 |
---------------------------------------------------------------------------------

Query Block Name / Object Alias (identified by operation id):
-------------------------------------------------------------

   1 - SEL$1
   2 - SEL$1 / TST_ACS@SEL$1

Outline Data
-------------

  /*+
      BEGIN_OUTLINE_DATA
      IGNORE_OPTIM_EMBEDDED_HINTS
      OPTIMIZER_FEATURES_ENABLE('12.1.0.1')
      DB_VERSION('12.1.0.1')
      ALL_ROWS
      OUTLINE_LEAF(@"SEL$1")
      INDEX(@"SEL$1" "TST_ACS"@"SEL$1" ("TST_ACS"."ID"))
      END_OUTLINE_DATA
  */

Peeked Binds (identified by position):
--------------------------------------

   1 - :OBJID (NUMBER): 93211

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

   2 - access("ID"=:OBJID)

Column Projection Information (identified by operation id):
-----------------------------------------------------------

   1 - (#keys=0) COUNT("ID")[22]
   2 - "ID"[NUMBER,22]


50 rows selected.

SQL>

SQL> select * from v$sql_cs_statistics
where sql_id='0j06tw291x3m5'
order by child_number;  2    3

no rows selected

SQL> select * from v$sql_cs_selectivity
where sql_id='0j06tw291x3m5'
order by child_number;  2    3

ADDRESS          HASH_VALUE SQL_ID        CHILD_NUMBER PREDICATE                                  RANGE_ID LOW        HIGH     CON_ID
---------------- ---------- ------------- ------------ ---------------------------------------- ---------- ---------- ---------- ----------
000000007DD472C8 2451476069 0j06tw291x3m5            1 =OBJID                                            0 0.000003   0.000003              0        <<<< Selectivity is accurate 1/367332 apprx 2.7*E-6

SQL> select * from v$sql_cs_histogram where sql_id='0j06tw291x3m5';

ADDRESS          HASH_VALUE SQL_ID        CHILD_NUMBER  BUCKET_ID      COUNT     CON_ID
---------------- ---------- ------------- ------------ ---------- ---------- ----------
000000007DD472C8 2451476069 0j06tw291x3m5            1          0          1          0
000000007DD472C8 2451476069 0j06tw291x3m5            1          1          0          0
000000007DD472C8 2451476069 0j06tw291x3m5            1          2          0          0
000000007DD472C8 2451476069 0j06tw291x3m5            0          0          1          0
000000007DD472C8 2451476069 0j06tw291x3m5            0          1          1          0
000000007DD472C8 2451476069 0j06tw291x3m5            0          2          0          0

6 rows selected.

SQL>


So this is done the ACS works as expected, when we queried most records of the table we got a FTS and when we tried querying only 1 record acs came for rescue, though we had 1 iteration running into an issue.

thanks

Impact of sorting/nosorting and usage of parallel clause when creating table on the clustering factor of the index associated with the table

Goal: Impact of sorting/nosorting and usage of parallel clause when creating table on the clustering factor of the index associated with the table.

No parallel loads:
create tablespace test_assm
blocksize 8K
datafile size 10m autoextend on maxsize 50m
extent management local
uniform size 1M
segment space management auto
;

create table scott.t1 tablespace test_assm
as
select * from dba_objects;


Use T1 to populate further tables in sorted manner and non-sorted manner...

drop tablespace test_assm_nosort including contents and datafiles;
drop tablespace test_assm_sort including contents and datafiles;

create tablespace test_assm_sort
blocksize 8K
datafile size 10m autoextend on maxsize 50m
extent management local
uniform size 1M
segment space management auto
;

create tablespace test_assm_nosort
blocksize 8K
datafile size 10m autoextend on maxsize 50m
extent management local
uniform size 1M
segment space management auto
;


create table scott.t1_sort tablespace test_assm_nosort
as
select * from scott.t1
order by object_id;

create table scott.t1_nosort tablespace test_assm_sort
as
select * from scott.t1;

let us now create an index on object_id column....

create index scott.t1_sort_idx on scott.t1_sort(object_id);
create index scott.t1_nosort_idx on scott.t1_nosort(object_id);

exec dbms_stats.gather_table_stats('SCOTT','T1_SORT');
exec dbms_stats.gather_table_stats('SCOTT','T1_NoSORT');

alter session set nls_Date_Format='DD/MM/YYYY HH24:MI';

col owner for a10
col table_name for a10
col index_name for a20
col INDEX_TYPE for a10
select a.owner,a.table_name,a.num_rows,a.last_analyzed,b.index_name,b.index_type,b.uniqueness,b.clustering_factor,b.num_rows
from dba_tables a,dba_indexes b
where a.owner=b.owner
and a.table_name=b.table_name
and a.table_name like 'T1_%'
and a.owner='SCOTT'
order by owner,table_name,index_name;

select a.owner,a.table_name,a.num_rows,a.last_analyzed tbl_analyz,b.index_name,b.index_type,b.last_analyzed indx_analz,b.clustering_factor,b.num_rows
from dba_tables a,dba_indexes b
where a.owner=b.owner
and a.table_name=b.table_name
and a.table_name like 'T1_%'
and a.owner='SCOTT'
order by owner,table_name,index_name;


SQL> select a.owner,a.table_name,a.num_rows,a.last_analyzed,b.index_name,b.index_type,b.uniqueness,b.clustering_factor,b.num_rows
  2  from dba_tables a,dba_indexes b
  3  where a.owner=b.owner
  4  and a.table_name=b.table_name
  5  and a.table_name like 'T1_%'
  6  and a.owner='SCOTT'
  7  order by owner,table_name,index_name;

OWNER      TABLE_NAME   NUM_ROWS LAST_ANALYZED    INDEX_NAME           INDEX_TYPE UNIQUENES CLUSTERING_FACTOR   NUM_ROWS
---------- ---------- ---------- ---------------- -------------------- ---------- --------- ----------------- ----------
SCOTT      T1_NOSORT       91818 14/09/2018 19:28 T1_NOSORT_IDX        NORMAL     NONUNIQUE              2519      91818
SCOTT      T1_SORT         91818 14/09/2018 19:28 T1_SORT_IDX          NORMAL     NONUNIQUE              1541      91818

SQL>

SQL> select a.owner,a.table_name,a.num_rows,a.last_analyzed tbl_analyz,b.index_name,b.index_type,b.last_analyzed indx_analz,b.clustering_factor,b.num_rows
from dba_tables a,dba_indexes b
where a.owner=b.owner
  2    3    4  and a.table_name=b.table_name
  5  and a.table_name like 'T1_%'
and a.owner='SCOTT'
  6    7  order by owner,table_name,index_name;

OWNER      TABLE_NAME   NUM_ROWS TBL_ANALYZ       INDEX_NAME           INDEX_TYPE INDX_ANALZ       CLUSTERING_FACTOR   NUM_ROWS
---------- ---------- ---------- ---------------- -------------------- ---------- ---------------- ----------------- ----------
SCOTT      T1_NOSORT       91818 14/09/2018 19:28 T1_NOSORT_IDX        NORMAL     14/09/2018 19:28              2519      91818
SCOTT      T1_SORT         91818 14/09/2018 19:28 T1_SORT_IDX          NORMAL     14/09/2018 19:28              1541      91818

SQL>



==> so we evidently see there is a difference in the clustering factor for a table loaded in sorted manner vs the other.

Now let us proceed to magnify this further.. inclusion of parallel clause.

create tablespace test_assm_px_sort
blocksize 8K
datafile size 10m autoextend on maxsize 50m
extent management local
uniform size 1M
segment space management auto
;

create tablespace test_assm_px_nosort
blocksize 8K
datafile size 10m autoextend on maxsize 50m
extent management local
uniform size 1M
segment space management auto
;

create table scott.t1_px_sort tablespace test_assm_px_sort
as
select /*+ parallel(a,4) */ * from scott.t1 a
order by object_id;

create table scott.t1_px_nosort tablespace test_assm_px_nosort
as
select /*+ parallel(a,4) */ * from scott.t1 a;


create index scott.t1_px_sort_idx on scott.t1_px_sort(object_id);
create index scott.t1_px_nosort_idx on scott.t1_px_nosort(object_id);

SQL> select a.owner,a.table_name,a.num_rows,a.last_analyzed,b.index_name,b.index_type,b.uniqueness,b.clustering_factor,b.num_rows
  2  from dba_tables a,dba_indexes b
where a.owner=b.owner
  3    4  and a.table_name=b.table_name
  5  and a.table_name like 'T1_%'
and a.owner='SCOTT'
  6    7  order by owner,table_name,index_name;


OWNER     ,TABLE_NAME          ,  NUM_ROWS,LAST_ANALYZED      ,INDEX_NAME          ,INDEX_TYPE,UNIQUENES,CLUSTERING_FACTOR,  NUM_ROWS
----------,--------------------,----------,-------------------,--------------------,----------,---------,-----------------,----------
SCOTT     ,T1_NOSORT           ,     91818,14/09/2018 19:58:43,T1_NOSORT_IDX       ,NORMAL    ,NONUNIQUE,             2519,       91818
SCOTT     ,T1_PX_NOSORT        ,     91818,14/09/2018 19:58:51,T1_PX_NOSORT_IDX    ,NORMAL    ,NONUNIQUE,             3783,       91818
SCOTT     ,T1_PX_SORT          ,     91818,14/09/2018 19:58:50,T1_PX_SORT_IDX      ,NORMAL    ,NONUNIQUE,             1541,       91818
SCOTT     ,T1_SORT             ,     91818,14/09/2018 19:58:43,T1_SORT_IDX         ,NORMAL    ,NONUNIQUE,             1541,       91818

SQL> select a.owner,a.table_name,a.num_rows,a.last_analyzed tbl_analyz,b.index_name,b.index_type,b.last_analyzed indx_analz,b.clustering_factor,b.num_rows
from dba_tables a,dba_indexes b
  2    3  where a.owner=b.owner
and a.table_name=b.table_name
  4    5  and a.table_name like 'T1_%'
and a.owner='SCOTT'
  6    7  order by owner,table_name,index_name;


OWNER     ,TABLE_NAME          ,  NUM_ROWS,TBL_ANALYZ         ,INDEX_NAME          ,INDEX_TYPE,INDX_ANALZ         ,CLUSTERING_FACTOR,  NUM_ROWS
----------,--------------------,----------,-------------------,--------------------,----------,-------------------,-----------------,----------
SCOTT     ,T1_NOSORT           ,     91818,14/09/2018 19:58:43,T1_NOSORT_IDX       ,NORMAL    ,14/09/2018 19:58:44,      2519,      91818
SCOTT     ,T1_PX_NOSORT        ,     91818,14/09/2018 19:58:51,T1_PX_NOSORT_IDX    ,NORMAL    ,14/09/2018 19:58:51,      3783,      91818
SCOTT     ,T1_PX_SORT          ,     91818,14/09/2018 19:58:50,T1_PX_SORT_IDX      ,NORMAL    ,14/09/2018 19:58:50,      1541,      91818
SCOTT     ,T1_SORT             ,     91818,14/09/2018 19:58:43,T1_SORT_IDX         ,NORMAL    ,14/09/2018 19:58:43,      1541,      91818



conclusion: if we observe same set of data and same type of index, but look if the table is loaded with parallel clause with no sort then the clustering factor is nearly 2x more than the viceversa condition.

Thanks

Tuesday, September 11, 2018

Oracle 12.1 example for regular expression replace (regexp_replace) of single quote

Goal: example for regular expression replace.

In real world we wouldnt like the search expression or pattern associated with the text output we need. So let us move on to replace those patterns such that we get what we need.

Candidate Text:

SQL> select ('Hi this is ''ramu'' and here is the ''rose''') string_tosearch from dual;

STRING_TOSEARCH
----------------------------------------
Hi this is 'ramu' and here is the 'rose'


We in the previous blog [http://oracledbaplanner.blogspot.com/2018/09/examples-of-regexpsubstr-usage-in.html] noticed we can use the below sql to filter out the first occurence of a substring covered by single quote.

SQL> select regexp_substr('Hi this is ''ramu'' and here is the ''rose''','''([[:alnum:]]+'')') srch_result from dual;

SRCH_R
------
'ramu'


We have the search pattern which is single quote still reported, so now let us see how can we replace this single quotes such that we get only the text we need.

SQL> select regexp_replace(regexp_substr('Hi this is ''ramu'' and here is the ''rose''','''([[:alnum:]]+'')'),'('')','') replaced_text from dual;

REPL
----
ramu


Now from 'ramu' it came down to ramu.

Thanks

Oracle 12.1 example of regexp_substr usage - filter single quote

Goal: Let us see how can we filter out only the single quoted string from the below text.

Query 1:
select ('Hi this is ''ramu''') from dual;


SQL> select ('Hi this is ''ramu''') from dual;

('HITHISIS''RAMU'
-----------------
Hi this is 'ramu'

Solution:
select regexp_substr('Hi this is ''ramu''','''([[:alnum:]]+'')') from dual;

Explanation:
Examine the actual substr expression the below way, you will know what exactly is your substring filter.

SQL> select ('''([[:alnum:]]+'')') from dual;

('''([[:ALNUM:]]
----------------
'([[:alnum:]]+')

Here,
(i) ''' (single quotes) in the regular expression filter is '''([[:alnum:]]+'')' actually translated to a 2 single quote 1 is used as the format for substr expression

and other is used for the search (here this indicates start my search from first single quote apperarence).
(ii) bracets () covering is used again as a format controller to group the next set of search conditions
(iii) []+ tells that I should look for text starting with single quote and what ever is mentioned within this enclosure, which here is a substring of alphanumeric

characters which is [:alnum:].
(iv) '')' tells that I should end my search with the next consective appearence of a single quote (indicated by ''). We close our search with the closing bracket.

Hope this is clear.

Let us evaulate weather the explanation holds correct by another example...

SQL> select ('Hi this is ''ramu'' and here is the ''rose''') string_tosearch from dual;

STRING_TOSEARCH
----------------------------------------
Hi this is 'ramu' and here is the 'rose'

SQL> select regexp_substr('Hi this is ''ramu'' and here is the ''rose''','''([[:alnum:]]+'')') srch_result from dual;

SRCH_R
------
'ramu'

let us see how can we filter out the second consecutive occurence of the single quoted string.


Solution:

select regexp_substr('Hi this is ''ramu'' and here is the ''rose''','''([[:alnum:]]+'')',1,2) srch_result from dual;

SQL> select ('Hi this is ''ramu'' and here is the ''rose''') string_tosearch from dual;

STRING_TOSEARCH
----------------------------------------
Hi this is 'ramu' and here is the 'rose'

SQL> select regexp_substr('Hi this is ''ramu'' and here is the ''rose''','''([[:alnum:]]+'')',1,2) srch_result from dual;

SRCH_R
------
'rose'


Explanation:
a)  Here ,1,2 within the brackets indicate that the search should begin from 1st position and look for second consecutive occurrence of the matching pattern.

if I wanted to search for what ever starting with ^ until ! or end of line...

select ('Hi,this is''nt a joke!, we know where to look for! if we dont find him in ^Krish will come! back to you!') string_tosearch from dual;

SQL> select ('Hi,this is''nt a joke!, we know where to look for! if we dont find him in ^Krish will come! back to you!') string_tosearch from dual;

STRING_TOSEARCH
-------------------------------------------------------------------------------------------------------
Hi,this is'nt a joke!, we know where to look for! if we dont find him in ^Krish will come! back to you!


Solution:
select regexp_substr('Hi,this is''nt a joke!, we know where to look for! if we dont find him in ^Krish will come! back to you!','\^[^!]+!') srch_result from dual;

SQL> select regexp_substr('Hi,this is''nt a joke!, we know where to look for! if we dont find him in ^Krish will come! back to you!','\^[^!]+!') srch_result from dual;

SRCH_RESULT
-----------------
^Krish will come!


Here what we did was we looked @ first occurence of a pattern which started with ^ and ended with !, we get both leading and trailing characters printed here.


The '+' symbol signifies we search for one or more occurrence of the  preceding search pattern.







Thanks


Conclusion: We are correctly filtering out the sub-string enclosed by a single quote in the position we call out. We even filtered out special characters.

Use case: Being a DBA you can use this to filter out literals used in sqltext

Flashback data archive steps

 Objective: Ways to track DML changes in a table Detailed objective: We should be able to track the changes in the table at any point in tim...