Thanks for the helpful tip!

Tim

----- Original Message ----- 
From: "Tom Lane" <[EMAIL PROTECTED]>
To: "Tim Barnard" <[EMAIL PROTECTED]>
Cc: "Jim" <[EMAIL PROTECTED]>; <[EMAIL PROTECTED]>
Sent: Tuesday, May 29, 2001 7:50 AM
Subject: Re: [GENERAL] Re: [SQL] Difficult SQL Statement 


> I wrote:
> > select ASMT_CODE, PASSED, TOTAL, PASSED::float4/TOTAL::float4
> > from
> >     (select ASMT_CODE, count(*) as TOTAL from RESULTS
> >      group by ASMT_CODE) as tmp1
> >   natural join
> >     (select ASMT_CODE, count(*) as PASSED from RESULTS
> >      where STATUS='PASSED' group by ASMT_CODE) as tmp2
> 
> BTW, although this is a fine example of how to avoid using temp tables,
> it's not such a great solution to the original problem.  What happens
> if there are no 'PASSED' entries at all for a given ASMT_CODE?  You
> probably won't want that ASMT_CODE to disappear from your report ---
> but it will disappear in the join.  We could fix this with a left join
> and some hackery to deal with the resulting NULL values for PASSED,
> but now things are getting ugly.  Time to try something different:
> 
> select ASMT_CODE, PASSED, TOTAL, PASSED::float4/TOTAL::float4 as PCT
> from
>     (select ASMT_CODE,
>             count(*) as TOTAL,
>             sum(CASE WHEN STATUS='PASSED' THEN 1 ELSE 0 END) as PASSED
>      from RESULTS group by ASMT_CODE) as tmp1
> 
> Here we use the sub-select only as a way of labeling the count() and
> sum() results so that we don't have to write and compute them twice.
> You could write it as a simple one-level SELECT if you didn't mind
> that redundancy.
> 
> regards, tom lane
> 


---------------------------(end of broadcast)---------------------------
TIP 5: Have you checked our extensive FAQ?

http://www.postgresql.org/users-lounge/docs/faq.html

Reply via email to