From: | Alban Hertroys <haramrae(at)gmail(dot)com> |
---|---|
To: | Hemil Ruparel <hemilruparel2002(at)gmail(dot)com> |
Cc: | pgsql-general(at)postgresql(dot)org |
Subject: | Re: How to update a table with the result of deleting rows in another table |
Date: | 2020-10-06 12:45:52 |
Message-ID: | DAF94EE1-F4B3-44ED-95B9-ED007B64F363@gmail.com |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-general |
> On 6 Oct 2020, at 7:37, Hemil Ruparel <hemilruparel2002(at)gmail(dot)com> wrote:
>
> I am trying to delete orders for a given customer on a given date and add the cost of those orders to credit for the customer.
>
> So far, I came up with this:
> ```
> with data as (
> delete from orders
> where customer_id = <customer id>
> and date = '2020-10-05' returning price
> ), total as (
> select sum(price) from data
> )
> update paymentdetail
> set temp_credit = temp_credit + (select * from total)
> where customer_id = <customer id>
> ```
>
> which works. but is there a better way to update one table using the result of deleting rows from another table given that I only want the aggregate of the result?
Adding the customer id to your returning clause and using update..from could help:
with data as (
delete from orders
where customer_id = <customer id>
returning customer_id, price
), total as (
select customer_id, sum(price) as total_price
from data
group by customer_id
)
update paymentdetail
set temp_credit = temp_credit + total.total_price
from total
where customer_id = total.customer_id
You could also do this using subqueries instead of CTE’s, that may perform better as CTE’s act as optimisation fences.
Alban Hertroys
--
If you can't see the forest for the trees,
cut the trees and you'll find there is no forest.
From | Date | Subject | |
---|---|---|---|
Next Message | Tony Shelver | 2020-10-06 14:33:29 | Re: What's your experience with using Postgres in IoT-contexts? |
Previous Message | Paul Förster | 2020-10-06 09:53:00 | Re: How to execute the sql file in PSQL |