Re: Do not INSERT if UPDATE fails

From: Alexander Farber <alexander(dot)farber(at)gmail(dot)com>
To:
Cc: pgsql-general <pgsql-general(at)postgresql(dot)org>
Subject: Re: Do not INSERT if UPDATE fails
Date: 2017-08-04 12:10:09
Message-ID: CAADeyWiPqdg1padJE_eRr4AbWqeTvOJnpwymZyZJjgcEpqujZw@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

Hello, I have followed David's suggestion (thank you!) -

On Wed, Aug 2, 2017 at 6:40 PM, David G. Johnston <
david(dot)g(dot)johnston(at)gmail(dot)com> wrote:

> On Wed, Aug 2, 2017 at 8:58 AM, Alexander Farber <
> alexander(dot)farber(at)gmail(dot)com> wrote:
>
>> However if the user record is not found or the user already has vip_until
>> >= CURRENT_TIMESTAMP (i.e. the user has already purchased "vip status") I
>> would like to cancel the INSERT.
>>
>>
> ​You can "join" two DDL commands by using a Common Table Expression (CTE)
> (i.e., WITH / SELECT)​. You would need to make it so the UPDATE happens
> first and if there are no results the INSERT simply becomes a no-op.
>
>
and the following works (if I change the function return type to VOID):

CREATE OR REPLACE FUNCTION words_buy_vip(
in_sid text,
in_social integer,
in_tid text,
in_item text,
in_price float,
in_ip inet)
RETURNS void AS
$func$
WITH cte AS (
UPDATE words_users u
SET vip_until = CURRENT_TIMESTAMP + interval '1 year'
FROM words_social s
WHERE s.sid = in_sid
AND s.social = in_social
AND u.uid = s.uid
AND (u.vip_until IS NULL OR u.vip_until <
CURRENT_TIMESTAMP)
RETURNING
u.uid AS uid,
in_sid AS sid,
in_social AS social,
in_tid AS tid,
in_price AS price,
in_ip AS ip
)
INSERT INTO words_payments (
sid,
social,
tid,
paid,
price,
ip
) SELECT
sid,
social,
tid,
CURRENT_TIMESTAMP,
price,
ip
FROM cte
-- RETURNING uid;

$func$ LANGUAGE sql;

But I wonder how to return the uid in the above statement?

(my original function returned integer uid)

Regards
Alex

In response to

Browse pgsql-general by date

  From Date Subject
Next Message armand pirvu 2017-08-04 12:21:10 Re: hot standby questions
Previous Message k b 2017-08-04 06:01:18 Re: cast issue in WITH RECURION