create table OFFER (
OFFER_ID bigint generated always as identity primary key,
PRODUCT_ID bigint not null,
ARCHIVED boolean default false not null,
PRICE decimal(9,2) not null
);
create unique index IDX_OFFER_UNIQUE_PRODUCT
on OFFER (PRODUCT_ID)
where not ARCHIVED;
insert into OFFER (PRODUCT_ID, ARCHIVED, PRICE) values (1, false, 18.95);
insert into OFFER (PRODUCT_ID, ARCHIVED, PRICE) values (1, true, 17.95);
insert into OFFER (PRODUCT_ID, ARCHIVED, PRICE) values (1, true, 16.95);
-- Next fails due to second record for PRODUCT_ID=1 and ARCHIVED=false:
insert into OFFER (PRODUCT_ID, ARCHIVED, PRICE) values (1, false, 19.95);
-- Statement failed, SQLSTATE = 23000
-- attempt to store duplicate value (visible to active transactions) in unique index "IDX_OFFER_UNIQUE_PRODUCT"
-- -Problematic key value is ("PRODUCT_ID" = 1)