> On Jul 8, 2021, at 20:32, Nagaraj Raj <nagaraj...@yahoo.com> wrote:
>
> My apologies for making confusion with new thread. Yes its same issue related
> to earlier post.
>
> I was trying to figure out how to ensure unique values for columns
> (billing_account_guid, ban). If i add partition key to constraint , it wont
> be possible what im looking for.
>
> My use case as below
>
> INSERT INTO t1 SELECT * from t2 ON CONFLICT (billing_account_guid,ban) DO
> UPDATE SET something…
>
> Or
>
> INSERT INTO t1 SELECT * from t2 ON CONFLICT constraint (pk or
> uk)(billing_account_guid,ban) DO UPDATE SET something…
Right now, PostgreSQL does not support unique indexes on partitioned tables
(that operate across all partitions) unless the partition key is included in
the index definition. If it didn't have that requirement, it would have to
independently (and in a concurrency-supported way) scan every partition
individually to see if there is a duplicate key violation in any of the
partitions, and the machinery to do that does not exist right now.
If the goal is to make sure there is only one (billing_account_guid, ban, date)
combination across the entire partition set, you can create an index unique
index on the partitioned set as (billing_account_guid, ban, date), and INSERT
... ON CONFLICT DO NOTHING works properly then.
If the goal is to make sure there is only one (billing_account_uid, ban) in any
partition regardless of date, you'll need to do something more sophisticated to
make sure that two sessions don't insert an (billing_account_uid, ban) value
into two different partitions. This isn't a great fit for table partitioning,
and you might want to reconsider if partitioning the table is the right answer
here. If you *must* have table partitioning, a possible algorithm is:
-- Start a transaction
-- Hash the (billing_account_uid, ban) key into a 64 bit value.
-- Use that 64 bit value as a key to a call to pg_advisory_xact_lock() [1] to,
in essence, create a signal to any other transaction attempting to insert that
pair that it is being modified.
-- SELECT on that pair to make sure one does not already exist.
-- If one does not, do the INSERT.
-- Commit, which releases the advisory lock.
This doesn't provide quite the same level of uniqueness that a cross-partition
index would, but if this is the only code path that does the INSERT, it should
keep duplicate from showing up in different partitions.
[1]
https://www.postgresql.org/docs/current/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS