The Fake Index Trap (“Nowhere Now”) May 2, 2023
Posted by Richard Foote in CBO, Drop Index, Fake Indexes, Index Internals, NOSEGMENT Option, Online DDL, Oracle, Oracle 21c, Oracle Bugs, Oracle General, Oracle Indexes, Oracle Indexing Internals Webinar, Oracle19c, Tablespace Management, Virtual Indexes.add a comment
In a recent correspondence, I was alerted to an issue in relation to the use of Virtual/Fake/Nosegment Indexes that I wasn’t aware of previously. Having a play, it appears this issue is still present in at least Oracle Database 21c, so I thought it worth a mention in case anyone else happens to fall into this trap.
I’ve discussed Virtual/Fake/Nosegment Indexes a number of times previously. These are indexes that do not exist as a physical segment (and so can be created almost immediately without consuming any storage), that can be used to determine if an index could potentially be used by the CBO if it were to be actually created.
Although such Fake Indexes don’t physically exist, they can cause issues if forgotten…
To illustrate this issue, I’ll start by creating a new tablespace:
SQL> create tablespace BOWIE_TS datafile 'C:\ORADATA\ZIGGY\ZIGGYPDB1\BOWIE_TS.DBF' size 100M; Tablespace created.
Next, I’ll create and populate a table in this BOWIE_TS tablespace:
SQL> create table bowie_test (id number, name varchar2(42)) tablespace bowie_ts; Table created. SQL> insert into bowie_test select rownum, 'DAVID BOWIE' from dual connect by level <=10000; 10000 rows created. SQL> commit; Commit complete. SQL> exec dbms_stats.gather_table_stats(ownname=>null, tabname=>'BOWIE_TEST'); PL/SQL procedure successfully completed.
I’ll next create a Virtual/Fake index, using the NOSEGMENT option:
SQL> create index bowie_test_id_i on bowie_test(id) nosegment tablespace bowie_ts; Index created.
We note this Fake Index is NOT listed in either USER_INDEXES or USER_SEGMENTS:
SQL> select index_name, tablespace_name from user_indexes where table_name='BOWIE_TEST'; no rows selected SQL> select segment_name, segment_type, tablespace_name from user_segments where segment_name='BOWIE_TEST_ID_I'; no rows selected
If we run a basic, highly selective query on this table:
SQL> select * from bowie_test where id=42; Execution Plan ---------------------------------------------------------- Plan hash value: 65548668 -------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | -------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 16 | 11 (0) | 00:00:01 | |* 1 | TABLE ACCESS FULL | BOWIE_TEST | 1 | 16 | 11 (0) | 00:00:01 | -------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - filter("ID"=42) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 38 consistent gets 0 physical reads 0 redo size 648 bytes sent via SQL*Net to client 52 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 1 rows processed
We notice the CBO uses a FTS. The Fake Index is NOT considered by default.
However, if we set the session as follows and re-run the query:
SQL> alter session set "_use_nosegment_indexes" = true; Session altered. SQL> select * from bowie_test where id=42; Execution Plan ---------------------------------------------------------- Plan hash value: 1280686875 ------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | ------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 16 | 2 (0) | 00:00:01 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE_TEST | 1 | 16 | 2 (0) | 00:00:01 | |* 2 | INDEX RANGE SCAN | BOWIE_TEST_ID_I | 1 | | 1 (0) | 00:00:01 | ------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID"=42) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 38 consistent gets 0 physical reads 0 redo size 648 bytes sent via SQL*Net to client 52 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 1 rows processed
We can see the CBO appears to now use the Fake Index, but as it doesn’t actually physically exist, actually uses a FTS behind the scenes (the number of consistent gets is evidence of this). But at least we now know the CBO would at least consider such an index if it physically existed.
We now decide to drop the tablespace and so first try to MOVE the table to another tablespace using the ONLINE option:
SQL> alter table bowie_test move online tablespace users; alter table bowie_test move online tablespace users * ERROR at line 1: ORA-14808: table does not support ONLINE MOVE TABLE because of the presence of nosegment index
The error message clearly states we can’t move the table ONLINE if such a Fake/Nosegment Index exists. This is our official warning of the potential danger to come…
We try to move the table using the default OFFLINE method:
SQL> alter table bowie_test move tablespace users; Table altered.
We have now successfully moved the table to another tablespace.
If we check to see if we have any other segments within the tablespace yto be dropped:
SQL> select segment_name from dba_segments where tablespace_name='BOWIE_TS'; no rows selected
Oracle tells us that no, we do NOT have any current segments in this tablespace.
So it’s now safe to purge and drop this tablespace (or so we think):
SQL> purge tablespace bowie_ts; Tablespace purged. SQL> drop tablespace bowie_ts; Tablespace dropped.
The tablespace has been successfully dropped.
However, if we now re-run the query on this table:
SQL> select * from bowie_test where id=42; select * from bowie_test where id=42 * ERROR at line 1: ORA-00959: tablespace 'BOWIE_TS' does not exist
We get this unexpected error that the tablespace BOWIE_TS does not exist.
BUT, we already know the tablespace doesn’t exist, we’ve just dropped it !!!
So why are we getting this error?
It’s all due to the damn Fake Index we created previously.
Although there is no physical index segment for our Fake Index, there are still some internal Data Dictionary links between the Fake Index and the tablespace it was associated with. The tablespace is gone, but NOT the Fake Index.
The only place where fake indexes can be easily found within Oracle, is within the USER_OBJECTS view:
SQL> select o.object_name, o.object_type, o.status from user_objects o left join user_indexes i on o.object_name=i.index_name where o.object_type='INDEX' and i.index_name is null; OBJECT_NAME OBJECT_TYPE STATUS ------------------------------ ----------------------- ------- BOWIE_TEST_ID_I INDEX VALID
To eliminate this error, we have to first drop the Fake Index associated with the dropped tablespace:
SQL> drop index bowie_test_id_i; Index dropped.
We can now safely run the query without error:
SQL> select * from bowie_test where id=42; ID NAME ---------- ------------------------------------------ 42 DAVID BOWIE
So if you do ever create Fake Indexes, don’t forget to drop them once you’ve finished experimenting with them.
ESPECIALLY if you ever decide to drop the tablespace into which they were associated. This is explained in part in Oracle Support Doc ID 1361049.1.
Possible Impact To Clustering Factor Now ROWIDs Are Updated When Rows Migrate Part I (“Growin’ Up”) March 1, 2023
Posted by Richard Foote in 19c, 19c New Features, Attribute Clustering, Autonomous Data Warehouse, Autonomous Database, Autonomous Transaction Processing, BLEVEL, CBO, Changing ROWID, Clustering Factor, Data Clustering, Hints, Index Access Path, Index Block Splits, Index Delete Operations, Index Height, Index Internals, Index Rebuild, Index statistics, Leaf Blocks, Migrated Rows, Oracle, Oracle Blog, Oracle Cloud, Oracle Cost Based Optimizer, Oracle General, Oracle Indexes, Oracle Indexing Internals Webinar, Oracle Statistics, Oracle19c, Performance Tuning, Richard Foote Training, Richard's Blog, ROWID.2 comments
In my previous post I discussed how an index can potentially be somewhat inflated in size after ROWIDs are updated on the fly after a substantial number of rows are migrated.
However, there’s another key “factor” of an index that in some scenarios can be impacted by this new ROWID behaviour with regard migrated rows.
To highlight this scenario, I’ll again start by creating and populating a table with ENABLE ROW MOVEMENT disabled:
SQL> create table bowie(id number, code1 number, code2 number, code3 number, code4 number, code5 number, code6 number, code7 number, code8 number, code9 number, code10 number, code11 number, code12 number, code13 number, code14 number, code15 number, code16 number, code17 number, code18 number, code19 number, code20 number, name varchar2(142)) PCTFREE 0; Table BOWIE created. SQL> insert into bowie SELECT rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, 'BOWIE' FROM dual CONNECT BY LEVEL <= 200000; 200,000 rows inserted. SQL> commit; Commit complete. SQL> exec dbms_stats.gather_table_stats(ownname=>null, tabname=>'BOWIE', estimate_percent=> null, no_invalidate=>false); PL/SQL procedure successfully completed.
I’ll next create an index on the ID column. The important aspect with the ID column is that the data is entered monotonically in ID column order, so the associated index will have an excellent (very low) Clustering Factor:
SQL> create index bowie_id_i on bowie(id); Index BOWIE_ID_I created.
If we look at some key statistics of the table and index:
SQL> select table_name, num_rows, blocks from user_tables where table_name='BOWIE'; TABLE_NAME NUM_ROWS BLOCKS _____________ ___________ _________ BOWIE 200000 3268 SQL> select index_name, blevel, leaf_blocks, clustering_factor from user_indexes where table_name='BOWIE'; INDEX_NAME BLEVEL LEAF_BLOCKS CLUSTERING_FACTOR _____________ _________ ______________ ____________________ BOWIE_ID_I 1 473 3250
We can see that the number of table blocks is 3268, the number of index leaf blocks is 473 and we indeed have a near perfect Clustering Factor of 3250.
If we run a couple of queries:
SQL> select * from bowie where id between 1 and 1000; 1,000 rows selected. PLAN_TABLE_OUTPUT _______________________________________________________________________________________________________________ SQL_ID gz5u92hmjwz1h, child number 0 ------------------------------------- select * from bowie where id between 1 and 1000 Plan hash value: 1405654398 ------------------------------------------------------------------------------------------------------------ | Id | Operation | Name | Starts | E-Rows | A-Rows | A-Time | Buffers | ------------------------------------------------------------------------------------------------------------ | 0 | SELECT STATEMENT | | 1 | | 1000 |00:00:00.01 | 18 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE | 1 | 1000 | 1000 |00:00:00.01 | 18 | |* 2 | INDEX RANGE SCAN | BOWIE_ID_I | 1 | 1000 | 1000 |00:00:00.01 | 4 | ------------------------------------------------------------------------------------------------------------ Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID">=1 AND "ID"<=1000) Note ----- - automatic DOP: Computed Degree of Parallelism is 1 because of no expensive parallel operation Statistics ----------------------------------------------------------- 1 CPU used by this session 1 CPU used when call started 7353 RM usage 3 Requests to/from client 2 SQL*Net roundtrips to/from client 16 buffer is not pinned count 1985 buffer is pinned count 324 bytes received via SQL*Net from client 171305 bytes sent via SQL*Net to client 2 calls to get snapshot scn: kcmgss 2 calls to kcmgcs 18 consistent gets 1 consistent gets examination 1 consistent gets examination (fastpath) 18 consistent gets from cache 17 consistent gets pin 17 consistent gets pin (fastpath) 2 execute count 1 index range scans 147456 logical read bytes from cache 17 no work - consistent read gets 38 non-idle wait count 2 opened cursors cumulative 1 opened cursors current 2 parse count (total) 1 process last non-idle time 2 session cursor cache count 18 session logical reads 1 sorts (memory) 2024 sorts (rows) 1000 table fetch by rowid 3 user calls
We can see for this first query that returns 1000 rows, it requires just 18 consistent gets, thanks primarily due to the efficient index with the perfect Clustering Factor.
If we look at the cost of this plan:
SQL> SELECT * FROM TABLE(DBMS_XPLAN.display_cursor(sql_id=>'gz5u92hmjwz1h',format=>'ALLSTATS LAST +cost +bytes')); PLAN_TABLE_OUTPUT ____________________________________________________________________________________________________________________________________ SQL_ID gz5u92hmjwz1h, child number 0 ------------------------------------- select * from bowie where id between 1 and 1000 Plan hash value: 1405654398 --------------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows | A-Time | Buffers | --------------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | | 21 (100)| 1000 |00:00:00.01 | 18 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE | 1 | 1000 | 108K| 21 (0)| 1000 |00:00:00.01 | 18 | |* 2 | INDEX RANGE SCAN | BOWIE_ID_I | 1 | 1000 | | 4 (0)| 1000 |00:00:00.01 | 4 | --------------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID">=1 AND "ID"<=1000)
We can see the plan has an accurate cost of just 21.
If we now run a similar query that returns a few more rows:
SQL> select * from bowie where id between 1 and 4200; 4,200 rows selected. PLAN_TABLE_OUTPUT _______________________________________________________________________________________________________________ SQL_ID c376kdhy5b0x9, child number 0 ------------------------------------- select * from bowie where id between 1 and 4200 Plan hash value: 1405654398 ------------------------------------------------------------------------------------------------------------ | Id | Operation | Name | Starts | E-Rows | A-Rows | A-Time | Buffers | ------------------------------------------------------------------------------------------------------------ | 0 | SELECT STATEMENT | | 1 | | 4200 |00:00:00.01 | 68 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE | 1 | 4200 | 4200 |00:00:00.01 | 68 | |* 2 | INDEX RANGE SCAN | BOWIE_ID_I | 1 | 4200 | 4200 |00:00:00.01 | 11 | ------------------------------------------------------------------------------------------------------------ Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID">=1 AND "ID"<=4200) Note ----- - automatic DOP: Computed Degree of Parallelism is 1 because of no expensive parallel operation Statistics ----------------------------------------------------------- 1 CPU used by this session 1 CPU used when call started 1 DB time 11353 RM usage 3 Requests to/from client 2 SQL*Net roundtrips to/from client 59 buffer is not pinned count 8342 buffer is pinned count 324 bytes received via SQL*Net from client 461834 bytes sent via SQL*Net to client 2 calls to get snapshot scn: kcmgss 2 calls to kcmgcs 68 consistent gets 1 consistent gets examination 1 consistent gets examination (fastpath) 68 consistent gets from cache 67 consistent gets pin 67 consistent gets pin (fastpath) 2 execute count 1 index range scans 557056 logical read bytes from cache 67 no work - consistent read gets 73 non-idle wait count 2 opened cursors cumulative 1 opened cursors current 2 parse count (total) 1 process last non-idle time 2 session cursor cache count 68 session logical reads 1 sorts (memory) 2024 sorts (rows) 4200 table fetch by rowid 3 user calls
We can see that it only required just 68 consistent gets to return 4200 rows, thanks to the excellent data clustering and associated very low Clustering Factor.
If we look at the cost of this plan:
SQL> SELECT * FROM TABLE(DBMS_XPLAN.display_cursor(sql_id=>'c376kdhy5b0x9',format=>'ALLSTATS LAST +cost +bytes')); PLAN_TABLE_OUTPUT ____________________________________________________________________________________________________________________________________ SQL_ID c376kdhy5b0x9, child number 0 ------------------------------------- select * from bowie where id between 1 and 4200 Plan hash value: 1405654398 --------------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows | A-Time | Buffers | --------------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | | 80 (100)| 4200 |00:00:00.01 | 68 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE | 1 | 4200 | 455K| 80 (0)| 4200 |00:00:00.01 | 68 | |* 2 | INDEX RANGE SCAN | BOWIE_ID_I | 1 | 4200 | | 11 (0)| 4200 |00:00:00.01 | 11 | --------------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID">=1 AND "ID"<=4200)
We can see the cost of the plan is currently a relatively accurate 80.
OK, let’s now perform an update on this table that generates a bunch of migrated rows:
SQL> update bowie set name='THE RISE AND FALL OF BOWIE STARDUST AND THE SPIDERS FROM MARS'; 200,000 rows updated. SQL> commit; Commit complete.
If we now look at the table and index statistics:
SQL> exec dbms_stats.gather_table_stats(ownname=>null, tabname=>'BOWIE', estimate_percent=> null, no_invalidate=>false); PL/SQL procedure successfully completed. SQL> select table_name, num_rows, blocks from user_tables where table_name='BOWIE'; TABLE_NAME NUM_ROWS BLOCKS _____________ ___________ _________ BOWIE 200000 4906
We can see that the table blocks value has increased to 4906 (previously 3268). This as explained previously is to due in large part to the increased NAME column values and also due to the pointers in the original table blocks that point to the new locations of the migrated rows.
This relates to approximately a 50% increase in table blocks.
If we look at the current index statistics:
SQL> select index_name, blevel, leaf_blocks, clustering_factor from user_indexes where table_name='BOWIE'; INDEX_NAME BLEVEL LEAF_BLOCKS CLUSTERING_FACTOR _____________ _________ ______________ ____________________ BOWIE_ID_I 1 473 3250
We can see that these values are all unchanged, as the ROWIDs in indexes remain unchanged when a row migrates, when ENABLE ROW MOVEMENT is not set.
Therefore, when we re-run these same queries:
SQL> select * from bowie where id between 1 and 1000; 1,000 rows selected. PLAN_TABLE_OUTPUT _______________________________________________________________________________________________________________ SQL_ID gz5u92hmjwz1h, child number 0 ------------------------------------- select * from bowie where id between 1 and 1000 Plan hash value: 1405654398 ------------------------------------------------------------------------------------------------------------ | Id | Operation | Name | Starts | E-Rows | A-Rows | A-Time | Buffers | ------------------------------------------------------------------------------------------------------------ | 0 | SELECT STATEMENT | | 1 | | 1000 |00:00:00.01 | 666 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE | 1 | 1000 | 1000 |00:00:00.01 | 666 | |* 2 | INDEX RANGE SCAN | BOWIE_ID_I | 1 | 1000 | 1000 |00:00:00.01 | 4 | ------------------------------------------------------------------------------------------------------------ Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID">=1 AND "ID"<=1000) Note ----- - automatic DOP: Computed Degree of Parallelism is 1 because of no expensive parallel operation Statistics ----------------------------------------------------------- 1 DB time 7967 RM usage 3 Requests to/from client 2 SQL*Net roundtrips to/from client 664 buffer is not pinned count 1664 buffer is pinned count 324 bytes received via SQL*Net from client 171419 bytes sent via SQL*Net to client 2 calls to get snapshot scn: kcmgss 2 calls to kcmgcs 666 consistent gets 1 consistent gets examination 1 consistent gets examination (fastpath) 666 consistent gets from cache 665 consistent gets pin 665 consistent gets pin (fastpath) 2 execute count 1 index range scans 5455872 logical read bytes from cache 665 no work - consistent read gets 37 non-idle wait count 2 opened cursors cumulative 1 opened cursors current 2 parse count (total) 1 process last non-idle time 2 session cursor cache count 666 session logical reads 1 sorts (memory) 2024 sorts (rows) 1000 table fetch by rowid 327 table fetch continued row 3 user calls
The number of consistent gets has increased significantly to 666 (previously it was just 18).
Now we can attributed an increase of approximately 50% of the previous consistent gets (18 x 0.50 = 9) due to the 50% increase in table blocks required now to store the rows due to the increased row size.
We can also attribute an additional 327 consistent gets for the table fetch continued row value listed in the statistics, representing the extra consistent gets required to access the migrated rows from their new physical location.
But 18 + 9 + 327 = 354 still leaves us short of the new 666 consistent gets value.
The problem with having to visit another table block to get a row from its new location is that it means Oracle has to re-access again the original table block to get the next row (rather than reading multiple rows with the same consistent get).
So it’s actually approximately 2 x table fetch continued row, by which the number of consistent gets is going to increase when accessing migrated rows (noting that the last migrated row in a block will only incur a additional consistent get as the next table block accessed will differ regardless).
If we look at the new CBO cost for this plan:
SQL> SELECT * FROM TABLE(DBMS_XPLAN.display_cursor(sql_id=>'gz5u92hmjwz1h',format=>'ALLSTATS LAST +cost +bytes')); PLAN_TABLE_OUTPUT ____________________________________________________________________________________________________________________________________ SQL_ID gz5u92hmjwz1h, child number 0 ------------------------------------- select * from bowie where id between 1 and 1000 Plan hash value: 1405654398 --------------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows | A-Time | Buffers | --------------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | | 21 (100)| 1000 |00:00:00.01 | 666 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE | 1 | 1000 | 163K| 21 (0)| 1000 |00:00:00.01 | 666 | |* 2 | INDEX RANGE SCAN | BOWIE_ID_I | 1 | 1000 | | 4 (0)| 1000 |00:00:00.01 | 4 | --------------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID">=1 AND "ID"<=1000)
We notice the CBO cost for this plan remains unchanged at 21.
This is totally to be expected, as the index statistics by which the cost of an index scan is calculated are unchanged.
Considering the rough “rule of thumb” is that the CBO cost of an index scan should be in the ball-park of the number of possible IOs, the fact the plan now uses 666 consistent gets highlights this cost of just 21 is no longer as accurate…
If we look at the second SQL that returns 4200 rows:
SQL> select * from bowie where id between 1 and 4200; 4,200 rows selected. PLAN_TABLE_OUTPUT _______________________________________________________________________________________________________________ SQL_ID c376kdhy5b0x9, child number 0 ------------------------------------- select * from bowie where id between 1 and 4200 Plan hash value: 1405654398 ------------------------------------------------------------------------------------------------------------ | Id | Operation | Name | Starts | E-Rows | A-Rows | A-Time | Buffers | ------------------------------------------------------------------------------------------------------------ | 0 | SELECT STATEMENT | | 1 | | 4200 |00:00:00.01 | 2771 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE | 1 | 4200 | 4200 |00:00:00.01 | 2771 | |* 2 | INDEX RANGE SCAN | BOWIE_ID_I | 1 | 4200 | 4200 |00:00:00.01 | 11 | ------------------------------------------------------------------------------------------------------------ Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID">=1 AND "ID"<=4200) Note ----- - automatic DOP: Computed Degree of Parallelism is 1 because of no expensive parallel operation Statistics ----------------------------------------------------------- 2 CPU used by this session 2 CPU used when call started 2 DB time 14103 RM usage 3 Requests to/from client 2 SQL*Net roundtrips to/from client 2762 buffer is not pinned count 7005 buffer is pinned count 324 bytes received via SQL*Net from client 461947 bytes sent via SQL*Net to client 2 calls to get snapshot scn: kcmgss 2 calls to kcmgcs 2771 consistent gets 1 consistent gets examination 1 consistent gets examination (fastpath) 2771 consistent gets from cache 2770 consistent gets pin 2770 consistent gets pin (fastpath) 2 execute count 1 index range scans 22700032 logical read bytes from cache 2770 no work - consistent read gets 72 non-idle wait count 2 opened cursors cumulative 1 opened cursors current 2 parse count (total) 1 process last non-idle time 2 session cursor cache count 2771 session logical reads 1 sorts (memory) 2024 sorts (rows) 4200 table fetch by rowid 1366 table fetch continued row 3 user calls
We again notice consistent gets has increased significantly to 2771 (previously it was just 68). Again, these additional consistent gets can not be attributed to the extra size of the table and the additional approximate 2 x 1366 table fetch continued row gets.
If we now look at the cost of this plan:
SQL> SELECT * FROM TABLE(DBMS_XPLAN.display_cursor(sql_id=>'c376kdhy5b0x9',format=>'ALLSTATS LAST +cost +bytes')); PLAN_TABLE_OUTPUT ________________________________________________________________________________________________________________________ ____________ SQL_ID c376kdhy5b0x9, child number 0 ------------------------------------- select * from bowie where id between 1 and 4200 Plan hash value: 1405654398 --------------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows | A-Time | Buffers | --------------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | | 80 (100)| 4200 |00:00:00.01 | 2771 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE | 1 | 4200 | 684K| 80 (0)| 4200 |00:00:00.01 | 2771 | |* 2 | INDEX RANGE SCAN | BOWIE_ID_I | 1 | 4200 | | 11 (0)| 4200 |00:00:00.01 | 11 | --------------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID">=1 AND "ID"<=4200)
We again notice the CBO cost for this plan remains unchanged at 80, again totally expected as the underlying index statistics have remain unchanged after the update statement.
But again, not necessary as accurate a cost as it was previously…
If we repeat this demo, but this time on a table with ENABLE ROW MOVEMENT enabled:
SQL> create table bowie2(id number, code1 number, code2 number, code3 number, code4 number, code5 number, code6 number, code7 number, code8 number, code9 number, code10 number, code11 number, code12 number, code13 number, code14 number, code15 number, code16 number, code17 number, code18 number, code19 number, code20 number, name varchar2(142)) PCTFREE 0 ENABLE ROW MOVEMENT; Table BOWIE2 created. SQL> insert into bowie2 SELECT rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, rownum, 'BOWIE' FROM dual CONNECT BY LEVEL <= 200000; 200,000 rows inserted. SQL> commit; Commit complete. SQL> exec dbms_stats.gather_table_stats(ownname=>null, tabname=>'BOWIE2', estimate_percent=> null, no_invalidate=>false); PL/SQL procedure successfully completed. SQL> create index bowie2_id_i on bowie2(id); Index BOWIE2_ID_I created. SQL> select table_name, num_rows, blocks from user_tables where table_name='BOWIE2'; TABLE_NAME NUM_ROWS BLOCKS _____________ ___________ _________ BOWIE2 200000 3268 SQL> select index_name, blevel, leaf_blocks, clustering_factor from user_indexes where table_name='BOWIE2'; INDEX_NAME BLEVEL LEAF_BLOCKS CLUSTERING_FACTOR __________________ _________ ______________ ____________________ BOWIE2_ID_I 1 473 3250
The table and index statistics are currently identical to the previous demo.
If we run the same two equivalent queries:
SQL> select * from bowie2 where id between 1 and 1000; 1,000 rows selected. PLAN_TABLE_OUTPUT ________________________________________________________________________________________________________________ SQL_ID gtkw2704bxj7q, child number 0 ------------------------------------- select * from bowie2 where id between 1 and 1000 Plan hash value: 3243780227 ------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows | A-Rows | A-Time | Buffers | ------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | 1000 |00:00:00.01 | 18 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE2 | 1 | 1000 | 1000 |00:00:00.01 | 18 | |* 2 | INDEX RANGE SCAN | BOWIE2_ID_I | 1 | 1000 | 1000 |00:00:00.01 | 4 | ------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID">=1 AND "ID"<=1000) Note ----- - automatic DOP: Computed Degree of Parallelism is 1 because of no expensive parallel operation Statistics ----------------------------------------------------------- 1 CPU used by this session 1 CPU used when call started 7909 RM usage 3 Requests to/from client 2 SQL*Net roundtrips to/from client 16 buffer is not pinned count 1985 buffer is pinned count 325 bytes received via SQL*Net from client 171306 bytes sent via SQL*Net to client 2 calls to get snapshot scn: kcmgss 2 calls to kcmgcs 18 consistent gets 1 consistent gets examination 1 consistent gets examination (fastpath) 18 consistent gets from cache 17 consistent gets pin 17 consistent gets pin (fastpath) 2 execute count 1 index range scans 147456 logical read bytes from cache 17 no work - consistent read gets 37 non-idle wait count 2 opened cursors cumulative 1 opened cursors current 2 parse count (total) 1 process last non-idle time 2 session cursor cache count 18 session logical reads 1 sorts (memory) 2024 sorts (rows) 1000 table fetch by rowid 3 user calls SQL> SELECT * FROM TABLE(DBMS_XPLAN.display_cursor(sql_id=>'gtkw2704bxj7q',format=>'ALLSTATS LAST +cost +bytes')); PLAN_TABLE_OUTPUT _____________________________________________________________________________________________________________________________________ SQL_ID gtkw2704bxj7q, child number 0 ------------------------------------- select * from bowie2 where id between 1 and 1000 Plan hash value: 3243780227 ---------------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows | A-Time | Buffers | ---------------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | | 21 (100)| 1000 |00:00:00.01 | 18 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE2 | 1 | 1000 | 108K| 21 (0)| 1000 |00:00:00.01 | 18 | |* 2 | INDEX RANGE SCAN | BOWIE2_ID_I | 1 | 1000 | | 4 (0)| 1000 |00:00:00.01 | 4 | ---------------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID">=1 AND "ID"<=1000) SQL> select * from bowie2 where id between 1 and 4200; 4,200 rows selected. PLAN_TABLE_OUTPUT ________________________________________________________________________________________________________________ SQL_ID 25qktyn35b662, child number 0 ------------------------------------- select * from bowie2 where id between 1 and 4200 Plan hash value: 3243780227 ------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows | A-Rows | A-Time | Buffers | ------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | 4200 |00:00:00.01 | 68 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE2 | 1 | 4200 | 4200 |00:00:00.01 | 68 | |* 2 | INDEX RANGE SCAN | BOWIE2_ID_I | 1 | 4200 | 4200 |00:00:00.01 | 11 | ------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID">=1 AND "ID"<=4200) Note ----- - automatic DOP: Computed Degree of Parallelism is 1 because of no expensive parallel operation Statistics ----------------------------------------------------------- 1 CPU used by this session 1 CPU used when call started 2 DB time 13157 RM usage 3 Requests to/from client 2 SQL*Net roundtrips to/from client 59 buffer is not pinned count 8342 buffer is pinned count 325 bytes received via SQL*Net from client 461838 bytes sent via SQL*Net to client 2 calls to get snapshot scn: kcmgss 2 calls to kcmgcs 68 consistent gets 1 consistent gets examination 1 consistent gets examination (fastpath) 68 consistent gets from cache 67 consistent gets pin 67 consistent gets pin (fastpath) 2 execute count 1 index range scans 557056 logical read bytes from cache 67 no work - consistent read gets 73 non-idle wait count 2 opened cursors cumulative 1 opened cursors current 2 parse count (total) 1 process last non-idle time 2 session cursor cache count 68 session logical reads 1 sorts (memory) 2024 sorts (rows) 4200 table fetch by rowid 3 user calls SQL> SELECT * FROM TABLE(DBMS_XPLAN.display_cursor(sql_id=>'25qktyn35b662',format=>'ALLSTATS LAST +cost +bytes')); PLAN_TABLE_OUTPUT _____________________________________________________________________________________________________________________________________ SQL_ID 25qktyn35b662, child number 0 ------------------------------------- select * from bowie2 where id between 1 and 4200 Plan hash value: 3243780227 ---------------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows | A-Time | Buffers | ---------------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | | 80 (100)| 4200 |00:00:00.01 | 68 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE2 | 1 | 4200 | 455K| 80 (0)| 4200 |00:00:00.01 | 68 | |* 2 | INDEX RANGE SCAN | BOWIE2_ID_I | 1 | 4200 | | 11 (0)| 4200 |00:00:00.01 | 11 | ---------------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID">=1 AND "ID"<=4200)
With identical table/index statistics, we notice as expected that both SQLs have the same consistent gets and CBO costs as with the previous demo.
If we now repeat the equivalent Update statement:
SQL> update bowie2 set name='THE RISE AND FALL OF BOWIE STARDUST AND THE SPIDERS FROM MARS'; 200,000 rows updated. SQL> commit; Commit complete. SQL> exec dbms_stats.gather_table_stats(ownname=>null, tabname=>'BOWIE2', estimate_percent=> null, no_invalidate=>false); PL/SQL procedure successfully completed.
If we look at the table statistics:
SQL> select table_name, num_rows, blocks from user_tables where table_name='BOWIE2'; TABLE_NAME NUM_ROWS BLOCKS _____________ ___________ _________ BOWIE2 200000 4654
We notice the number of table blocks has increased to 4654 due to the increased row lengths, but not as much as with the previous demo (where table blocks increased to 4906) as in this scenario, Oracle does not have to store the row location pointers in the original blocks for the migrated rows.
If we look at the index statistics:
SQL> select index_name, blevel, leaf_blocks, clustering_factor from user_indexes where table_name='BOWIE2'; INDEX_NAME BLEVEL LEAF_BLOCKS CLUSTERING_FACTOR ______________ _________ ______________ ____________________ BOWIE2_ID_I 2 945 109061
We notice that these are substantially different from the first demo, where ROWIDs for migrated rows are not updated on the fly.
By now updating the ROWIDs, the indexes can possibly increase in size as they have to store both the previous and new ROWIDs in separate index entries and hence Oracle is more likely to perform additional index block splits (as I discussed in my previous post).
The LEAF_BLOCKS are now 945 (previously 473) and even the BLEVEL has increased from 1 to 2.
Additionally, and perhaps importantly for specific key indexes, the Clustering Factor value of indexes can also be impacted. By migrating rows and physically storing them in different locations, this can potentially detrimentally impact the tight clustering of rows based on specific column values.
The Clustering Factor for the index on the monotonically increased ID column has now increased significantly to 109061, up from the previously perfect 3250.
So columns that have naturally good clustering (e.g.: monotonically increasing values such as IDs and dates) or have been manually well clustered for performance purposes, can have the Clustering Factor of associated indexes detrimentally impacted by migrated rows.
If we re-run the first query:
SQL> select * from bowie2 where id between 1 and 1000; 1,000 rows selected. PLAN_TABLE_OUTPUT ________________________________________________________________________________________________________________ SQL_ID gtkw2704bxj7q, child number 0 ------------------------------------- select * from bowie2 where id between 1 and 1000 Plan hash value: 3243780227 ------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows | A-Rows | A-Time | Buffers | ------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | 1000 |00:00:00.01 | 639 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE2 | 1 | 1000 | 1000 |00:00:00.01 | 639 | |* 2 | INDEX RANGE SCAN | BOWIE2_ID_I | 1 | 1000 | 1000 |00:00:00.01 | 7 | ------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID">=1 AND "ID"<=1000) Note ----- - automatic DOP: Computed Degree of Parallelism is 1 because of no expensive parallel operation Statistics ----------------------------------------------------------- 1 CPU used by this session 1 CPU used when call started 1 DB time 15262 RM usage 3 Requests to/from client 2 SQL*Net roundtrips to/from client 634 buffer is not pinned count 1367 buffer is pinned count 325 bytes received via SQL*Net from client 171421 bytes sent via SQL*Net to client 2 calls to get snapshot scn: kcmgss 2 calls to kcmgcs 639 consistent gets 2 consistent gets examination 2 consistent gets examination (fastpath) 639 consistent gets from cache 637 consistent gets pin 637 consistent gets pin (fastpath) 2 execute count 1 index range scans 5234688 logical read bytes from cache 637 no work - consistent read gets 38 non-idle wait count 1 non-idle wait time 2 opened cursors cumulative 1 opened cursors current 2 parse count (total) 1 process last non-idle time 2 session cursor cache count 639 session logical reads 1 sorts (memory) 2024 sorts (rows) 1000 table fetch by rowid 3 user calls
I discussed in a previous post how by updating the ROWIDs of migrated rows we can improve performance, as Oracle can go directly to the correct new physical location of a migrated row.
But for some specific indexes, where data clustering is crucial, and we have a significant number migrated rows, this might not necessarily be the case.
We can see consistent gets here has increased to 639 (previously is was just 21), and so not hugely different from the 666 consistent gets required to fetch the migrated rows when the ROWIDs were not updated in the first demo.
If we look at the CBO costings:
SQL> SELECT * FROM TABLE(DBMS_XPLAN.display_cursor(sql_id=>'gtkw2704bxj7q',format=>'ALLSTATS LAST +cost +bytes')); PLAN_TABLE_OUTPUT _____________________________________________________________________________________________________________________________________ SQL_ID gtkw2704bxj7q, child number 0 ------------------------------------- select * from bowie2 where id between 1 and 1000 Plan hash value: 3243780227 ---------------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows | A-Time | Buffers | ---------------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | | 553 (100)| 1000 |00:00:00.01 | 639 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE2 | 1 | 1000 | 163K| 553 (0)| 1000 |00:00:00.01 | 639 | |* 2 | INDEX RANGE SCAN | BOWIE2_ID_I | 1 | 1000 | | 7 (0)| 1000 |00:00:00.01 | 7 | ---------------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID">=1 AND "ID"<=1000)
We can see the CBO cost has increased significantly to 553 (previously it was just 21).
With a much increased Clustering Factor, this will obviously impact the CBO costs of associated index scans.
In very extreme cases, these possible changes in the Clustering Factor can even impact the viability of using the index.
If we re-run the second query returning the 4200 rows:
SQL> select * from bowie2 where id between 1 and 4200; 4,200 rows selected. PLAN_TABLE_OUTPUT _____________________________________________________________________________________________________ SQL_ID 25qktyn35b662, child number 0 ------------------------------------- select * from bowie2 where id between 1 and 4200 Plan hash value: 1495904576 ---------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows | A-Rows | A-Time | Buffers | ---------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | 4200 |00:00:00.02 | 4572 | |* 1 | TABLE ACCESS STORAGE FULL | BOWIE2 | 1 | 4200 | 4200 |00:00:00.02 | 4572 | ---------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - storage(("ID"<=4200 AND "ID">=1)) filter(("ID"<=4200 AND "ID">=1))
We can see that the CBO has now chosen to perform a Full Table Scan (FTS), rather than use the now less efficient index to return this number of rows.
If we look at the CBO costings of this FTS plan:
SQL> SELECT * FROM TABLE(DBMS_XPLAN.display_cursor(sql_id=>'25qktyn35b662',format=>'ALLSTATS LAST +cost +bytes')); PLAN_TABLE_OUTPUT ______________________________________________________________________________________________________________________ SQL_ID 25qktyn35b662, child number 0 ------------------------------------- select * from bowie2 where id between 1 and 4200 Plan hash value: 1495904576 ------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows | A-Time | Buffers | ------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | | 1264 (100)| 4200 |00:00:00.02 | 4572 | |* 1 | TABLE ACCESS STORAGE FULL | BOWIE2 | 1 | 4200 | 684K| 1264 (1)| 4200 |00:00:00.02 | 4572 | ------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - storage(("ID"<=4200 AND "ID">=1)) filter(("ID"<=4200 AND "ID">=1))
The cost of the FTS plan is 1264.
If we compare this is a plan that used the index:
SQL> select /*+ index (bowie2) */ * from bowie2 where id between 1 and 4200; 4,200 rows selected. PLAN_TABLE_OUTPUT ________________________________________________________________________________________________________________ SQL_ID bzm2vhchqpq7w, child number 0 ------------------------------------- select /*+ index (bowie2) */ * from bowie2 where id between 1 and 4200 Plan hash value: 3243780227 ------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows | A-Rows | A-Time | Buffers | ------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | 4200 |00:00:00.01 | 2665 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE2 | 1 | 4200 | 4200 |00:00:00.01 | 2665 | |* 2 | INDEX RANGE SCAN | BOWIE2_ID_I | 1 | 4200 | 4200 |00:00:00.01 | 21 | ------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID">=1 AND "ID"<=4200) Note ----- - automatic DOP: Computed Degree of Parallelism is 1 because of no expensive parallel operation Statistics ----------------------------------------------------------- 2 CPU used by this session 2 CPU used when call started 2 DB time 14531 RM usage 3 Requests to/from client 2 SQL*Net roundtrips to/from client 2646 buffer is not pinned count 5755 buffer is pinned count 348 bytes received via SQL*Net from client 462143 bytes sent via SQL*Net to client 2 calls to get snapshot scn: kcmgss 2 calls to kcmgcs 2665 consistent gets 2 consistent gets examination 2 consistent gets examination (fastpath) 2665 consistent gets from cache 2663 consistent gets pin 2663 consistent gets pin (fastpath) 2 execute count 1 index range scans 21831680 logical read bytes from cache 2663 no work - consistent read gets 73 non-idle wait count 2 opened cursors cumulative 1 opened cursors current 2 parse count (total) 3 process last non-idle time 2 session cursor cache count 2665 session logical reads 1 sorts (memory) 2024 sorts (rows) 4200 table fetch by rowid 3 user calls SQL> SELECT * FROM TABLE(DBMS_XPLAN.display_cursor(sql_id=>'bzm2vhchqpq7w',format=>'ALLSTATS LAST +cost +bytes')); PLAN_TABLE_OUTPUT _____________________________________________________________________________________________________________________________________ SQL_ID bzm2vhchqpq7w, child number 0 ------------------------------------- select /*+ index (bowie2) */ * from bowie2 where id between 1 and 4200 Plan hash value: 3243780227 ---------------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows | A-Time | Buffers | ---------------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | | 2314 (100)| 4200 |00:00:00.01 | 2665 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE2 | 1 | 4200 | 684K| 2314 (1)| 4200 |00:00:00.01 | 2665 | |* 2 | INDEX RANGE SCAN | BOWIE2_ID_I | 1 | 4200 | | 22 (0)| 4200 |00:00:00.01 | 21 | ---------------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID">=1 AND "ID"<=4200)
The cost of using the index to retrieve the 4200 rows is 2310, more than the 1264 of the FTS.
For the vast majority of indexes, updating the ROWIDs for migrated rows will result in better performance, as such indexes will be able to directly access the correct new physical location of migrated rows, rather than having to visit the original table block and then follow the stored pointer to the new table block.
But for some very specific indexes, where data clustering is crucial, AND we have a significant number migrated rows, this might not necessarily be the case. The performance benefit might be minimal at best.
That’s more than enough for one post 🙂
In my next post, I’ll discuss how to potentially remedy these performance implications, both for tables with or without ENABLE TABLE MOVEMENT enabled…
When Does A ROWID Change? Part III (“Arriving Somewhere But Not Here”) December 13, 2022
Posted by Richard Foote in Autonomous Database, Changing ROWID, Index Internals, Local Indexes, Oracle, Oracle Blog, Oracle Cloud, Oracle General, Oracle Indexes, Oracle Indexing Internals Webinar, Partitioning, Performance Tuning, Richard's Blog, ROWID, Secondary Indexes.2 comments
In Part II of this series, I discussed how updating the Partitioned Key of a row from a Partitioned table will result in the row physically moving and the associated ROWID changing.
One of the reasons why changing the ROWID has historically has not been the default behaviour and requires the explicit setting of the ENABLE ROW MOVEMENT clause for Partitioned tables is because changing a ROWID comes at a cost. The cost being not only having to delete and re-insert the row within the table, but also delete and re-insert the associated index entry for each corresponding index on the table.
To illustrate, I’m going to create and populate another simple little Partitioned Table:
SQL> CREATE TABLE big_bowie2(id number, code1 number, code2 number, code3 number, code4 number, code5 number, code6 number, code7 number, code8 number, code9 number, code10 number, release_date date, name varchar2(42)) PARTITION BY RANGE (release_date) (PARTITION ALBUMS_2021 VALUES LESS THAN (TO_DATE('01-JAN-2022', 'DD-MON-YYYY')), PARTITION ALBUMS_2022 VALUES LESS THAN (MAXVALUE)) ENABLE ROW MOVEMENT; Table created. SQL> INSERT INTO big_bowie2 SELECT rownum, mod(rownum,1000), mod(rownum,1000), mod(rownum,1000), mod(rownum,100 ownum,1000), mod(rownum,1000), mod(rownum,1000), mod(rownum,1000), mod(rownum,1000), mod(rownum,1000), sysdate- m,500), 'DAVID BOWIE' FROM dual CONNECT BY LEVEL <= 10000; 10000 rows created. SQL> commit; Commit complete. SQL> exec dbms_stats.gather_table_stats(ownname=> null, tabname=> 'BIG_BOWIE2'); PL/SQL procedure successfully completed.
I’m now going to create a number of basic Global indexes on this table:
SQL> create index big_bowie2_id_i on big_bowie2(id); Index created. SQL> create index big_bowie2_code1_i on big_bowie2(code1); Index created. SQL> create index big_bowie2_code2_i on big_bowie2(code2); Index created. SQL> create index big_bowie2_code3_i on big_bowie2(code3); Index created. SQL> create index big_bowie2_code4_i on big_bowie2(code4); Index created. SQL> create index big_bowie2_code5_i on big_bowie2(code5); Index created. SQL> create index big_bowie2_code6_i on big_bowie2(code6); Index created. SQL> create index big_bowie2_code7_i on big_bowie2(code7); Index created. SQL> create index big_bowie2_code8_i on big_bowie2(code8); Index created. SQL> create index big_bowie2_code9_i on big_bowie2(code9); Index created. SQL> create index big_bowie2_code10_i on big_bowie2(code10); Index created.
If I run a simple single row UPDATE that updates a non-indexed, non-partitioned key column:
SQL> update big_bowie2 set name='ZIGGY STARDUST' where id=424; 1 row updated. Execution Plan ---------------------------------------------------------- Plan hash value: 3590621923 ------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | ------------------------------------------------------------------------------------- | 0 | UPDATE STATEMENT | | 1 | 16 | 2 (0) | 00:00:01 | | 1 | UPDATE | BIG_BOWIE2 | | | | | |* 2 | INDEX RANGE SCAN | BIG_BOWIE2_ID_I | 1 | 16 | 1 (0) | 00:00:01 | ------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID"=424) Statistics ---------------------------------------------------------- 1 recursive calls 1 db block gets 2 consistent gets 0 physical reads 328 redo size 204 bytes sent via SQL*Net to client 41 bytes received via SQL*Net from client 1 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 1 rows processed
We can see that the number of db block gets is just 1 and consistent gets just 2, as only the one table block needs to be updated and easily accessed via the index on the ID column.
If we now run a single row update of an indexed column:
SQL> update big_bowie2 set code1=42 where id = 424; 1 row updated. Execution Plan ---------------------------------------------------------- Plan hash value: 3590621923 ------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | ------------------------------------------------------------------------------------- | 0 | UPDATE STATEMENT | | 1 | 8 | 2 (0) | 00:00:01 | | 1 | UPDATE | BIG_BOWIE2 | | | | | |* 2 | INDEX RANGE SCAN | BIG_BOWIE2_ID_I | 1 | 8 | 1 (0) | 00:00:01 | ------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID"=424) Statistics ---------------------------------------------------------- 1 recursive calls 5 db block gets 2 consistent gets 1 physical reads 948 redo size 204 bytes sent via SQL*Net to client 41 bytes received via SQL*Net from client 1 SQL*Net roundtrips to/from client 1 sorts (memory) 0 sorts (disk) 1 rows processed
We can see that the number of db block gets increases to 5, as not only does the table block have to be updated but so also do the associated index blocks.
If we now finally run a single row update on the partitioned table’s partition key column that results in the row having to physically move to another partition:
SQL> update big_bowie2 set release_date='06-DEC-22' where id = 424; 1 row updated. Execution Plan ---------------------------------------------------------- Plan hash value: 3590621923 ------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | ------------------------------------------------------------------------------------- | 0 | UPDATE STATEMENT | | 1 | 64 | 2 (0) | 00:00:01 | | 1 | UPDATE | BIG_BOWIE2 | | | | | |* 2 | INDEX RANGE SCAN | BIG_BOWIE2_ID_I | 1 | 64 | 1 (0) | 00:00:01 | ------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("ID"=424) Statistics ---------------------------------------------------------- 1 recursive calls 49 db block gets 3 consistent gets 0 physical reads 5996 redo size 204 bytes sent via SQL*Net to client 41 bytes received via SQL*Net from client 1 SQL*Net roundtrips to/from client 11 sorts (memory) 0 sorts (disk) 1 rows processed
We see that the number of db block gets jumps significantly to 49, as all the corresponding indexes require their associated index entries to be likewise deleted/re-inserted in order to change all their ROWIDs.
So this additional cost of updating the indexes has been a cost that Oracle has traditionally attempted to avoid, by generally not changing the ROWID when performing an update of a row.
Of course, the update of a Partitioned Key column is not the only manner in which ROWIDs have previously easily changed as we’ll see in Part IV…
UPDATE: As my buddie Martin Widlake makes in this comment. it’s also well worth mentioning the increase in associated redo (as redo is an excellent measurement of “work” the Oracle Database has to perform), if Oracle has to change the ROWID of a row and make the necessary changes to all its corresponding indexes. In the example above, the redo increases significantly from 328 bytes to 5996 bytes, when Oracle has to move the row to another partition and so update the ROWID on the 11 indexes. More on all this when I discuss the changes implemented with the current Autonomous Databases…
Automatic Indexes: Automatically Rebuild Unusable Indexes Part IV (“Nothing Has Changed”) May 31, 2022
Posted by Richard Foote in 19c, 19c New Features, 21c New Features, Automatic Indexing, Autonomous Database, Autonomous Transaction Processing, CBO, Exadata, Full Table Scans, Index Column Order, Index Internals, Local Indexes, Mixing Auto and Manual Indexes, Oracle, Oracle 21c, Oracle Blog, Oracle Cloud, Oracle Cost Based Optimizer, Oracle General, Oracle Indexes, Oracle Indexing Internals Webinar, Oracle19c, Unusable Indexes.1 comment so far
In a previous post, I discussed how Automatic Indexing (AI) does not automatically rebuild a manually built index that is in an Unusable state (but will rebuild an Unusable automatically created index).
The demo I used was a simple one, based on manually created indexes referencing a non-partitioned table.
In this post, I’m going to use a demo based on manually created indexes referencing a partitioned table.
I’ll start by creating a rather basic range-based partitioned table, using the RELEASE_DATE column to partition the data by year:
SQL> CREATE TABLE big_bowie (id number, album_id number, country_id number, release_date date, total_sales number) PARTITION BY RANGE (release_date) (PARTITION ALBUMS_2014 VALUES LESS THAN (TO_DATE('01-JAN-2015', 'DD-MON-YYYY')), PARTITION ALBUMS_2015 VALUES LESS THAN (TO_DATE('01-JAN-2016', 'DD-MON-YYYY')), PARTITION ALBUMS_2016 VALUES LESS THAN (TO_DATE('01-JAN-2017', 'DD-MON-YYYY')), PARTITION ALBUMS_2017 VALUES LESS THAN (TO_DATE('01-JAN-2018', 'DD-MON-YYYY')), PARTITION ALBUMS_2018 VALUES LESS THAN (TO_DATE('01-JAN-2019', 'DD-MON-YYYY')), PARTITION ALBUMS_2019 VALUES LESS THAN (TO_DATE('01-JAN-2020', 'DD-MON-YYYY')), PARTITION ALBUMS_2020 VALUES LESS THAN (TO_DATE('01-JAN-2021', 'DD-MON-YYYY')), PARTITION ALBUMS_2021 VALUES LESS THAN (MAXVALUE)); Table created. SQL> INSERT INTO big_bowie SELECT rownum, mod(rownum,5000)+1, mod(rownum,100)+1, sysdate-mod(rownum,2800), ceil(dbms_random.value(1,500000)) FROM dual CONNECT BY LEVEL <= 10000000; 10000000 rows created. SQL> commit; Commit complete. SQL> exec dbms_stats.gather_table_stats(ownname=> null, tabname=> 'BIG_BOWIE'); PL/SQL procedure successfully completed.
I’ll next manually create a couple indexes; a non-partitioned index based on just the ALBUM_ID column and a prefixed locally partitioned index, based on the columns RELEASE_DATE, TOTAL_SALES:
SQL> create index album_id_i on big_bowie(album_id); Index created. SQL> create index release_date_total_sales_i on big_bowie(release_date, total_sales) local; Index created.
If we now re-organise just partition ALBUMS_2017 (without using the ONLINE clause):
SQL> alter table big_bowie move partition albums_2017; Table altered.
This results in the non-partitioned index and the ALBUMS_2017 local index partition becoming Unusable:
SQL> select index_name, status from user_indexes where table_name='BIG_BOWIE'; INDEX_NAME STATUS ------------------------------ -------- ALBUM_ID_I UNUSABLE RELEASE_DATE_TOTAL_SALES_I N/A SQL> select index_name, partition_name, status from user_ind_partitions where index_name='RELEASE_DATE_TOTAL_SALES_I'; INDEX_NAME PARTITION_NAME STATUS ------------------------------ -------------------- -------- RELEASE_DATE_TOTAL_SALES_I ALBUMS_2014 USABLE RELEASE_DATE_TOTAL_SALES_I ALBUMS_2015 USABLE RELEASE_DATE_TOTAL_SALES_I ALBUMS_2016 USABLE RELEASE_DATE_TOTAL_SALES_I ALBUMS_2017 UNUSABLE RELEASE_DATE_TOTAL_SALES_I ALBUMS_2018 USABLE RELEASE_DATE_TOTAL_SALES_I ALBUMS_2019 USABLE RELEASE_DATE_TOTAL_SALES_I ALBUMS_2020 USABLE RELEASE_DATE_TOTAL_SALES_I ALBUMS_2021 USABLE
Let’s now run a number of queries a number of times. The first series is based on a predicate on just the ALBUM_ID column, such as:
SQL> select * from big_bowie where album_id=42; 2000 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 1510748290 ------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | Pstart| Pstop | ------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 2000 | 52000 | 7959 (2) | 00:00:01 | | | | 1 | PARTITION RANGE ALL | | 2000 | 52000 | 7959 (2) | 00:00:01 | 1 | 8 | | * 2 | TABLE ACCESS FULL | BIG_BOWIE | 2000 | 52000 | 7959 (2) | 00:00:01 | 1 | 8 | ------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - storage("ALBUM_ID"=42) - filter("ALBUM_ID"=42) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 48593 consistent gets 42881 physical reads 0 redo size 44289 bytes sent via SQL*Net to client 52 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 2000 rows processed
We’ll also run a series of queries based on both the RELEASE_DATE column using dates from the unusable index partition and the TOTAL_SALES column, such as:
SQL> select * from big_bowie where release_date='01-JUN-2017' and total_sales=42; no rows selected Execution Plan ---------------------------------------------------------- Plan hash value: 3245457041 ---------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | Pstart| Pstop | ---------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 26 | 986 (2) | 00:00:01 | | | | 1 | PARTITION RANGE SINGLE | | 1 | 26 | 986 (2) | 00:00:01 | 4 | 4 | | * 2 | TABLE ACCESS FULL | BIG_BOWIE | 1 | 26 | 986 (2) | 00:00:01 | 4 | 4 | ---------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - storage("TOTAL_SALES"=42 AND "RELEASE_DATE"=TO_DATE(' 2017-06-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) - filter("TOTAL_SALES"=42 AND "RELEASE_DATE"=TO_DATE(' 2017-06-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 5573 consistent gets 0 physical reads 0 redo size 676 bytes sent via SQL*Net to client 41 bytes received via SQL*Net from client 1 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 0 rows processed
Without a valid/usable index, the CBO currently has no choice but to use a Full Table Scan on the first query, and a Full Partition Scan on the partition with the unusable local index.
So what does AI make of things? Does it rebuild the unusable manually created indexes so the associated indexes can be used to improve these queries?
If we wait until the next AI task completes and check out the indexes on the table:
SQL> select index_name, status, partitioned from user_indexes where table_name='BIG_BOWIE'; INDEX_NAME STATUS PAR ------------------------------ -------- --- RELEASE_DATE_TOTAL_SALES_I N/A YES ALBUM_ID_I UNUSABLE NO SYS_AI_aw2825ffpus5s VALID NO SYS_AI_2hf33fpvnqztw VALID NO SQL> select index_name, partition_name, status from user_ind_partitions where index_name='RELEASE_DATE_TOTAL_SALES_I'; INDEX_NAME PARTITION_NAME STATUS ------------------------------ -------------------- -------- RELEASE_DATE_TOTAL_SALES_I ALBUMS_2014 USABLE RELEASE_DATE_TOTAL_SALES_I ALBUMS_2015 USABLE RELEASE_DATE_TOTAL_SALES_I ALBUMS_2016 USABLE RELEASE_DATE_TOTAL_SALES_I ALBUMS_2017 UNUSABLE RELEASE_DATE_TOTAL_SALES_I ALBUMS_2018 USABLE RELEASE_DATE_TOTAL_SALES_I ALBUMS_2019 USABLE RELEASE_DATE_TOTAL_SALES_I ALBUMS_2020 USABLE RELEASE_DATE_TOTAL_SALES_I ALBUMS_2021 USABLE
We notice that AI has created two new non-partitioned automatic indexes, while both the manually created indexes remain in the same unusable state. If we look at the columns associated with these new automatic indexes:
SQL> select index_name, column_name, column_position from user_ind_columns where table_name='BIG_BOWIE'; INDEX_NAME COLUMN_NAME COLUMN_POSITION ------------------------------ -------------------- --------------- ALBUM_ID_I ALBUM_ID 1 RELEASE_DATE_TOTAL_SALES_I RELEASE_DATE 1 RELEASE_DATE_TOTAL_SALES_I TOTAL_SALES 2 SYS_AI_aw2825ffpus5s ALBUM_ID 1 SYS_AI_aw2825ffpus5s RELEASE_DATE 2 SYS_AI_2hf33fpvnqztw TOTAL_SALES 1 SYS_AI_2hf33fpvnqztw RELEASE_DATE 2
As we can see, AI has logically replaced both unusable indexes.
The manual index based on ALBUM_ID has been replaced with an inferior index based on the ALBUM_ID, RELEASE_DATE columns. Inferior in that the automatic index is both redundant (if only the manual index on ALBUM_ID were rebuilt) and in that it has the logically unnecessary RELEASE_DATE column to inflate the size of the index.
The manual index based on the RELEASE_DATE, TOTAL_SALES columns has been replaced with a redundant automatic index based on the reversed TOTAL_SALES, RELEASE_DATE columns.
Now, AI has indeed automatically addressed the current FTS performance issues associated with these queries by creating these indexes, but a better remedy would have been to rebuild the unusable manual indexes and hence negate the need for these redundant automatic indexes.
But currently (including with version 21.3), AI will NOT rebuild unusable manually created indexes, no matter the scenario, and will instead create additional automatic indexes if it’s viable for it to do so.
A reason why Oracle at times recommends dropping all current manually created secondary indexes before implementing AI (although of course this comes with a range of obvious issues and concerns).
If these manually created indexes didn’t exist, I’ll leave it as an exercise to the discernable reader on what automatic indexes would have been created…
As always, this restriction may change in future releases…
Announcement: Registration Links For Upcoming Webinars Now Open (“Join The Gang”) May 25, 2022
Posted by Richard Foote in 18c New Features, 19c New Features, 21c New Features, Index Internals, Index Internals Seminar, Indexing Tricks, Oracle 21c, Oracle General, Oracle Index Seminar, Oracle Indexing Internals Webinar, Oracle Performance Diagnostics and Tuning Seminar, Oracle Performance Diagnostics and Tuning Webinar, Oracle19c, Performance Tuning, Performance Tuning Seminar, Performance Tuning Webinar, Richard Foote Consulting, Richard Foote Seminars, Richard Foote Training, Richard Presentations.add a comment
The registration links for my upcoming webinars running in August are now open!!!
The price of each webinar is $1,600 AUD. There is a special price of $2,750 AUD if you wish to attend both webinars (just use the Special Combo Price button).
(Note: Do NOT use the links if you’re an Australian resident. Please contact me at richard@richardfooteconsulting.com for additional payment info and tax invoice that includes additional GST).
Just click the below “Buy Now” buttons to book your place for these unique, highly acclaimed Oracle training events (see some of my testimonials for feedback by previous attendees to these training events):
“Oracle Indexing Internals“ Webinar: 8-12 August 2022 (between 09:00 GMT and 13:00 GMT daily) – $1,600 AUD: SOLD OUT!!
“Oracle Performance Diagnostics and Tuning“ Webinar: 22-25 August 2022 (between 09:00 GMT and 13:00 GMT daily) – $1,600 AUD: SOLD OUT!!
“Special Combo Price for both August 2022 Webinars” $2,750 AUD: SOLD OUT!!
The links allow you to book a place using either PayPal or a credit card. If you wish to pay via a different method or have any questions at all regarding these events, please contact me at richard@richardfooteconsulting.com.
As I mentioned previously, for those of you on my official waiting list, I will reserve a place for you for a limited time.
As this will probably be the last time I will run these events, remaining places are likely to go quickly. So please book your place ASAP to avoid disappointment…
Read below a brief synopsis of each webinar:
“Oracle Indexing Internals“
This is a must attend webinar of benefit to not only DBAs, but also to Developers, Solution Architects and anyone else interested in designing, developing or maintaining high performance Oracle-based applications. It’s a fun, but intense, content rich webinar that is suitable for people of all experiences (from beginners to seasoned Oracle experts).
Indexes are fundamental to every Oracle database and are crucial for optimal performance. However, there’s an incredible amount of misconception, misunderstanding and pure myth regarding how Oracle indexes function and should be maintained. Many applications and databases are suboptimal and run inefficiently primarily because an inappropriate indexing strategy has been implemented.
This webinar examines most available Oracle index structures/options and discusses in considerable detail how indexes function, how/when they should be used and how they should be maintained. A key component of the webinar is how indexes are costed and evaluated by the Cost Based Optimizer (CBO) and how appropriate data management practices are vital for an effective indexing strategy. It also covers many useful tips and strategies to maximise the benefits of indexes on application/database performance and scalability, as well as in maximising Oracle database investments. Much of the material is exclusive to this webinar and is not generally available in Oracle documentation or in Oracle University courses.
For full details, see: https://richardfooteconsulting.com/indexing-seminar/
“Oracle Performance Diagnostics and Tuning“
This is a must attend webinar aimed at Oracle professionals (both DBAs and Developers) who are interested in Performance Tuning. The webinar details how to maximise the performance of both Oracle databases and associated applications and how to diagnose and address any performance issues as quickly and effectively as possible.
When an application suddenly runs “slow” or when people start complaining about the “poor performance” of the database, there’s often some uncertainty in how to most quickly and most accurately determine the “root” cause of any such slowdown and effectively address any associated issues. In this seminar, we explore a Tuning Methodology that helps Oracle professionals to both quickly and reliably determine the actual causes of performance issues and so ensure the effectiveness of any applied resolutions.
Looking at a number of real world scenarios and numerous actual examples and test cases, this webinar will show participants how to confidently and reliably diagnose performance issues. The webinar explores in much detail the various diagnostics tools and reports available in Oracle to assist in determining any database performance issue and importantly WHEN and HOW to effectively use each approach. Additionally, participants are also invited to share their own database/SQL reports, where we can apply the principles learnt in diagnosing the performance of their actual databases/applications.
One of the more common reasons for poor Oracle performance is inefficient or poorly running SQL. This seminar explores in much detail how SQL is executed within the Oracle database, the various issues and related concepts important in understanding why SQL might be inefficient and the many capabilities and features Oracle has in helping to both resolve SQL performance issues and to maintain the stability and reliability of SQL execution.
It’s a fun, but intense, content rich webinar that is suitable for people of all experiences (from beginners to seasoned Oracle experts).
For full details, see: https://richardfooteconsulting.com/performance-tuning-seminar/
If you have any questions about these events, please contact me at richard@richardfooteconsulting.com
Announcement: Dates Confirmed For Upcoming Webinars (“Here Today, Gone Tomorrow”) May 19, 2022
Posted by Richard Foote in 19c, 19c New Features, 21c New Features, Index Internals, Index Internals Seminar, Indexing Myth, Oracle, Oracle 21c, Oracle General, Oracle Index Seminar, Oracle Indexes, Oracle Indexing Internals Webinar, Oracle Performance Diagnostics and Tuning Webinar, Oracle19c, Performance Tuning, Performance Tuning Webinar, Richard Foote Seminars, Webinar.add a comment
As promised last week, I have now finalised the dates for my upcoming webinars.
They will be run as follows (UPDATED):
“Oracle Indexing Internals“ Webinar: 8-12 August 2022 (between 09:00 GMT and 13:00 GMT daily): SOLD OUT!!
“Oracle Performance Diagnostics and Tuning“ Webinar: 22-25 August 2022 (between 09:00 GMT and 13:00 GMT daily): SOLD OUT!!
“Special Combo Price for both August 2022 Webinars“: SOLD OUT!!
I’ll detail costings and how to register for these events in the coming days.
There is already quite a waiting list for both of these webinars and so I anticipate available places will likely go quickly. Sorry to all those who have been waiting for so long and thank you for your patience. Please note for those on the waiting list, I already have places reserved for you.
It’s highly likely these will be the last time I’ll ever run these highly acclaimed training events (yes, I’m getting old)…
So don’t miss this unique opportunity to learn important skills in how to improve the performance and scalability of both your Oracle based applications and backend Oracle databases, in the comfort of your own home or office.
Read below a brief synopsis of each webinar:
“Oracle Indexing Internals“
This is a must attend webinar of benefit to not only DBAs, but also to Developers, Solution Architects and anyone else interested in designing, developing or maintaining high performance Oracle-based applications. It’s a fun, but intense, content rich webinar that is suitable for people of all experiences (from beginners to seasoned Oracle experts).
Indexes are fundamental to every Oracle database and are crucial for optimal performance. However, there’s an incredible amount of misconception, misunderstanding and pure myth regarding how Oracle indexes function and should be maintained. Many applications and databases are suboptimal and run inefficiently primarily because an inappropriate indexing strategy has been implemented.
This seminar examines most available Oracle index structures/options and discusses in considerable detail how indexes function, how/when they should be used and how they should be maintained. A key component of the seminar is how indexes are costed and evaluated by the Cost Based Optimizer (CBO) and how appropriate data management practices are vital for an effective indexing strategy. It also covers many useful tips and strategies to maximise the benefits of indexes on application/database performance and scalability, as well as in maximising Oracle database investments. Much of the material is exclusive to this seminar and is not generally available in Oracle documentation or in Oracle University courses.
For full details, see: https://richardfooteconsulting.com/indexing-seminar/
“Oracle Performance Diagnostics and Tuning“
This is a must attend webinar aimed at Oracle professionals (both DBAs and Developers) who are interested in Performance Tuning. The webinar details how to maximise the performance of both Oracle databases and associated applications and how to diagnose and address any performance issues as quickly and effectively as possible.
When an application suddenly runs “slow” or when people start complaining about the “poor performance” of the database, there’s often some uncertainty in how to most quickly and most accurately determine the “root” cause of any such slowdown and effectively address any associated issues. In this seminar, we explore a Tuning Methodology that helps Oracle professionals to both quickly and reliably determine the actual causes of performance issues and so ensure the effectiveness of any applied resolutions.
Looking at a number of real world scenarios and numerous actual examples and test cases, this webinar will show participants how to confidently and reliably diagnose performance issues. The webinar explores in much detail the various diagnostics tools and reports available in Oracle to assist in determining any database performance issue and importantly WHEN and HOW to effectively use each approach. Additionally, participants are also invited to share their own database/SQL reports, where we can apply the principles learnt in diagnosing the performance of their actual databases/applications.
One of the more common reasons for poor Oracle performance is inefficient or poorly running SQL. This seminar explores in much detail how SQL is executed within the Oracle database, the various issues and related concepts important in understanding why SQL might be inefficient and the many capabilities and features Oracle has in helping to both resolve SQL performance issues and to maintain the stability and reliability of SQL execution.
It’s a fun, but intense, content rich webinar that is suitable for people of all experiences (from beginners to seasoned Oracle experts).
For full details, see: https://richardfooteconsulting.com/performance-tuning-seminar/
Keep an eye out in the coming days on costings and how to register for these events.
If you have any questions about these events, please contact me at richard@richardfooteconsulting.com
Announcement: Both Of My Oracle Webinars Scheduled For February 2021 !! January 19, 2021
Posted by Richard Foote in Oracle, Oracle Cost Based Optimizer, Oracle General, Oracle Indexes, Oracle Indexing Internals Webinar, Oracle Performance Diagnostics and Tuning Webinar, Richard Foote Seminars.add a comment
I’m please to announce that both of my highly acclaimed webinars scheduled for February are now confirmed.
These webinars are a must for any Oracle DBA or Developer interested in designing, developing or maintaining high performance, highly scalable Oracle-based applications or databases.
However only a few places are currently available on each webinar with numbers very strictly limited, as I only run small classes to give every attendee the opportunity to get the most from the training experience.
Webinar details are as follows:
8-12 February 2021 (5pm-9pm AEDT) – Oracle Indexing Internals and Best Practices Webinar (International Customers Only)
This seminar examines most available Oracle index structures/options and discusses in considerable detail how indexes function, how/when they should be used and how they should be maintained. It covers many useful tips and strategies to maximise the benefits of indexes on application/database performance and scalability, as well as in maximising Oracle database investments. Much of the material is exclusive to this seminar and is not generally available in Oracle documentation or in Oracle University courses.
23-26 February 2021 (5pm-9pm AEDT) – Oracle Performance Diagnostics and Tuning Webinar
(International Customers Only)
The seminar will detail how to maximise the performance of both Oracle databases and associated applications and how to diagnose and address any performance issues as quickly and effectively as possible. It also provides opportunity to have your own AWR reports analysed to identify performance issues.
You can also purchase tickets to both webinars at a special combo discount:
Both “Oracle Indexing Internals and Best Practices” and “Oracle Performance Diagnostics and Tuning” Webinars running in February 2021: (International Customers Only)
Each webinar is $1,800 (AUS) individually and $3,000 (AUS) when both purchased in the combo package (the Buy Now functionality is available for International Customers Only).
Please Note: If based in Australia, please contact me (at richard@richardfooteconsulting.com) for a tax invoice that includes GST and instructions on how to pay.
Please contact me directly if you wish to pay via invoice and direct bank transfer or if you have any questions.
For full content details of the “Oracle Indexing Internals and Best Practices” Webinar: https://richardfooteconsulting.com/indexing-seminar/
For full content details of the “Oracle Performance Diagnostics and Tuning” Webinar: https://richardfooteconsulting.com/performance-tuning-seminar/
Hopefully you can take advantage of the opportunity to participate in this unique training experience (see here for some testimonials)…
ANNOUNCEMENT: Replacement Oracle Indexing Internals and Performance Tuning Webinars 23-26 March 2020 !! March 11, 2020
Posted by Richard Foote in Oracle Indexing Internals Webinar, Oracle Performance Diagnostics and Tuning Webinar, Webinar.add a comment
London March 2020 Seminar Dates Cancelled 😦
Unfortunately, due to the Coronavirus crisis, both seminars scheduled for London during March 2020 have been cancelled. Full refunds have been processed for all attendees.
March 2020 Webinar Replacement Dates Announced !!
However, as a quick replacement primarily for those disappointed by the cancellation of the London seminars, I will now be running webinar versions of both events as replacements during the same times the seminars were previously scheduled.
Remaining places for the webinars can be purchased by anyone until all remaining places are taken. Simple click on the Buy Now button to purchase your place for this unique training opportunity.
23-24 March 2020 (running between 9:00 – 17:00 GMT): “Oracle Indexing Internals and Best Practices” Webinar:
25-26 March 2020 (running between 9:00 – 17:00 GMT): “Oracle Performance Diagnostics and Tuning” Webinar:
You can also purchase tickets to both webinars at a special combo discount:
23-26 March 2020 (running between 9:00 – 17:00 GMT): Both “Oracle Indexing Internals and Best Practices” and “Oracle Performance Diagnostics and Tuning” Webinars:
The cost for an individual webinar is $1,800 Australian Dollars.
The cost for the webinar combo is $3,000 Australian Dollars.
For full content details of “Oracle Indexing Internals and Best Practices” Webinar: https://richardfooteconsulting.com/indexing-seminar/
For full content details of “Oracle Performance Diagnostics and Tuning” Webinar: https://richardfooteconsulting.com/performance-tuning-seminar/
Please contact me directly if you wish to pay via invoice and direct bank transfer or if you have any questions.
Although I might not currently be able to run these events in London, hopefully you’ll still have the opportunity to attend this high acclaimed training 🙂
March 2019 – New Webinar Dates Announced for “Oracle Indexing Internals and Best Practices” November 14, 2018
Posted by Richard Foote in Oracle Index Seminar, Oracle Indexes, Oracle Indexing Internals Webinar, Webinar.add a comment
I’m very excited to announce two new Webinar events for my acclaimed “Oracle Indexing Internals and Best Practices” training event, running in March 2019 !!
For details of all the extensive content covered in the webinars, please visit my Indexing Seminar page.
The webinars will run for 4 hours each day, spanning a full week period (Monday to Friday) in various timezones that are friendly to different parts of the world.
So that’s 15+ hours of extensive and practical content that will be of benefit to not only DBAs, but also to Developers, Solution Architects and anyone else interested in designing, developing or maintaining high performance Oracle-based applications.
There are currently 2 webinar series scheduled. They are:
- Webinar Series 1: 4 – 8 March 2019 (start 7pm AEDT, end 11pm AEDT)
- Webinar Series 2: 26 – 30 March 2019 (start 5am AEDT, end 9am AEDT)
Webinar Series 1 will be in timezones more agreeable to Eastern Asia/Europe. For example, they will start at 1:30pm local time in Mumbai, at 9:00am local time in Paris.
Webinar Series 2 will be in timezones more agreeable to the American Continents. For example they will start at in 1:00pm local time New York and 10:00am local time in San Francisco. (Note: The dates listed are as in Australia, they will actually run between Monday 25 November to Friday 29 March in the Americas).
The cost of each 5 x day series will be $1200.00 Australian Dollars (+GST if applicable and attending from within Australia).
Note: Numbers are strictly limited to ensure the smooth running of these events and enable the opportunity for all attendees to ask questions. One of my previous webinars was officially FULL, so please register early to avoid disappointment as webinars are not scheduled too regularly.
Booking and Payment Instructions
To book your place, please email me at richard@richardfooteconsulting.comand I will send you an invoice with payment instructions. You can pay either by credit card via PayPal (you do not need a PayPal account for this), via a PayPal account or via direct bank transfer. Note: payment must be received before you can attend the webinar.
You can also pay for these webinars directly here if NOT attending from Australia:
Webinar Series 1: 4-8 March 2019 (start 7pm AEDT, end 11pm AEDT):
Webinar Series 2: 26-30 March 2019 (start 5am AEDT, end 9am AEDT):
Once registered, you will be sent a unique link for each booking with instructions on how to attend the webinar. Prior to the webinar, you will also be sent a soft copy of the webinar materials, with 850+ pages of amazing content, that includes many useful tips and strategies to maximise the benefits of indexes on application/database performance and scalability.
Up to date details and terms and conditions can be found at my Indexing Webinar web page.
If you have any questions, please don’t hesitate to contact me.