Thread: Unique key constraint Issue
Hello,
We have postgresql servers with PostgreSQL 13.10 on Ubuntu release 22.04.
The issue is a unique key constraint with two columns one is character another is integer. At some point the unique key did not work as I see duplicate values with these two columns combination and it happened on multiple servers on multiple databases on same table with same unique key. I tried db dump and restore but the key is failing to create when restore with duplicate value errors.
Output should be consistent across servers below query o/p
SELECT conname, pg_get_constraintdef(oid)
FROM pg_constraint
WHERE conrelid = 'your table name'::regclass AND contype = 'u';
FROM pg_constraint
WHERE conrelid = 'your table name'::regclass AND contype = 'u';
(different datatype combine in UK is not an issue). This issue may not happen in asynchronous, log shipping or streaming replication. In logical replication it may create problem.
On Mon, Nov 25, 2024 at 12:01 PM shashidhar Reddy <shashidharreddy001@gmail.com> wrote:
Hello,We have postgresql servers with PostgreSQL 13.10 on Ubuntu release 22.04.The issue is a unique key constraint with two columns one is character another is integer. At some point the unique key did not work as I see duplicate values with these two columns combination and it happened on multiple servers on multiple databases on same table with same unique key. I tried db dump and restore but the key is failing to create when restore with duplicate value errors.
Hi Ajit,
Thank you for your reply!
The result of the query is same across all servers and yes streaming replication does not have any issue but the question is how did duplicate values entered when there unique key in place.
On Mon, 25 Nov, 2024, 1:21 pm ajit wangkhem, <ajit.wangkhem@gmail.com> wrote:
Output should be consistent across servers below query o/pSELECT conname, pg_get_constraintdef(oid)
FROM pg_constraint
WHERE conrelid = 'your table name'::regclass AND contype = 'u';(different datatype combine in UK is not an issue). This issue may not happen in asynchronous, log shipping or streaming replication. In logical replication it may create problem.On Mon, Nov 25, 2024 at 12:01 PM shashidhar Reddy <shashidharreddy001@gmail.com> wrote:Hello,We have postgresql servers with PostgreSQL 13.10 on Ubuntu release 22.04.The issue is a unique key constraint with two columns one is character another is integer. At some point the unique key did not work as I see duplicate values with these two columns combination and it happened on multiple servers on multiple databases on same table with same unique key. I tried db dump and restore but the key is failing to create when restore with duplicate value errors.
If all syntax correct while creating unique key or composite unique key than there is no chances of fail. In my experience I m facing same issue but it’s rear case, if any extra space in data (insert query) than duplicate data inserted. Please chk thorough insert query . May be the issue not sure. In oracle extra space omit but in Postgres it would not.
From: shashidhar Reddy <shashidharreddy001@gmail.com>
Sent: Monday, November 25, 2024 2:14:37 PM
To: ajit wangkhem <ajit.wangkhem@gmail.com>
Cc: pgsql-general <pgsql-general@postgresql.org>
Subject: Re: Unique key constraint Issue
Sent: Monday, November 25, 2024 2:14:37 PM
To: ajit wangkhem <ajit.wangkhem@gmail.com>
Cc: pgsql-general <pgsql-general@postgresql.org>
Subject: Re: Unique key constraint Issue
Hi Ajit,
Thank you for your reply!
The result of the query is same across all servers and yes streaming replication does not have any issue but the question is how did duplicate values entered when there unique key in place.
On Mon, 25 Nov, 2024, 1:21 pm ajit wangkhem, <ajit.wangkhem@gmail.com> wrote:
Output should be consistent across servers below query o/pSELECT conname, pg_get_constraintdef(oid)
FROM pg_constraint
WHERE conrelid = 'your table name'::regclass AND contype = 'u';(different datatype combine in UK is not an issue). This issue may not happen in asynchronous, log shipping or streaming replication. In logical replication it may create problem.On Mon, Nov 25, 2024 at 12:01 PM shashidhar Reddy <shashidharreddy001@gmail.com> wrote:Hello,We have postgresql servers with PostgreSQL 13.10 on Ubuntu release 22.04.The issue is a unique key constraint with two columns one is character another is integer. At some point the unique key did not work as I see duplicate values with these two columns combination and it happened on multiple servers on multiple databases on same table with same unique key. I tried db dump and restore but the key is failing to create when restore with duplicate value errors.
On 11/25/24 00:44, shashidhar Reddy wrote: > Hi Ajit, > > Thank you for your reply! > > The result of the query is same across all servers and yes streaming > replication does not have any issue but the question is how did > duplicate values entered when there unique key in place. Corrupted index? Have you tried doing a REINDEX? -- Adrian Klaver adrian.klaver@aklaver.com
shashidhar Reddy <shashidharreddy001@gmail.com> writes: > The issue is a unique key constraint with two columns one is character > another is integer. At some point the unique key did not work as I see > duplicate values with these two columns combination and it happened on > multiple servers on multiple databases on same table with same unique key. If the table has existed for some time (like, across updates of the underlying operating system) then your problem likely traces to changes in the OS' sorting rules for character strings: https://wiki.postgresql.org/wiki/Locale_data_changes Such a change causes the unique key's index to be out of sort order and thus effectively corrupt from PG's viewpoint: searches may or may not find an entry that is there. Once that happens it's pretty easy for duplicate entries to get added. The fix is to REINDEX affected indexes. But if you already have duplicate entries in the table, you'll need to correct them before REINDEX will succeed. regards, tom lane
Hi Adrian,
Thank you for your response.
I don't think index corrupted as I can generate the ddl script from the index and the index is still in use when we query.
To rebuild the index we are still removing duplicate entries. But nothing found in logs.
On Mon, 25 Nov, 2024, 9:30 pm Adrian Klaver, <adrian.klaver@aklaver.com> wrote:
On 11/25/24 00:44, shashidhar Reddy wrote:
> Hi Ajit,
>
> Thank you for your reply!
>
> The result of the query is same across all servers and yes streaming
> replication does not have any issue but the question is how did
> duplicate values entered when there unique key in place.
Corrupted index?
Have you tried doing a REINDEX?
--
Adrian Klaver
adrian.klaver@aklaver.com
On 11/25/24 19:07, shashidhar Reddy wrote: > Hi Adrian, > > Thank you for your response. > > I don't think index corrupted as I can generate the ddl script from the What DDL script? > index and the index is still in use when we query. See Tom Lanes post for more detail. Short version the index will still 'work' except for the part where it lets in duplicate entries. > To rebuild the index we are still removing duplicate entries. But > nothing found in logs. > > On Mon, 25 Nov, 2024, 9:30 pm Adrian Klaver, <adrian.klaver@aklaver.com > <mailto:adrian.klaver@aklaver.com>> wrote: > > On 11/25/24 00:44, shashidhar Reddy wrote: > > Hi Ajit, > > > > Thank you for your reply! > > > > The result of the query is same across all servers and yes streaming > > replication does not have any issue but the question is how did > > duplicate values entered when there unique key in place. > > Corrupted index? > > Have you tried doing a REINDEX? > > > -- > Adrian Klaver > adrian.klaver@aklaver.com <mailto:adrian.klaver@aklaver.com> > -- Adrian Klaver adrian.klaver@aklaver.com
Thank you Tom!
The issue is with OS upgrade we could able replicate it.
On Mon, 25 Nov, 2024, 9:32 pm Tom Lane, <tgl@sss.pgh.pa.us> wrote:
shashidhar Reddy <shashidharreddy001@gmail.com> writes:
> The issue is a unique key constraint with two columns one is character
> another is integer. At some point the unique key did not work as I see
> duplicate values with these two columns combination and it happened on
> multiple servers on multiple databases on same table with same unique key.
If the table has existed for some time (like, across updates of the
underlying operating system) then your problem likely traces to
changes in the OS' sorting rules for character strings:
https://wiki.postgresql.org/wiki/Locale_data_changes
Such a change causes the unique key's index to be out of sort order
and thus effectively corrupt from PG's viewpoint: searches may or
may not find an entry that is there. Once that happens it's pretty
easy for duplicate entries to get added.
The fix is to REINDEX affected indexes. But if you already have
duplicate entries in the table, you'll need to correct them before
REINDEX will succeed.
regards, tom lane
Thank you Adrian.
We replicated the issue with OS upgrade.
On Tue, 26 Nov, 2024, 11:06 am Adrian Klaver, <adrian.klaver@aklaver.com> wrote:
On 11/25/24 19:07, shashidhar Reddy wrote:
> Hi Adrian,
>
> Thank you for your response.
>
> I don't think index corrupted as I can generate the ddl script from the
What DDL script?
> index and the index is still in use when we query.
See Tom Lanes post for more detail. Short version the index will still
'work' except for the part where it lets in duplicate entries.
> To rebuild the index we are still removing duplicate entries. But
> nothing found in logs.
>
> On Mon, 25 Nov, 2024, 9:30 pm Adrian Klaver, <adrian.klaver@aklaver.com
> <mailto:adrian.klaver@aklaver.com>> wrote:
>
> On 11/25/24 00:44, shashidhar Reddy wrote:
> > Hi Ajit,
> >
> > Thank you for your reply!
> >
> > The result of the query is same across all servers and yes streaming
> > replication does not have any issue but the question is how did
> > duplicate values entered when there unique key in place.
>
> Corrupted index?
>
> Have you tried doing a REINDEX?
>
>
> --
> Adrian Klaver
> adrian.klaver@aklaver.com <mailto:adrian.klaver@aklaver.com>
>
--
Adrian Klaver
adrian.klaver@aklaver.com