Re: [GENERAL] Concatenating NULL with JSONB value return NULL - Mailing list pgsql-general

From Tom Lane
Subject Re: [GENERAL] Concatenating NULL with JSONB value return NULL
Date
Msg-id 21340.1482108388@sss.pgh.pa.us
Whole thread Raw
In response to Re: [GENERAL] Concatenating NULL with JSONB value return NULL  (Melvin Davidson <melvin6925@gmail.com>)
Responses Re: [GENERAL] Concatenating NULL with JSONB value return NULL
List pgsql-general
Melvin Davidson <melvin6925@gmail.com> writes:
> On Sun, Dec 18, 2016 at 6:08 PM, John R Pierce <pierce@hogranch.com> wrote:
>> On 12/18/2016 2:52 PM, Jong-won Choi wrote:
>>> I have a NULL-able JSONB type column and want to perform upsert,
>>> concatenating with the existing value.

>> NULL does not mean 'NO' value in SQL it means UNKNOWN value. sort of like
>> the 'indeterminate' in math.

> Have you tried using CASE?

> INSERT INTO Fan  (oid, campaigns, facts)  VALUES (189,'{"campaign-id":
> "12345"}','{"attended": false}')
> ON CONFLICT (oid)
> DO UPDATE SET campaigns = EXCLUDED.campaigns,
>               CASE WHEN fan.facts is NULL
>                    THEN facts = EXCLUDED.facts
>                    ELSE facts = fan.facts || EXCLUDED.facts
>                END
>     RETURNING *;

Another option is COALESCE:

...
DO UPDATE SET campaigns = EXCLUDED.campaigns,
              facts = COALESCE(fan.facts, '{}'::jsonb) || EXCLUDED.facts
...

I'd argue though that if you think this is okay, then you're abusing
NULL; that's supposed to mean "unknown", not "known to be empty".
It would be better to initialize the column to '{}' to begin with.

            regards, tom lane


pgsql-general by date:

Previous
From: Gavin Flower
Date:
Subject: Re: [GENERAL] About the MONEY type
Next
From: Rob Sargent
Date:
Subject: Re: [GENERAL] About the MONEY type