Joel Mc Graw <[EMAIL PROTECTED]> writes:
> A query such as "select sum(pages) from job_documents where
> delivery_type='print'" returned 0 in version 7.0.3 if there were no rows
> matching the query.  In 7.1.3 the result is NULL if no rows match the
> query.  Why the change?  Which result is "correct" according to the SQL
> standard?

NULL is correct according to the SQL standard (yes, I think it's
brain-dead too).  SQL92 section 6.5 saith:

            b) If AVG, MAX, MIN, or SUM is specified, then

              Case:

              i) If TXA is empty, then the result is the null value.
                 --------------------------------------------------

             ii) If AVG is specified, then the result is the average of the
                 values in TXA.

            iii) If MAX or MIN is specified, then the result is respec-
                 tively the maximum or minimum value in TXA. These results
                 are determined using the comparison rules specified in
                 Subclause 8.2, "<comparison predicate>".

             iv) If SUM is specified, then the result is the sum of the
                 values in TXA. If the sum is not within the range of the
                 data type of the result, then an exception condition is
                 raised: data exception-numeric value out of range.

I'd suggest COALESCE(SUM(foo), 0) if you need a zero result.

However, I dispute your assertion that 7.0.3 returned zero.  I just
double checked, and I get a NULL there too.  If we ever returned zero,
it was a long time ago.

                        regards, tom lane

---------------------------(end of broadcast)---------------------------
TIP 3: if posting/reading through Usenet, please send an appropriate
subscribe-nomail command to [EMAIL PROTECTED] so that your
message can get through to the mailing list cleanly

Reply via email to