Re: How do I upsert depending on a second table?

From: Adrian Klaver <adrian(dot)klaver(at)aklaver(dot)com>
To: Samuel Marks <samuelmarks(at)gmail(dot)com>
Cc: Juan Rodrigo Alejandro Burgos Mella <rodrigoburgosmella(at)gmail(dot)com>, pgsql-general <pgsql-general(at)lists(dot)postgresql(dot)org>
Subject: Re: How do I upsert depending on a second table?
Date: 2025-09-26 22:17:02
Message-ID: 5a08b23d-3aa8-4b14-92c6-d595eeafba25@aklaver.com
Views: Whole Thread | Raw Message | Download mbox | Resend email
Thread:
Lists: pgsql-general

On 9/24/25 16:03, Adrian Klaver wrote:
> On 9/24/25 10:02, Samuel Marks wrote:
>> On Wed, Sep 24, 2025 at 10:13 AM Adrian Klaver

> I don't have enough experience with below to come up with an off the top
> of my head examples, but they look like they may offer alternatives.
>
> MERGE:
>
> https://www.postgresql.org/docs/current/sql-merge.html
>

First time working with MERGE, so approach the below with caution:

CREATE TABLE org
(
"name" VARCHAR(50) PRIMARY KEY,
owner VARCHAR(50) NOT NULL
);

CREATE TABLE repo
(
"id" INTEGER PRIMARY KEY,
full_name VARCHAR(255) UNIQUE NOT NULL,
org VARCHAR(50) NOT NULL REFERENCES org ("name")
);

INSERT INTO org(name, owner) VALUES ('org0', 'user0');

WITH t AS (SELECT
*
FROM
org
RIGHT JOIN
(values(0 , 'org0/name0 by wrong user', 'org0', 'wrong_user'))
AS v(id, full_name, org, user_name)
ON
org.name = v.org
AND
org.owner = v.user_name
)
MERGE INTO repo as r
USING t
ON
r.org = t.name

WHEN MATCHED AND t.id = r.id THEN
UPDATE SET (id, full_name, org) = (t.id, t.full_name, t.org)
WHEN NOT MATCHED AND t.user_name = COALESCE(t.owner, '') THEN
INSERT VALUES(t.id, t.full_name, t.org)

RETURNING r.*;

id | full_name | org
----+-----------+-----
(0 rows)

MERGE 0

select * from repo ;
id | full_name | org
----+-----------+-----

WITH t AS (SELECT
*
FROM
org
RIGHT JOIN
(values(0 , 'org0/name0 by right user', 'org0', 'user0'))
AS v(id, full_name, org, user_name)
ON
org.name = v.org
AND
org.owner = v.user_name
)
MERGE INTO repo as r
USING t
ON
r.org = t.name

WHEN MATCHED AND t.id = r.id THEN
UPDATE SET (id, full_name, org) = (t.id, t.full_name, t.org)
WHEN NOT MATCHED AND t.user_name = COALESCE(t.owner, '') THEN
INSERT VALUES(t.id, t.full_name, t.org)

RETURNING r.*;
id | full_name | org
----+--------------------------+------
0 | org0/name0 by right user | org0
(1 row)

MERGE 1

select * from repo ;
id | full_name | org
----+--------------------------+------
0 | org0/name0 by right user | org0

WITH t AS (SELECT
*
FROM
org
RIGHT JOIN
(values(0 , 'org0/name0 by right user update', 'org0', 'user0'))
AS v(id, full_name, org, user_name)
ON
org.name = v.org
AND
org.owner = v.user_name
)
MERGE INTO repo as r
USING t
ON
r.org = t.name

WHEN MATCHED AND t.id = r.id THEN
UPDATE SET (id, full_name, org) = (t.id, t.full_name, t.org)
WHEN NOT MATCHED AND t.user_name = COALESCE(t.owner, '') THEN
INSERT VALUES(t.id, t.full_name, t.org)

RETURNING r.*;
id | full_name | org
----+---------------------------------+------
0 | org0/name0 by right user update | org0
(1 row)

select * from repo ;
id | full_name | org
----+---------------------------------+------
0 | org0/name0 by right user update | org0
(1 row)

--
Adrian Klaver
adrian(dot)klaver(at)aklaver(dot)com

In response to

Browse pgsql-general by date

  From Date Subject
Next Message Ron Johnson 2025-09-26 23:00:13 Re: Correct query for monitor
Previous Message veem v 2025-09-26 20:15:29 Re: Correct query for monitor