I have a table
CREATE TABLE IF NOT EXISTS club.climbers
(
climber_id SERIAL PRIMARY KEY,
climber_first_name VARCHAR(20) NOT NULL,
climber_last_name VARCHAR(30) NOT NULL,
climber_full_name TEXT GENERATED ALWAYS AS (climber_first_name || ' ' || climber_last_name) STORED NOT NULL,
sex_id INTEGER NOT NULL REFERENCES club.sex,
climber_date_birth DATE NOT NULL,
climber_phone VARCHAR(20) NOT NULL,
postal_code_id INTEGER REFERENCES club.postal_codes,
street VARCHAR(75) NOT NULL,
building VARCHAR(5) NOT NULL,
apartment VARCHAR(5),
full_address TEXT GENERATED ALWAYS AS (street || ',' || building || '-' || apartment) STORED
);
But apartment
can be NULL and then full_address
would be NULL too. I need to ignore NULL values from apartment
.
I tried to use CONCAT
and COALESCE
, but I don't know how to suppress a dangling '-' when apartment
is NULL.
One option is to use CASE
expression:
full_address TEXT GENERATED ALWAYS AS
(street || ',' || case when apartment is not null then building || '-' || apartment
else building end) STORED
which - for inserts as
insert into climbers (street, building, apartment) values ('Wall street', 'A', '10');
insert into climbers (street, building, apartment) values ('5th Avenue', 'B', null);
results in
street building apartment full_address
Wall street A 10 Wall street,A-10
5th Avenue B null 5th Avenue,B
See fiddle.