“Hidden” Efficiencies of Non-Partitioned Indexes on Partitioned Tables Part IV” (Hallo Spaceboy) October 31, 2018
Posted by Richard Foote in Global Indexes, Local Indexes, Oracle Indexes, Partitioned Indexes.4 comments
In Part I, Part II and Part III we looked at some advantages of Global Indexes that may not be obvious to some.
One of the advantages of a Local Index vs. Non-Partitioned Global Index is that a Local Index being a smaller index structures may have a reduced BLEVEL in comparison. This can save a logical read each and every time the index is accessed.
However, if this is a performance concern for usage of a corresponding Global Index, this is a key reason why Global Indexes can likewise be partitioned.
As we saw in the demo in Part III, when the Global Index is used in a query that uses a predicate with the table partitioned key:
SQL> SELECT * FROM big_bowie WHERE total_sales = 42 and release_date between '01-JAN-2017' and '31-JUL-2017'; ID ALBUM_ID COUNTRY_ID RELEASE_D TOTAL_SALES ---------- ---------- ---------- --------- ----------- 1000041 42 42 20-JUL-17 42 Execution Plan ---------------------------------------------------------- Plan hash value: 1081241859 -------------------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | Pstart | Pstop | -------------------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 25 | 13 (0) | 00:00:01 | | | |* 1 | TABLE ACCESS BY GLOBAL INDEX ROWID BATCHED | BIG_BOWIE | 1 | 25 | 13 (0) | 00:00:01 | 7 | 7 | |* 2 | INDEX RANGE SCAN | BIG_BOWIE_TOTAL_SALES_I | 10 | | 3 (0) | 00:00:01 | | | -------------------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - filter("RELEASE_DATE"=TO_DATE('2017-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) 2 - access("TOTAL_SALES"=42) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 5 consistent gets 0 physical reads 0 redo size 885 bytes sent via SQL*Net to client 624 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 1 rows processed
The query required 5 consistent gets.
But when the Local Index is used with a reduced BLEVEL:
SQL> SELECT * FROM big_bowie WHERE total_sales = 42 and release_date between '01-JAN-2017' and '31-JUL-2017'; ID ALBUM_ID COUNTRY_ID RELEASE_D TOTAL_SALES ---------- ---------- ---------- --------- ----------- 1000041 42 42 20-JUL-17 42 Execution Plan ---------------------------------------------------------- Plan hash value: 3499166408 -------------------------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | Pstart | Pstop | -------------------------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 25 | 2 (0) | 00:00:01 | | | | 1 | PARTITION RANGE SINGLE | | 1 | 25 | 2 (0) | 00:00:01 | 7 | 7 | |* 2 | TABLE ACCESS BY LOCAL INDEX ROWID BATCHED | BIG_BOWIE | 1 | 25 | 2 (0) | 00:00:01 | 7 | 7 | |* 3 | INDEX RANGE SCAN | BIG_BOWIE_TOTAL_SALES_LOCAL_I | 1 | | 1 (0) | 00:00:01 | 7 | 7 | -------------------------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - filter("RELEASE_DATE"<=TO_DATE(' 2017-07-31 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) 3 - access("TOTAL_SALES"=42) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 4 consistent gets 0 physical reads 0 redo size 885 bytes sent via SQL*Net to client 624 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 1 rows processed
The query used just 4 consistent gets (vs. 5) as a result of the reduction of 1 for the BLEVEL.
So to have the best of both worlds, excellent performance when the query doesn’t contain the table partitioned columns in a predicate and excellent performance to match Local Indexes when the table partitioned key is specified, a Global Index can also be partitioned into many, smaller index structures.
However, unlike a Local Index, a Global Partitioned Index can be partitioned in a manner totally different to that of the table (indeed, the table doesn’t even have to be partitioned).
In this example, the Global Index on the TOTAL_SALES column is partitioned based on TOTAL_SALES (unlike the table which is partitioned based on RELEASE_DATE) and partitioned into 16 partitions (unlike the table which has 8 partitions):
SQL> CREATE INDEX big_bowie_total_sales_global_i ON big_bowie(total_sales) 2 GLOBAL PARTITION BY RANGE (total_sales) 3 (PARTITION P1 VALUES LESS THAN (12501), 4 PARTITION P2 VALUES LESS THAN (25001), 5 PARTITION P3 VALUES LESS THAN (37501), 6 PARTITION P4 VALUES LESS THAN (50001), 7 PARTITION P5 VALUES LESS THAN (62501), 8 PARTITION P6 VALUES LESS THAN (75001), 9 PARTITION P7 VALUES LESS THAN (87501), 10 PARTITION P8 VALUES LESS THAN (100001), 11 PARTITION P9 VALUES LESS THAN (112501), 12 PARTITION P10 VALUES LESS THAN (125001), 13 PARTITION P11 VALUES LESS THAN (137501), 14 PARTITION P12 VALUES LESS THAN (150001), 15 PARTITION P13 VALUES LESS THAN (162501), 16 PARTITION P14 VALUES LESS THAN (175001), 17 PARTITION P15 VALUES LESS THAN (187501), 18 PARTITION P16 VALUES LESS THAN (MAXVALUE)) invisible; Index created. SQL> select index_name, partition_name, blevel, leaf_blocks from dba_ind_partitions where index_name='BIG_BOWIE_TOTAL_SALES_GLOBAL_I'; INDEX_NAME PARTITION_NAME BLEVEL LEAF_BLOCKS ------------------------------ -------------------- ---------- ----------- BIG_BOWIE_TOTAL_SALES_GLOBAL_I P1 1 335 BIG_BOWIE_TOTAL_SALES_GLOBAL_I P10 1 349 BIG_BOWIE_TOTAL_SALES_GLOBAL_I P11 1 349 BIG_BOWIE_TOTAL_SALES_GLOBAL_I P12 1 349 BIG_BOWIE_TOTAL_SALES_GLOBAL_I P13 1 349 BIG_BOWIE_TOTAL_SALES_GLOBAL_I P14 1 349 BIG_BOWIE_TOTAL_SALES_GLOBAL_I P15 1 349 BIG_BOWIE_TOTAL_SALES_GLOBAL_I P16 1 349 BIG_BOWIE_TOTAL_SALES_GLOBAL_I P2 1 349 BIG_BOWIE_TOTAL_SALES_GLOBAL_I P3 1 349 BIG_BOWIE_TOTAL_SALES_GLOBAL_I P4 1 349 BIG_BOWIE_TOTAL_SALES_GLOBAL_I P5 1 349 BIG_BOWIE_TOTAL_SALES_GLOBAL_I P6 1 349 BIG_BOWIE_TOTAL_SALES_GLOBAL_I P7 1 349 BIG_BOWIE_TOTAL_SALES_GLOBAL_I P8 1 349 BIG_BOWIE_TOTAL_SALES_GLOBAL_I P9 1 349
We notice that each Global Index partition now only has a BLEVEL of 1, the same as the corresponding Local Index.
As such, the performance of the Global Index now matches that of the Local Index when the table partition key is referenced in an SQL predicate:
SQL> alter index BIG_BOWIE_TOTAL_SALES_LOCAL_I invisible; Index altered. SQL> alter index BIG_BOWIE_TOTAL_SALES_GLOBAL_I visible; Index altered. SQL> SELECT * FROM big_bowie WHERE total_sales = 42 and release_date between '01-JAN-2017' and '31-JUL-2017'; ID ALBUM_ID COUNTRY_ID RELEASE_D TOTAL_SALES ---------- ---------- ---------- --------- ----------- 1000041 42 42 20-JUL-17 42 Execution Plan ---------------------------------------------------------- Plan hash value: 2458305506 ---------------------------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | Pstart | Pstop | ---------------------------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 25 | 11 (0) | 00:00:01 | | | | 1 | PARTITION RANGE SINGLE | | 1 | 25 | 11 (0) | 00:00:01 | 1 | 1 | |* 2 | TABLE ACCESS BY GLOBAL INDEX ROWID BATCHED | BIG_BOWIE | 1 | 25 | 11 (0) | 00:00:01 | 7 | 7 | |* 3 | INDEX RANGE SCAN | BIG_BOWIE_TOTAL_SALES_GLOBAL_I | 1 | | 1 (0) | 00:00:01 | 1 | 1 | ---------------------------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - filter("RELEASE_DATE"=TO_DATE(' 2017-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) 3 - access("TOTAL_SALES"=42) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 4 consistent gets 0 physical reads 0 redo size 885 bytes sent via SQL*Net to client 624 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 1 rows processed
So Global Indexes can perform optimally, regardless of whether the table partition key is specified in a predicate or not.
The same can’t always be said for a corresponding Local Index.
“Hidden” Efficiencies of Non-Partitioned Indexes on Partitioned Tables Part III” (Ricochet) October 25, 2018
Posted by Richard Foote in Block Dumps, Global Indexes, Local Indexes, Oracle Indexes, Partitioned Indexes, Partitioning.1 comment so far
In Part I and Part II of this series, we looked at how Global Indexes can effectively perform “Partition Pruning” when the partition keys are specified in SQL predicates, by only using those index entries that have a Data Object of interest stored within the index Rowids.
In this piece, I’ll cover the key performance advantage that Global Indexes have over Local Indexes and why I generally recommended Global Indexes from a purely performance perspective.
First, a quick recap of how the Global Index performed. Following is the performance of a query where the table partitioned key is specified in the query:
SQL> SELECT * FROM big_bowie WHERE total_sales = 42 and release_date between '01-JAN-2017' and '31-JUL-2017'; ID ALBUM_ID COUNTRY_ID RELEASE_D TOTAL_SALES ---------- ---------- ---------- --------- ----------- 1000041 42 42 20-JUL-17 42 Execution Plan ---------------------------------------------------------- Plan hash value: 1081241859 -------------------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | Pstart | Pstop | -------------------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 25 | 13 (0) | 00:00:01 | | | |* 1 | TABLE ACCESS BY GLOBAL INDEX ROWID BATCHED | BIG_BOWIE | 1 | 25 | 13 (0) | 00:00:01 | 7 | 7 | |* 2 | INDEX RANGE SCAN | BIG_BOWIE_TOTAL_SALES_I | 10 | | 3 (0) | 00:00:01 | | | -------------------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - filter("RELEASE_DATE"=TO_DATE('2017-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) 2 - access("TOTAL_SALES"=42) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 5 consistent gets 0 physical reads 0 redo size 885 bytes sent via SQL*Net to client 624 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 1 rows processed
As discussed previously, at just 5 consistent gets, it’s very efficient as only the table blocks that reside in possible partitions of interest are only accessed.
The following query selects all TOTAL_SALES values of interest, with no partition key predicate:
SQL> SELECT * FROM big_bowie WHERE total_sales = 42; ID ALBUM_ID COUNTRY_ID RELEASE_D TOTAL_SALES ---------- ---------- ---------- --------- ----------- 400041 42 42 28-JAN-12 42 1800041 42 42 28-JAN-12 42 800041 42 42 03-MAR-13 42 1200041 42 42 07-APR-14 42 1600041 42 42 12-MAY-15 42 200041 42 42 12-MAY-15 42 600041 42 42 15-JUN-16 42 1000041 42 42 20-JUL-17 42 41 42 42 24-AUG-18 42 1400041 42 42 24-AUG-18 42 10 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 1761527485 -------------------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | Pstart | Pstop | -------------------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 10 | 250 | 13 (0) | 00:00:01 | | | | 1 | TABLE ACCESS BY GLOBAL INDEX ROWID BATCHED | BIG_BOWIE | 10 | 250 | 13 (0) | 00:00:01 | ROWID | ROWID | |* 2 | INDEX RANGE SCAN | BIG_BOWIE_TOTAL_SALES_I | 10 | | 3 (0) | 00:00:01 | | | -------------------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("TOTAL_SALES"=42) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 14 consistent gets 0 physical reads 0 redo size 1184 bytes sent via SQL*Net to client 624 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 10 rows processed
So the index is scanned (4 consistent gets) and 10 consistent gets for the 10 rows accessed (as the clustering here is poor) for a total of 14 consistent gets.
Let’s now compare this to an equivalent Local Index.
SQL> create index big_bowie_total_sales_local_i on big_bowie(total_sales) local invisible; Index created. SQL> alter index big_bowie_total_sales_i invisible; Index altered. SQL> alter index big_bowie_total_sales_local_i visible; Index altered.
If we compare the size characteristics between the two indexes we notice a couple of important differences:
SQL> select index_name, blevel, leaf_blocks from dba_indexes where table_name='BIG_BOWIE'; INDEX_NAME BLEVEL LEAF_BLOCKS ------------------------------ ---------- ----------- BIG_BOWIE_TOTAL_SALES_I 2 5585 BIG_BOWIE_TOTAL_SALES_LOCAL_I 1 4444 SQL> select index_name, partition_name, blevel, leaf_blocks from dba_ind_partitions where index_name='BIG_BOWIE_TOTAL_SALES_LOCAL_I'; INDEX_NAME PARTITION_NAME BLEVEL LEAF_BLOCKS ------------------------------ -------------------- ---------- ----------- BIG_BOWIE_TOTAL_SALES_LOCAL_I ALBUMS_2011 1 525 BIG_BOWIE_TOTAL_SALES_LOCAL_I ALBUMS_2012 1 581 BIG_BOWIE_TOTAL_SALES_LOCAL_I ALBUMS_2013 1 579 BIG_BOWIE_TOTAL_SALES_LOCAL_I ALBUMS_2014 1 579 BIG_BOWIE_TOTAL_SALES_LOCAL_I ALBUMS_2015 1 579 BIG_BOWIE_TOTAL_SALES_LOCAL_I ALBUMS_2016 1 581 BIG_BOWIE_TOTAL_SALES_LOCAL_I ALBUMS_2017 1 580 BIG_BOWIE_TOTAL_SALES_LOCAL_I ALBUMS_2018 1 440 8 rows selected.
The first difference is that the corresponding Local index segments have a reduced BLEVEL (just 1) when compared to the Global Index (value of 2). A reduction in BLEVEL is quite possible as instead of one “big” index segment, we now have 8 “smaller” index segments.
However, if we look at the overall size of both indexes, we notice that the Local Index (at 4444 leaf blocks) is somewhat smaller than the Global Index (5585 leaf blocks). This is due to the Rowids of Local Indexes not having to be the extended Global Index 10 byte version (which contains the 4 byte Data Object Id), but the standard 6 byte version. Local Indexes can only reference the one table partition and so it’s unnecessary to store the corresponding Data Object Id within the Rowid.
A partial block dump of a Local Index leaf block:
Leaf block dump
===============
header address 924483684=0x371a8064
kdxcolev 0
KDXCOLEV Flags = – – –
kdxcolok 0
kdxcoopc 0x80: opcode=0: iot flags=— is converted=Y
kdxconco 2
kdxcosdc 0
kdxconro 483
kdxcofbo 1002=0x3ea
kdxcofeo 1823=0x71f
kdxcoavs 821
kdxlespl 0
kdxlende 0
kdxlenxt 29412237=0x1c0cb8d
kdxleprv 0=0x0
kdxledsz 0
kdxlebksz 8036
row#0[8024] flag: ——-, lock: 0, len=12
col 0; len 2; (2): c1 47
col 1; len 6; (6): 01 c0 20 7b 00 a6
row#1[8012] flag: ——-, lock: 0, len=12
col 0; len 2; (2): c1 47
col 1; len 6; (6): 01 c0 22 3a 00 00
row#2[8000] flag: ——-, lock: 0, len=12
col 0; len 2; (2): c1 48
col 1; len 6; (6): 01 c0 20 7b 00 a7
Shows that the Rowids are only 6 bytes.
If we re-run the query that references the partition key in a SQL predicate:
SQL> SELECT * FROM big_bowie WHERE total_sales = 42 and release_date between '01-JAN-2017' and '31-JUL-2017'; ID ALBUM_ID COUNTRY_ID RELEASE_D TOTAL_SALES ---------- ---------- ---------- --------- ----------- 1000041 42 42 20-JUL-17 42 Execution Plan ---------------------------------------------------------- Plan hash value: 3499166408 -------------------------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | Pstart | Pstop | -------------------------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 25 | 2 (0) | 00:00:01 | | | | 1 | PARTITION RANGE SINGLE | | 1 | 25 | 2 (0) | 00:00:01 | 7 | 7 | |* 2 | TABLE ACCESS BY LOCAL INDEX ROWID BATCHED | BIG_BOWIE | 1 | 25 | 2 (0) | 00:00:01 | 7 | 7 | |* 3 | INDEX RANGE SCAN | BIG_BOWIE_TOTAL_SALES_LOCAL_I | 1 | | 1 (0) | 00:00:01 | 7 | 7 | -------------------------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - filter("RELEASE_DATE"<=TO_DATE(' 2017-07-31 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) 3 - access("TOTAL_SALES"=42) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 4 consistent gets 0 physical reads 0 redo size 885 bytes sent via SQL*Net to client 624 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 that this is slightly more efficient with only 4 consistent gets, when previously the Global Index required 5 consistent gets. This is directly due to the reduction in the BLEVEL.
So this is a good thing, especially if this query is frequently executed.
If we now run the query without the partition key SQL predicate:
SQL> SELECT * FROM big_bowie WHERE total_sales = 42; ID ALBUM_ID COUNTRY_ID RELEASE_D TOTAL_SALES ---------- ---------- ---------- --------- ----------- 400041 42 42 28-JAN-12 42 1800041 42 42 28-JAN-12 42 800041 42 42 03-MAR-13 42 1200041 42 42 07-APR-14 42 1600041 42 42 12-MAY-15 42 200041 42 42 12-MAY-15 42 600041 42 42 15-JUN-16 42 1000041 42 42 20-JUL-17 42 41 42 42 24-AUG-18 42 1400041 42 42 24-AUG-18 42 10 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 3527547124 -------------------------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | Pstart | Pstop | -------------------------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 10 | 250 | 15 (0) | 00:00:01 | | | | 1 | PARTITION RANGE ALL | | 10 | 250 | 15 (0) | 00:00:01 | 1 | 8 | | 2 | TABLE ACCESS BY LOCAL INDEX ROWID BATCHED | BIG_BOWIE | 10 | 250 | 15 (0) | 00:00:01 | 1 | 8 | |* 3 | INDEX RANGE SCAN | BIG_BOWIE_TOTAL_SALES_LOCAL_I | 10 | | 9 (0) | 00:00:01 | 1 | 8 | -------------------------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 3 - access("TOTAL_SALES"=42) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 27 consistent gets 0 physical reads 0 redo size 1088 bytes sent via SQL*Net to client 624 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 10 rows processed
We notice that consistent gets have increased more significantly, up to 27 consistent gets when it was previously 14 consistent gets.
This is because instead of accessing the one Global Index structure, we are now forced to access all 8 Local index structures, as the required TOTAL_SALES value could potentially be found in any of the table partitions. So that’s a minimum of at least 2 consistent gets per Local Index (with an index of BLEVEL 1) that has to accessed even if there are actually no corresponding rows of interest in the particular table partition.
Imagine if this table had a 1000+ table partitions, you can easily see how the cost of using such Local Indexes can quickly become excessive.
So Local Indexes can be very problematic if the partition key is NOT referenced in the SQL or if the range of possible table partitions is excessive. The advantage of a Non-Partitioned index is that there is only the one index structure that need be accessed, regardless of the number of table partitions.
So what if you want to protect yourself from the possible ramifications of the table partition key not being referenced in SQL predicates, but you want to take advantage of the performance benefits of smaller index structures that might have a reduced index BLEVEL?
That’s the topic of Part IV in this series 🙂
“Hidden” Efficiencies of Non-Partitioned Indexes on Partitioned Tables Part II (Aladdin Sane) October 9, 2018
Posted by Richard Foote in Global Indexes, Index Internals, Local Indexes, Oracle Indexes, Partitioned Indexes, Partitioning, ROWID.2 comments
In Part I of this series, I highlighted how a Non-Partitioned Global Index on a Partitioned Table is able to effectively perform “Partition Pruning” by reading only the associated index entries to access just the table blocks of interest from relevant table partitions when the table partitioned keys are specified in an SQL Predicate.
Understanding how Oracle achieves this is key (pun fully intended) in understanding the associated advantages of Global Indexes.
Back in time before Oracle introduced Partitioning (pre-Oracle 8 days), the 6 byte ROWID was safely made up of the following components:
- File Number
- Block Number
- Row Number
to uniquely determine the location of any given row.
If we look at a partial block dump of a leaf block from the index based on the Non-Partitioned table:
Leaf block dump
===============
header address 1881436260=0x70247064
kdxcolev 0
KDXCOLEV Flags = – – –
kdxcolok 0
kdxcoopc 0x80: opcode=0: iot flags=— is converted=Y
kdxconco 2
kdxcosdc 0
kdxconro 513
kdxcofbo 1062=0x426
kdxcofeo 1880=0x758
kdxcoavs 818
kdxlespl 0
kdxlende 0
kdxlenxt 29387269=0x1c06a05
kdxleprv 0=0x0
kdxledsz 0
kdxlebksz 8036
row#0[8024] flag: ——-, lock: 0, len=12
col 0; len 2; (2): c1 02
col 1; len 6; (6): 01 c0 1d 68 00 18
row#1[8012] flag: ——-, lock: 0, len=12
col 0; len 2; (2): c1 02
col 1; len 6; (6): 01 c0 24 c8 00 c1
row#2[8000] flag: ——-, lock: 0, len=12
col 0; len 2; (2): c1 02
col 1; len 6; (6): 01 c0 3a 1c 00 96
…
We notice that the ROWID for each index entry is the standard 6 bytes in size.
With the introduction of Oracle 8 and the Partitioning Option, the File Number was no longer unique, with this number of files (approx. 1K) now possible not for the database at large, but for each Tablespace (thus making Oracle able to cater for very large databases with there now being the option for so many more data files in a database).
This means for a Partitioned Table in which each table partition (or sub-partition) could potentially reside in different tablespaces, the associated file number (RELATIVE_FNO) within the ROWID is no longer unique. Therefore, for Global Indexes in which index entries span across all table partitions, the ROWID is extended to include the 4 byte Data Object Id. A specific object can only live in one tablespace and if Oracle knows the tablespace, Oracle can determine which specific file number the ROWID is referencing. So an extended ROWID is consists of:
- Data Object Id
- File Number
- Block Number
- Row Number
If we look at a partial block dump of a leaf block from the index based on the Partitioned table:
Leaf block dump
===============
header address 1881436260=0x70247064
kdxcolev 0
KDXCOLEV Flags = – – –
kdxcolok 0
kdxcoopc 0x80: opcode=0: iot flags=— is converted=Y
kdxconco 2
kdxcosdc 0
kdxconro 399
kdxcofbo 834=0x342
kdxcofeo 1652=0x674
kdxcoavs 818
kdxlespl 0
kdxlende 0
kdxlenxt 29385221=0x1c06205
kdxleprv 0=0x0
kdxledsz 0
kdxlebksz 8036
row#0[8020] flag: ——-, lock: 0, len=16
col 0; len 2; (2): c1 02
col 1; len 10; (10): 00 01 57 4a 01 c0 5e cf 00 cc
row#1[8004] flag: ——-, lock: 0, len=16
col 0; len 2; (2): c1 02
col 1; len 10; (10): 00 01 57 4a 01 c0 5f 74 00 e7
row#2[7988] flag: ——-, lock: 0, len=16
col 0; len 2; (2): c1 02
col 1; len 10; (10): 00 01 57 4b 01 c0 5c 32 00 c9
…
We notice that the ROWID for each index entry is now the extended 10 bytes in size as it includes the Data Object Id.
Storing the Data Object Id as part of the ROWID has various advantages, such as being able to asynchronously maintain index entries following table partition operations such as dropping a table partition (as discussed previously here).
However the key advantage of storing the Data Object Id as part of the ROWID is that this enables Oracle when using Global Indexes to automatically perform “Partition Pruning” (the ability to access only those partitions that can possibly contain data of interest), when the table partition key is specified in an SQL predicate.
When the table partition key is specified in an SQL predicate, Oracle can determine which table partitions can only contain such data and then only access the table blocks via the index ROWIDs that have corresponding Data Object Ids of interest. This is how in the example in Part I Oracle was able to only access just the table block that belongs in the table partition of interest, effectively performing predicate filtering at the index level, without unnecessarily having to access the table blocks at all from partitions that are not of interest.
This enables Global Indexes to have almost Local Index like performance in scenarios where the table partition key is specified in SQL predicates. Local Indexes do have the advantage of potentially having a reduced BLEVEL in that if you have say 100 table partitions, each Local Index would only have to be approx. 1/100 the size of the single, Non-Partitioned Index (although Global Indexes can in turn be partitioned if individual index size were problematic, even if the table were not partitioned). Additionally, Local Indexes don’t have to concern themselves with having to read through unnecessary index entries if index entries associated with a specific subset of table partitions were only of interest.
However, Global Indexes have a key performance advantage over Local Indexes which I’ll discussed in Part III.
“Hidden” Efficiencies of Non-Partitioned Indexes on Partitioned Tables Part I (The Jean Genie) October 4, 2018
Posted by Richard Foote in Global Indexes, Local Indexes, Non-Partitioned Indexes, Oracle Indexes, Partitioned Indexes, Partitioning.7 comments
When it comes to indexing a partitioned table, many automatically opt for Local Indexes, as it’s often assumed they’re simply easier to manage and more efficient than a corresponding Global Index.
Having smaller index structures that are aligned to how the table is partitioned certainly has various advantages. The focus in this little series is on the “more efficient” claim.
A key point that many miss is that a Non-Partitioned Index on a Non-Partitioned table is not exactly the same beast as a Non-Partitioned Index on a Partitioned Table. The purpose of this initial post is to illustrate this difference.
Let’s begin by creating a Non-Partitioned table that has a number of years worth of data:
SQL> CREATE TABLE big_ziggy (id number, album_id number, country_id number, release_date date, total_sales number); Table created. SQL> INSERT INTO big_ziggy SELECT rownum, mod(rownum,5000)+1, mod(rownum,100)+1, sysdate-mod(rownum,2800), mod(rownum,200000)+1 FROM dual CONNECT BY LEVEL 2000000; 2000000 rows created. SQL> commit; Commit complete. SQL> exec dbms_stats.gather_table_stats(ownname=> null, tabname=> 'BIG_ZIGGY'); PL/SQL procedure successfully completed.
So we have a 2M row table with about 8 years worth of data (based on the RELEASE_DATE column) and a TOTAL_SALES column that has some 200,000 distinct columns throughout this period.
Let’s next create a standard Non-Partitioned index based on the TOTAL_SALES column:
SQL> create index big_ziggy_total_sales_i on big_ziggy(total_sales); Index created.
If we now run a query to access the 10 rows with a value equal to 42:
SQL> SELECT * FROM big_ziggy WHERE total_sales = 42; ID ALBUM_ID COUNTRY_ID RELEASE_D TOTAL_SALES ---------- ---------- ---------- --------- ----------- 1400041 42 42 24-AUG-18 42 400041 42 42 28-JAN-12 42 1000041 42 42 20-JUL-17 42 1800041 42 42 28-JAN-12 42 600041 42 42 15-JUN-16 42 800041 42 42 03-MAR-13 42 1200041 42 42 07-APR-14 42 1600041 42 42 12-MAY-15 42 200041 42 42 12-MAY-15 42 41 42 42 24-AUG-18 42 10 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 1252095634 --------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | --------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 10 | 250 | 13 (0) | 00:00:01 | | 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BIG_ZIGGY | 10 | 250 | 13 (0) | 00:00:01 | |* 2 | INDEX RANGE SCAN | BIG_ZIGGY_TOTAL_SALES_I | 10 | | 3 (0) | 00:00:01 | --------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("TOTAL_SALES"=42) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 14 consistent gets 0 physical reads 0 redo size 1184 bytes sent via SQL*Net to client 624 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 10 rows processed
We notice we need 14 consistent gets to access these 10 rows, 4 gets for index block accesses and 10 gets to access the relevant rows from the table blocks (as we have a terrible clustering due to the relevant data being distributed throughout the table).
If we run a query where we’re only interested in accessing data only within a specific year:
SQL> SELECT * FROM big_ziggy WHERE total_sales = 42 and release_date between '01-JAN-2017' and '31-JUL-2017'; ID ALBUM_ID COUNTRY_ID RELEASE_D TOTAL_SALES ---------- ---------- ---------- --------- ----------- 1000041 42 42 20-JUL-17 42 Execution Plan ---------------------------------------------------------- Plan hash value: 1252095634 --------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | --------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 25 | 13 (0) | 00:00:01 | |* 1 | TABLE ACCESS BY INDEX ROWID BATCHED | BIG_ZIGGY | 1 | 25 | 13 (0) | 00:00:01 | |* 2 | INDEX RANGE SCAN | BIG_ZIGGY_TOTAL_SALES_I | 10 | | 3 (0) | 00:00:01 | --------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - filter("RELEASE_DATE">=TO_DATE(' 2017-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND "RELEASE_DATE"<=TO_DATE(' 2017-07-31 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) 2 - access("TOTAL_SALES"=42) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 14 consistent gets 0 physical reads 0 redo size 885 bytes sent via SQL*Net to client 624 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 1 rows processed
Even though we now only return the one row, notice we still have to perform the same 14 consistent gets. That’s because the RELEASE_DATE column is NOT part of the index, so we still need to fetch all 10 matching rows with TOTAL_SALES=42 and then filter out those that don’t have a RELEASE_DATE of interest. The note above in the predicate information shows we now have this additional filtering taking place.
Let’s run the same queries on a table with identical data, but this time on a table that is partitioned based on the RELEASE_DATE column, with a partition for each years worth of data:
SQL> CREATE TABLE big_bowie(id number, album_id number, country_id number, release_date date, total_sales number) 2 PARTITION BY RANGE (release_date) 3 (PARTITION ALBUMS_2011 VALUES LESS THAN (TO_DATE('01-JAN-2012', 'DD-MON-YYYY')), 4 PARTITION ALBUMS_2012 VALUES LESS THAN (TO_DATE('01-JAN-2013', 'DD-MON-YYYY')), 5 PARTITION ALBUMS_2013 VALUES LESS THAN (TO_DATE('01-JAN-2014', 'DD-MON-YYYY')), 6 PARTITION ALBUMS_2014 VALUES LESS THAN (TO_DATE('01-JAN-2015', 'DD-MON-YYYY')), 7 PARTITION ALBUMS_2015 VALUES LESS THAN (TO_DATE('01-JAN-2016', 'DD-MON-YYYY')), 8 PARTITION ALBUMS_2016 VALUES LESS THAN (TO_DATE('01-JAN-2017', 'DD-MON-YYYY')), 9 PARTITION ALBUMS_2017 VALUES LESS THAN (TO_DATE('01-JAN-2018', 'DD-MON-YYYY')), 10 PARTITION ALBUMS_2018 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), mod(rownum,200000)+1 FROM dual CONNECT BY LEVEL 2000000; 2000000 rows created. SQL> commit; Commit complete. SQL> exec dbms_stats.gather_table_stats(ownname=> null, tabname=> 'BIG_BOWIE'); PL/SQL procedure successfully completed.
Again, we create a standard, Non-Partitioned Index:
SQL> create index big_bowie_total_sales_i on big_bowie(total_sales); Index created.
If we now run the equivalent of the first query:
SQL> SELECT * FROM big_bowie WHERE total_sales = 42; ID ALBUM_ID COUNTRY_ID RELEASE_D TOTAL_SALES ---------- ---------- ---------- --------- ----------- 400041 42 42 28-JAN-12 42 1800041 42 42 28-JAN-12 42 800041 42 42 03-MAR-13 42 1200041 42 42 07-APR-14 42 1600041 42 42 12-MAY-15 42 200041 42 42 12-MAY-15 42 600041 42 42 15-JUN-16 42 1000041 42 42 20-JUL-17 42 41 42 42 24-AUG-18 42 1400041 42 42 24-AUG-18 42 10 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 1761527485 -------------------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | Pstart | Pstop | -------------------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 10 | 250 | 13 (0) | 00:00:01 | | | | 1 | TABLE ACCESS BY GLOBAL INDEX ROWID BATCHED | BIG_BOWIE | 10 | 250 | 13 (0) | 00:00:01 | ROWID | ROWID | |* 2 | INDEX RANGE SCAN | BIG_BOWIE_TOTAL_SALES_I | 10 | | 3 (0) | 00:00:01 | | | -------------------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("TOTAL_SALES"=42) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 14 consistent gets 0 physical reads 0 redo size 1184 bytes sent via SQL*Net to client 624 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 10 rows processed
We get the exact same performance, with the same 14 consistent gets necessary to access the 10 rows of interest.
If we now run the equivalent of the second query:
SQL> SELECT * FROM big_bowie WHERE total_sales = 42 and release_date between '01-JAN-2017' and '31-JUL-2017'; ID ALBUM_ID COUNTRY_ID RELEASE_D TOTAL_SALES ---------- ---------- ---------- --------- ----------- 1000041 42 42 20-JUL-17 42 Execution Plan ---------------------------------------------------------- Plan hash value: 1081241859 -------------------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | Pstart | Pstop | -------------------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 25 | 13 (0) | 00:00:01 | | | |* 1 | TABLE ACCESS BY GLOBAL INDEX ROWID BATCHED | BIG_BOWIE | 1 | 25 | 13 (0) | 00:00:01 | 7 | 7 | |* 2 | INDEX RANGE SCAN | BIG_BOWIE_TOTAL_SALES_I | 10 | | 3 (0) | 00:00:01 | | | -------------------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - filter("RELEASE_DATE"=TO_DATE(' 2017-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) 2 - access("TOTAL_SALES"=42) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 5 consistent gets 0 physical reads 0 redo size 885 bytes sent via SQL*Net to client 624 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 a key difference. Even though it’s equivalent to the same index as in the previous Non-Partitioned table and even though the index only contains just the TOTAL_SALES column, the number of consistent gets has dropped from 14 to just 5 consistent gets.
In this example, Oracle has clearly not had to fetch the rows from the table that do not match the RELEASE_DATE of interest. Even though the predicate information is listing the requirement for filtering to take place, this filtering has clearly been performed within the index, without having to actually fetch any of the rows that aren’t of interest.
The index is able to only access the row(s) of interest from the Partitioned Table…
This is the little “hidden efficiency” of Global Indexes on Partitioned Tables, which is what we effectively have here.
In Part II, I’ll discuss how Oracle does this additional filtering within the index and why understanding this is important in deciding which type of index to deploy, as from a “performance” perspective, Global Indexes are often the preferred option.