Joins of data-modifying CTE with the target table

From: Alex Bolenok <quassnoi(at)gmail(dot)com>
To: pgsql-general(at)lists(dot)postgresql(dot)org
Subject: Joins of data-modifying CTE with the target table
Date: 2023-04-19 15:37:37
Message-ID: CAMX8OqKTEVZSyi2ZXD9Z_ZV717FwDwx4-OB=4xH1Q9Z885VmDg@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

Hi list,

This popped up yesterday during a discussion at the Boston PostgreSQL group
meetup, and Jesper Pedersen had advised that I post it here.

Imagine this setup:

CREATE TABLE IF NOT EXISTS mytable (id BIGSERIAL PRIMARY KEY, value TEXT
NOT NULL);

WITH insert_cte AS
(
INSERT
INTO mytable (value)
VALUES ('test')
RETURNING
*
)
SELECT mytable.*
FROM insert_cte
JOIN mytable
USING (id);

This query will return nothing, even though people would expect it to
return the newly inserted record.

This is just a minimally reproducible example, in which you can easily work
around the problem just by getting rid of the join to mytable. But during
my consulting career, I've seen people try putting together more complex
queries using the same pattern, and this always comes as a surprise.

I get why it's not working (because the statement is not allowed to see the
tuples with its own cmin), but I was wondering if it was worth it at least
to spell it out explicitly in the documentation.

Right now the documentation says:

https://www.postgresql.org/docs/15/queries-with.html#QUERIES-WITH-MODIFYING

RETURNING data is the only way to communicate changes between different
> WITH sub-statements and the main query

which I don't think is covering the JOIN issue (after all, I am using the
RETURNING clause to communicate with the main query).

Can we please add this example to the documentation? I can do the wording
if that's something worth adding.

Thank you!

Responses

Browse pgsql-general by date

  From Date Subject
Next Message Adrian Klaver 2023-04-19 15:41:18 Re: COPY RETURNING?
Previous Message Erik Wienhold 2023-04-19 14:51:33 Re: psql:t_mstr.sql:994: ERROR: function to_char(numeric) does not exist