SELECT COUNT(DISTINCT dbms_rowid.rowid_block_number(ROWID)) blocks
FROM my_big_table
WHERE my_big_table.column1 = 'something'
AND my_big_table.column2 = 'something else'
SELECT COUNT(DISTINCT dbms_rowid.rowid_block_number(ROWID)) blocks
FROM my_big_table
CREATE TABLE measurement
(
meter_id INTEGER,
meter_time DATE,
meter_value NUMBER,
CONSTRAINT pk_measurement PRIMARY KEY(meter_id, meter_time)
);
INSERT INTO measurement(meter_id, meter_time, meter_value)
SELECT meter_id, meter_time, MOD(ROWNUM, 97) meter_value
FROM (SELECT LEVEL meter_id
FROM DUAL
CONNECT BY LEVEL <= 100),
(SELECT TRUNC(SYSDATE, 'yyyy') + LEVEL / 24 meter_time
FROM DUAL
CONNECT BY LEVEL < 1000)
ORDER BY meter_time, meter_id;
BEGIN
DBMS_STATS.gather_table_stats(
ownname => USER,
tabname => 'MEASUREMENT',
estimate_percent => NULL,
cascade => TRUE
);
END;
EXPLAIN PLAN
FOR
SELECT *
FROM measurement
WHERE meter_id = 50;
SELECT * FROM TABLE(DBMS_XPLAN.display);
Plan hash value: 190790823
---------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
---------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 999 | 13986 | 103 (1)| 00:00:02 |
|* 1 | TABLE ACCESS FULL| MEASUREMENT | 999 | 13986 | 103 (1)| 00:00:02 |
---------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter("METER_ID"=50)
CREATE INDEX idx_measurement_time
ON measurement(meter_time);
EXPLAIN PLAN
FOR
SELECT *
FROM measurement
WHERE meter_time > TRUNC(SYSDATE, 'yyyy') + 100 / 24
AND meter_time < TRUNC(SYSDATE, 'yyyy') + 200 / 24;
SELECT * FROM TABLE(DBMS_XPLAN.display);
Plan hash value: 1512076386
-----------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 10010 | 136K| 60 (0)| 00:00:01 |
|* 1 | FILTER | | | | | |
| 2 | TABLE ACCESS BY INDEX ROWID| MEASUREMENT | 10010 | 136K| 60 (0)| 00:00:01 |
|* 3 | INDEX RANGE SCAN | IDX_MEASUREMENT_TIME | 10010 | | 28 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter(TRUNC(SYSDATE@!,'fmyyyy')+4.16666666666666666666666666666666666667<TRUNC(SYSDAT
E@!,'fmyyyy')+8.33333333333333333333333333333333333333)
3 - access("METER_TIME">TRUNC(SYSDATE@!,'fmyyyy')+4.16666666666666666666666666666666666667
AND "METER_TIME"<TRUNC(SYSDATE@!,'fmyyyy')+8.33333333333333333333333333333333333333)
SELECT index_name, clustering_factor
FROM user_indexes
WHERE table_name = 'MEASUREMENT';
INDEX_NAME CLUSTERING_FACTOR
------------------------------ -----------------
PK_MEASUREMENT 26200
IDX_MEASUREMENT_TIME 316
SELECT COUNT(DISTINCT DBMS_ROWID.rowid_block_number(ROWID)) blocks FROM measurement;
BLOCKS
----------
262
SELECT COUNT(DISTINCT DBMS_ROWID.rowid_block_number(ROWID)) blocks
FROM measurement
WHERE meter_id = 50;
BLOCKS
----------
262
SELECT COUNT(DISTINCT DBMS_ROWID.rowid_block_number(ROWID)) blocks
FROM measurement
WHERE meter_time > TRUNC(SYSDATE, 'yyyy') + 100 / 24
AND meter_time < TRUNC(SYSDATE, 'yyyy') + 200 / 24;
BLOCKS
----------
27
EXPLAIN PLAN
FOR
SELECT *
FROM measurement
WHERE TRUNC(meter_time) = TRUNC(SYSDATE, 'yyyy') + 10;
SELECT * FROM TABLE(DBMS_XPLAN.display);
Plan hash value: 190790823
---------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
---------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 999 | 13986 | 108 (6)| 00:00:02 |
|* 1 | TABLE ACCESS FULL| MEASUREMENT | 999 | 13986 | 108 (6)| 00:00:02 |
---------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter(TRUNC(INTERNAL_FUNCTION("METER_TIME"))=TRUNC(SYSDATE@!,'fmy
yyy')+10)
CREATE INDEX idx_measurement_day
ON measurement(trunc(meter_time));
EXPLAIN PLAN
FOR
SELECT *
FROM measurement
WHERE TRUNC(meter_time) = TRUNC(SYSDATE, 'yyyy') + 10;
SELECT * FROM TABLE(DBMS_XPLAN.display);
Plan hash value: 242868325
---------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
---------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 999 | 13986 | 8 (0)| 00:00:01 |
| 1 | TABLE ACCESS BY INDEX ROWID| MEASUREMENT | 999 | 13986 | 8 (0)| 00:00:01 |
|* 2 | INDEX RANGE SCAN | IDX_MEASUREMENT_DAY | 400 | | 6 (0)| 00:00:01 |
---------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access(TRUNC(INTERNAL_FUNCTION("METER_TIME"))=TRUNC(SYSDATE@!,'fmyyyy')+10)
EXPLAIN PLAN
FOR
SELECT *
FROM measurement
WHERE meter_time >= TRUNC(SYSDATE, 'yyyy') + 10
AND meter_time < TRUNC(SYSDATE, 'yyyy') + 11;
SELECT * FROM TABLE(DBMS_XPLAN.display);
Plan hash value: 1512076386
-----------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 2502 | 35028 | 16 (0)| 00:00:01 |
|* 1 | FILTER | | | | | |
| 2 | TABLE ACCESS BY INDEX ROWID| MEASUREMENT | 2502 | 35028 | 16 (0)| 00:00:01 |
|* 3 | INDEX RANGE SCAN | IDX_MEASUREMENT_TIME | 2502 | | 8 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter(TRUNC(SYSDATE@!,'fmyyyy')+10<TRUNC(SYSDATE@!,'fmyyyy')+11)
3 - access("METER_TIME">=TRUNC(SYSDATE@!,'fmyyyy')+10 AND
"METER_TIME"<TRUNC(SYSDATE@!,'fmyyyy')+11)
filter(TRUNC(INTERNAL_FUNCTION("METER_TIME"))>=TRUNC(TRUNC(SYSDATE@!,'fmyyyy')+10)
AND TRUNC(INTERNAL_FUNCTION("METER_TIME"))<=TRUNC(TRUNC(SYSDATE@!,'fmyyyy')+11))
Have a question about something in this article? You can receive help directly from the article author. Sign up for a free trial to get started.
Comments (1)
Commented: