I think personally, A is the most readable. It actually says to me "get all of the rows such that end_date is not set or end_date >= right now"
C says "take end_date, if null set it to some value I cannot see, and then compare to sysdate"
The first says precisely what you mean, the second, not so much.
But that aside, if you are not planning on using an index as an access path for this (A) would get my vote. If you wanted an index access path then:
ops$tkyte%ORA11GR1> create table t
2 as
3 select all_objects.*, decode( mod(rownum,100), 0, to_date(null), created+1 ) end_date
4 from stage all_objects
5 /
Table created.
ops$tkyte%ORA11GR1>
ops$tkyte%ORA11GR1> create index t_idx on t( nvl(end_date,to_date('31-dec-9999','dd-mon-yyyy') ) );
Index created.
ops$tkyte%ORA11GR1> exec dbms_stats.gather_table_stats( user, 'T', method_opt=>'for all indexed columns' );
PL/SQL procedure successfully completed.
ops$tkyte%ORA11GR1>
ops$tkyte%ORA11GR1> variable x varchar2(30)
ops$tkyte%ORA11GR1>
ops$tkyte%ORA11GR1> set autotrace traceonly explain
ops$tkyte%ORA11GR1> select * from t where nvl(end_date,to_date('31-dec-9999','dd-mon-yyyy')) >= sysdate;
Execution Plan
----------------------------------------------------------
Plan hash value: 470836197
-------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 913 | 104K| 31 (0)| 00:00:01 |
| 1 | TABLE ACCESS BY INDEX ROWID| T | 913 | 104K| 31 (0)| 00:00:01 |
|* 2 | INDEX RANGE SCAN | T_IDX | 913 | | 4 (0)| 00:00:01 |
-------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access(NVL("END_DATE",TO_DATE(' 9999-12-31 00:00:00', 'syyyy-mm-dd
hh24:mi:ss'))>=SYSDATE@!)
ops$tkyte%ORA11GR1> set autotrace off
that would be my approach and you can hide the complexity if you wish by adding a virtual column:
ops$tkyte%ORA11GR1> drop index t_idx;
Index dropped.
ops$tkyte%ORA11GR1> alter table t add end_date_nvl as (nvl(end_date,to_date('31-dec-9999','dd-mon-yyyy')));
Table altered.
ops$tkyte%ORA11GR1> create index t_idx on t(end_date_nvl);
Index created.
ops$tkyte%ORA11GR1> exec dbms_stats.gather_table_stats( user, 'T', method_opt=>'for all indexed columns' );
PL/SQL procedure successfully completed.
ops$tkyte%ORA11GR1>
ops$tkyte%ORA11GR1> set autotrace traceonly explain
ops$tkyte%ORA11GR1> select * from t where end_date_nvl >= sysdate;
Execution Plan
----------------------------------------------------------
Plan hash value: 470836197
-------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 913 | 104K| 31 (0)| 00:00:01 |
| 1 | TABLE ACCESS BY INDEX ROWID| T | 913 | 104K| 31 (0)| 00:00:01 |
|* 2 | INDEX RANGE SCAN | T_IDX | 913 | | 4 (0)| 00:00:01 |
-------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("END_DATE_NVL">=SYSDATE@!)
ops$tkyte%ORA11GR1> set autotrace off