Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> Re: A Cure for Madness

Re: A Cure for Madness

From: Wolfgang Breitling <breitliw_at_centrexcc.com>
Date: Sun, 29 Aug 2004 10:43:59 -0600
Message-Id: <6.1.0.6.2.20040829100912.02ea7840@pop.centrexcc.com>


It is probably heresy to contradict the great Chris Date, but I disagree with this part of his follow-up:

"
Now, the SQL standard makes it perfectly clear that the result of the query

SELECT *
FROM R1
WHERE NUM > 0 ; is defined as follows:

  1. Evaluate R1.
  2. Restrict the result of the previous step to just those rows satisfying NUM > 0.
  3. Project the result of the previous step over all of its columns (which is effectively a no op, of course).

In other words, the inner subquery must be evaluated before the outer WHERE and SELECT clauses are executed (hence my unequivocal no to the question "Is this rewriting on the part of the optimizer valid?"). But there's still a little more to be said. "

Maybe that is the SQL standard, I don't know, I don't have the text of it, but it is certainly not part of the relational theory whose strength is the fact that the operations selection (where clause), projection (select clause) and join can be freely interchanged as long as the rules laid out by the theory are followed. And none of the relational databases implement Chris' 1-2-3 order of operation. And I am sure everyone would be very upset if they implemented the rule that a subquery must be evaluated before predicates and selection are applied. Think of the emp table (EMPNO, ENAME, JOB, MGR, HIREDATE, SAL, COMM, DEPTNO) and create a view that excludes the sensitive data: emp_vw (select EMPNO, ENAME, JOB, MGR, DEPTNO from emp). Now, according to Chris' stand, a query like select * from emp_vw where empno = 7369 would not be allowed to apply the predicate to the underlying emp table but would need to evaluate the view first ( which consists solely of a select , i.e. a temporary rowsource consisting of the selected columns from the entire emp table has to be built ) before applying the restriction "where empno = 7369". Imagine the performance.

I have said it before and I still content that the original problem is not caused by the optimizer incorrectly reordering the sequence of operations but by the fact that the to_number function is not well defined over the domain (varchar2). If that was not the case we would not have this debate as the end result would be the same no matter the order of operations. To prove it I created a function my_to_number which returns a NULL (i.e. undefined) if presented with something that does not represent a number: create or replace function my_to_number(input in varchar2) return number is
l_num number := NULL;
begin
  begin
   l_num := to_number(input);
  exception
   when others then null;
  end;
  return l_num;
end;

SQL> create table subtest (flag varchar2(1), num varchar2(5)); Table created.
SQL> insert into subtest values('N','123'); 1 row created.
SQL> insert into subtest values('X','123'); 1 row created.
SQL> insert into subtest values('Y','pqr'); 1 row created.
SQL> insert into subtest values('N','456'); 1 row created.
SQL> insert into subtest values('Z','ijk'); 1 row created.
SQL> commit;
Commit complete.
SQL> analyze table subtest compute statistics; Table analyzed.

Executing the query as is produces the error: SQL> SELECT SELECT FLAG, NUM
   2 FROM ( SELECT FLAG, TO_NUMBER ( NUM ) NUM

   3         FROM   SUBTEST
   4         WHERE  FLAG = 'N' )

   5 WHERE NUM > 0 ; ERROR:
ORA-01722: invalid number

Forcing the subquery to be evaluated first gives us the result SQL> SELECT SELECT FLAG, NUM
   2 FROM ( SELECT rownum, FLAG, TO_NUMBER ( NUM ) NUM

   3         FROM   SUBTEST
   4         WHERE  FLAG = 'N' )

   5 WHERE NUM > 0 ; F NUM
- ----------
N        123
N        456

2 rows selected.

Using the extended TO_NUMBER function also gives the same result, proving that the reordering does not affect the final resultset. SQL> SELECT SELECT FLAG, NUM
   2 FROM ( SELECT FLAG, my_TO_NUMBER ( NUM ) NUM

   3         FROM   SUBTEST
   4         WHERE  FLAG = 'N' )

   5 WHERE NUM > 0 ; F NUM
- ----------
N        123
N        456

2 rows selected.

At 03:19 PM 8/27/2004, you wrote:

>Some of you might have read the article I recently posted on
>"Subquery Madness!":
>
>http://five.pairlist.net/pipermail/oracle-article/2004/000012.html
>
>Chris Date took an interest in the issue, and he wrote a
>fascinating follow-up, "A Cure for Madness," which just went
>live today:
>
>http://www.dbdebunk.com/page/page/1351381.htm
>
>Please note that Chris is *not* saying that the subquery
>results need to be materialized, but only that the final
>results need to be "as if" they had been. I can think of at
>least two ways to merge the subquery and yet maintain the
>required "as if" behavior.
>
>Chris's article is really clear and well-written. I wish I
>could write as well as he does. I think you'll find his
>article interesting no matter which side of the issue you
>personally fall on.

Regards

Wolfgang Breitling
Centrex Consulting Corporation
www.centrexcc.com



Please see the official ORACLE-L FAQ: http://www.orafaq.com

To unsubscribe send email to: oracle-l-request_at_freelists.org put 'unsubscribe' in the subject line.
--
Archives are at http://www.freelists.org/archives/oracle-l/
FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------
Received on Sun Aug 29 2004 - 11:39:43 CDT

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US