Because you can never have enough of a good thing.
Here’s a thought – The optimizer doesn’t treat all constants equally. No explanations, just read the code – execution plans at the end:
SQL> drop table t1 purge; SQL> create table t1 nologging as select * from all_objects; SQL> create bitmap index t1_b1 on t1(owner); SQL> alter session set statistics_level = all; SQL> set serveroutput off SQL> select count(*) from t1; SQL> select * from table(dbms_xplan.display_cursor(null,null,'allstats last')); SQL> select count(1) from t1; SQL> select * from table(dbms_xplan.display_cursor(null,null,'allstats last')); SQL> select count(-1) from t1; SQL> select * from table(dbms_xplan.display_cursor(null,null,'allstats last')); SQL> alter session set cursor_sharing = force; SQL> alter system flush shared_pool; SQL> select count(1) from t1; SQL> select * from table(dbms_xplan.display_cursor(null,null,'allstats last'));
So, are you expecting to see the same results and performance from every single one of those queries ?
select count(*) from t1 ---------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows | A-Rows | A-Time | Buffers | Reads | ---------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | 1 |00:00:00.01 | 9 | 5 | | 1 | SORT AGGREGATE | | 1 | 1 | 1 |00:00:00.01 | 9 | 5 | | 2 | BITMAP CONVERSION COUNT | | 1 | 84499 | 31 |00:00:00.01 | 9 | 5 | | 3 | BITMAP INDEX FAST FULL SCAN| T1_B1 | 1 | | 31 |00:00:00.01 | 9 | 5 | ---------------------------------------------------------------------------------------------------------- select count(1) from t1 ------------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows | A-Rows | A-Time | Buffers | ------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | 1 |00:00:00.01 | 9 | | 1 | SORT AGGREGATE | | 1 | 1 | 1 |00:00:00.01 | 9 | | 2 | BITMAP CONVERSION COUNT | | 1 | 84499 | 31 |00:00:00.01 | 9 | | 3 | BITMAP INDEX FAST FULL SCAN| T1_B1 | 1 | | 31 |00:00:00.01 | 9 | ------------------------------------------------------------------------------------------------- select count(-1) from t1 ------------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows | A-Rows | A-Time | Buffers | ------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | 1 |00:00:00.43 | 9 | | 1 | SORT AGGREGATE | | 1 | 1 | 1 |00:00:00.43 | 9 | | 2 | BITMAP CONVERSION TO ROWIDS | | 1 | 84499 | 84499 |00:00:00.22 | 9 | | 3 | BITMAP INDEX FAST FULL SCAN| T1_B1 | 1 | | 31 |00:00:00.01 | 9 | ------------------------------------------------------------------------------------------------- SQL> alter session set cursor_sharing = force; SQL> alter system flush shared_pool; select count(1) from t1 select count(:"SYS_B_0") from t1 -- effect of cursor-sharing ------------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows | A-Rows | A-Time | Buffers | ------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | 1 |00:00:00.46 | 9 | | 1 | SORT AGGREGATE | | 1 | 1 | 1 |00:00:00.46 | 9 | | 2 | BITMAP CONVERSION TO ROWIDS | | 1 | 84499 | 84499 |00:00:00.23 | 9 | | 3 | BITMAP INDEX FAST FULL SCAN| T1_B1 | 1 | | 31 |00:00:00.01 | 9 | -------------------------------------------------------------------------------------------------
Check operation 2 in each plan – with the bitmap index in place there are two possible ways to count the rows referenced in the index – and one of them converts to rowids and does a lot more work.
The only “real” threat in this set of examples, of course, is the bind variable one – there are times when count(*) WILL be faster than count(1). Having said that, there is a case where a redundant “conversion to rowids” IS a threat – and I’ll write that up some time in the near future.
Trick question: when is 1+1 != 2 ?
Silly answer: compare the plan for: “select count (2) from t1” with the plan for “select count(1+1) from t1”
Note: All tests above run on 12.1.0.2
Hmmm….
1+1 != 2 when we want to use indexes.
Because indexing is verbotten for expressions or functions, unless one creates FBIs for each.
Butbutbut…
count(n) is a function, so it should not be using an index:
https://docs.oracle.com/cd/E11882_01/server.112/e41573/data_acc.htm#PFGRF94785
But it is: you just proven it above!
Enter the illogical nature of the CBO rules…
;)
Comment by Noons — January 12, 2015 @ 4:01 am GMT Jan 12,2015 |
[…] an earlier (not very serious) post about count(*) I pointed out how the optimizer sometimes does a redundant “bitmap conversion […]
Pingback by Bitmap Counts | Oracle Scratchpad — January 20, 2015 @ 9:06 pm GMT Jan 20,2015 |
[…] Anomaly 1 […]
Pingback by Why Bother | Oracle Scratchpad — September 20, 2016 @ 11:17 am BST Sep 20,2016 |
[…] will all do the same thing … execute as count(*); I’ve also listed a few quirky anomalies, also more than once. However, count(rowid) is a little different, it doesn’t get transformed […]
Pingback by count(*) – again | Oracle Scratchpad — February 25, 2020 @ 1:24 pm GMT Feb 25,2020 |
[…] Counting rowids by accident (Jan 2015): Cursor_Sharing and other exceptions to “count conversion”. […]
Pingback by Optimizer catalogue | Oracle Scratchpad — October 27, 2022 @ 8:46 am BST Oct 27,2022 |