Volatile functions in WITH

From: Ben Morrow <ben(at)morrow(dot)me(dot)uk>
To: pgsql-sql(at)postgresql(dot)org
Subject: Volatile functions in WITH
Date: 2013-02-17 07:58:59
Message-ID: 20130217075859.GE8029@anubis.morrow.me.uk
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

Suppose I run the following query:

WITH "exp" AS (
DELETE FROM "item" i
USING "item_expired" e
WHERE e.oref = i.ref
AND i.basket = $1
RETURNING i.basket, e.oref, e.nref, i.count, e.msg
),
"subst" AS (
INSERT INTO "item" ("basket", "ref", "count")
SELECT e.basket, e.nref, e.count
FROM "exp" e
WHERE e.nref IS NOT NULL
)
SELECT DISTINCT e.msg
FROM "exp" e

This is a very convenient and somewhat more flexible alternative to
INSERT... DELETE RETURNING (which doesn't work). However, the "item"
table has a unique constraint on (basket, ref), so sometimes I need to
update instead of insert; to handle this I have a VOLATILE function,
add_item. Unfortunately, if I call it the obvious way

WITH "exp" AS ( -- as before
),
"subst" AS (
SELECT add_item(e.basket, e.nref, e.count)
FROM "exp" e
WHERE e.nref IS NOT NULL
)
SELECT DISTINCT e.msg
FROM "exp" e

then the planner sees that the results of "subst" are not used, and
doesn't include it in the query plan at all.

Is there any way I can tell WITH that add_item is actually a data-
modifying statement? Adding FOR UPDATE doesn't seem to help (I didn't
really expect it would.)

Alternatively, are either of these safe (that is, are they guaranteed to
call the function once for every row returned by "exp", even if the
DISTINCT ends up eliminating some of those rows)?

WITH "exp" AS ( -- as before
), "subst" AS ( -- SELECT add_item(...) as before
)
SELECT DISTINCT e.msg
FROM "exp" e
LEFT JOIN "subst" s ON FALSE

WITH "exp" AS ( -- as before
)
SELECT DISTINCT s.msg
FROM (
SELECT e.msg, CASE
WHEN e.nref IS NULL THEN NULL
ELSE add_item(e.basket, e.nref, e.count)
END "subst"
) s

I don't like the second alternative much, but I could live with it if I
had to.

Ben

Responses

Browse pgsql-sql by date

  From Date Subject
Next Message Ben Morrow 2013-02-17 09:44:15 Re: upsert doesn't seem to work..
Previous Message Adam 2013-02-15 20:31:36 Perform Function When The Rows Of A View Change