Thread: Coalesce/Join/Entries may not exist.

Coalesce/Join/Entries may not exist.

From
"James Taylor"
Date:
I've got three tables, I'll shorten the columns down just so you get the
idea:

lists
-----------
id|order_id

list_results
------------
id|lid|total

orders
------------
id|max

All of the columns are int's.  What I'm trying to do is something like:

select (o.max-coalesce(sum(lr.total),0)) from orders o,list_results lr
where lr.l_id in (select  l.id from lists l, orders o where l.order_id=X and o.id=l.order_id)
group by o.max

This would, in theory, return a number which should be
o.total-sum(lr.total)

The problem is, there may not be any data in list_results OR lists
regarding the order ID.  If data from list_results.total exists, and is
referencing lists.id, which in turn is referencing orders.id through
lists.order_id, return o.max-lr.total.  If data from list_results or
lists DOESN'T exist, I would just want to go ahead and return
orders.max.  I was hoping the coalesce would be able to do this, but it
doesn't.  The subquery is in there because frankly I'm not sure how to
do multiple left joins, which I think would have to exist.  The easy way
out for me here I think would be to make list_results.order_id and leave
lists out of it, but then I'd have redundant data in two tables.  Any
suggestions on this one?




Re: Coalesce/Join/Entries may not exist.

From
Rod Taylor
Date:
On Mon, 2003-06-09 at 08:00, James Taylor wrote:
> I've got three tables, I'll shorten the columns down just so you get the
> idea:
>
> lists
> -----------
> id|order_id
>
> list_results
> ------------
> id|lid|total
>
> orders
> ------------
> id|max
>
> All of the columns are int's.  What I'm trying to do is something like:
>
> select (o.max-coalesce(sum(lr.total),0)) from orders o,list_results lr
> where lr.l_id in (select
>    l.id from lists l, orders o where l.order_id=X and o.id=l.order_id)
> group by o.max
>
> This would, in theory, return a number which should be
> o.total-sum(lr.total)
>
> The problem is, there may not be any data in list_results OR lists
> regarding the order ID.  If data from list_results.total exists, and is
> referencing lists.id, which in turn is referencing orders.id through
> lists.order_id, return o.max-lr.total.  If data from list_results or
> lists DOESN'T exist, I would just want to go ahead and return
> orders.max.  I was hoping the coalesce would be able to do this, but it
> doesn't.  The subquery is in there because frankly I'm not sure how to
> do multiple left joins, which I think would have to exist.  The easy way
> out for me here I think would be to make list_results.order_id and leave
> lists out of it, but then I'd have redundant data in two tables.  Any
> suggestions on this one?

Multiple left outer joins?

FROM <tab>
LEFT OUTER JOIN <tab2> USING (<column>)
LEFT OUTER JOIN <tab3> USING (<column>)
WHERE ...

In your case,


SELECT (o.max - coalesce(sum(lr.total), 0)) FROM orders
LEFT OUTER JOIN lists ON (orders.id = lists.order_id)
LEFT OUTER JOIN list_results ON (lists.id = list_results.l_id)
GROUP BY o.max

But I'm not sure if that accomplishes what you're looking for or not.

--
Rod Taylor <rbt@rbt.ca>

PGP Key: http://www.rbt.ca/rbtpub.asc