Here is an interesting little test case to demonstrate the issue.
create table dept (deptno number, dname varchar2(100));
insert into dept values (1,'HR');
insert into dept values (2,'AZ');
insert into dept values (3,'XL');
SELECT deptno, dname
FROM dept
WHERE deptno in (SELECT round(dbms_random.value(1, 3)) FROM dual);
I would expect that the sub query would return 1 row ( 1/2/3) and therefore the main query should always return 1 record.
Now let us run this query a few times and see the result set.
/
2 AZ
/
now rows selected
/
1 HR
3 XL
Here is the execution plan of the statement.
---------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
---------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 22 | 4 (0)| 00:00:01 |
|* 1 | FILTER | | | | | |
| 2 | TABLE ACCESS FULL| DEPT | 4 | 88 | 2 (0)| 00:00:01 |
|* 3 | FILTER | | | | | |
| 4 | FAST DUAL | | 1 | | 2 (0)| 00:00:01 |
---------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter( EXISTS (SELECT 0 FROM "SYS"."DUAL" "DUAL" WHERE
ROUND("DBMS_RANDOM"."VALUE"(1,3))=:B1))
3 - filter(ROUND("DBMS_RANDOM"."VALUE"(1,3))=:B1)
Strange, different executions return different number of records. Wrong results ?
No. Problem here is with the non-deterministic function (dbms_random.value).
This function is evaluated once for each row returned by DEPT, rather than
being evaluated once at the start. This behavior is expected as optimizer
does not guarantee when a non-deterministic function will be evaluated during
the statement execution.
You have to be careful when you use such non-deterministic functions in the SQL statement.
create table dept (deptno number, dname varchar2(100));
insert into dept values (1,'HR');
insert into dept values (2,'AZ');
insert into dept values (3,'XL');
SELECT deptno, dname
FROM dept
WHERE deptno in (SELECT round(dbms_random.value(1, 3)) FROM dual);
I would expect that the sub query would return 1 row ( 1/2/3) and therefore the main query should always return 1 record.
Now let us run this query a few times and see the result set.
/
2 AZ
/
now rows selected
/
1 HR
3 XL
Here is the execution plan of the statement.
---------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
---------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 22 | 4 (0)| 00:00:01 |
|* 1 | FILTER | | | | | |
| 2 | TABLE ACCESS FULL| DEPT | 4 | 88 | 2 (0)| 00:00:01 |
|* 3 | FILTER | | | | | |
| 4 | FAST DUAL | | 1 | | 2 (0)| 00:00:01 |
---------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter( EXISTS (SELECT 0 FROM "SYS"."DUAL" "DUAL" WHERE
ROUND("DBMS_RANDOM"."VALUE"(1,3))=:B1))
3 - filter(ROUND("DBMS_RANDOM"."VALUE"(1,3))=:B1)
Strange, different executions return different number of records. Wrong results ?
No. Problem here is with the non-deterministic function (dbms_random.value).
This function is evaluated once for each row returned by DEPT, rather than
being evaluated once at the start. This behavior is expected as optimizer
does not guarantee when a non-deterministic function will be evaluated during
the statement execution.
You have to be careful when you use such non-deterministic functions in the SQL statement.