Обсуждение: Sequence Cycle question
PostgreSQL 16
Question on how Cycle works with example:
I have table X with a primary key ID which is an integer that uses a sequence.
Sequence Settings:
start_value=1
min_value=1
max_value=1,000,000
cycle=true
Use Case:
Table X has records that have been removed over time randomly. There are IDs that cover a wide range of values between 1 and 1,000,000.
When the primary key ID, which is a sequence, reaches 1,000,000 then the next sequence value will start back at 1.
What would happen if I had a primary key for ID of 5 still in use? When I reach 5 will the sequence skip that number and go to 6 instead?
Could you please add some text in the documentation to explain this Use Case? It seems very important.
Thanks,
Lance
"Campbell, Lance" <lance@illinois.edu> writes: > Table X has records that have been removed over time randomly. There are IDs that cover a wide range of values between1 and 1,000,000. > When the primary key ID, which is a sequence, reaches 1,000,000 then the next sequence value will start back at 1. > What would happen if I had a primary key for ID of 5 still in use? When I reach 5 will the sequence skip that number andgo to 6 instead? No, the sequence has no idea about what is in the table. It will generate "5" when it's time to, and then your insert will get a duplicate-key violation. You could work around that by retrying the insert, but it might be better to reconsider whether you want a cycling sequence for this application. regards, tom lane
Lets say I was to set the cycle=true. Once the IDs start back at 1, lets say we get to an ID of 5 where there is a duplicate. Is there a trigger or something else, that I could associate with the table that would "catch/detect" the insert error. If an error occurs it would then do a "fresh" insert with no specified ID so the sequence would naturally be incremented? I hope that made sense. Thanks, -----Original Message----- From: Tom Lane <tgl@sss.pgh.pa.us> Sent: Thursday, January 23, 2025 11:42 AM To: Campbell, Lance <lance@illinois.edu> Cc: pgsql-admin@postgresql.org Subject: Re: Sequence Cycle question "Campbell, Lance" <lance@illinois.edu> writes: > Table X has records that have been removed over time randomly. There are IDs that cover a wide range of values between1 and 1,000,000. > When the primary key ID, which is a sequence, reaches 1,000,000 then the next sequence value will start back at 1. > What would happen if I had a primary key for ID of 5 still in use? When I reach 5 will the sequence skip that number andgo to 6 instead? No, the sequence has no idea about what is in the table. It will generate "5" when it's time to, and then your insert willget a duplicate-key violation. You could work around that by retrying the insert, but it might be better to reconsider whether you want a cycling sequencefor this application. regards, tom lane
Lets say I was to set the cycle=true. Once the IDs start back at 1, lets say we get to an ID of 5 where there is a duplicate.
Is there a trigger or something else, that I could associate with the table that would "catch/detect" the insert error. If an error occurs it would then do a "fresh" insert with no specified ID so the sequence would naturally be incremented?
Lance,
Why can’t you change the max_value to 2,000,000 or higher? I can’t think of a reason if this will cause any other problems, including performance. Other please correct otherwise.
Thank you
Kam
From: David G. Johnston <david.g.johnston@gmail.com>
Sent: Thursday, January 23, 2025 12:59 PM
To: Campbell, Lance <lance@illinois.edu>
Cc: Tom Lane <tgl@sss.pgh.pa.us>; pgsql-admin@postgresql.org
Subject: [EXT] Re: Sequence Cycle question
External Email: Use caution with links and attachments. |
On Thu, Jan 23, 2025 at 11:47 AM Campbell, Lance <lance@illinois.edu> wrote:
Lets say I was to set the cycle=true. Once the IDs start back at 1, lets say we get to an ID of 5 where there is a duplicate.
Is there a trigger or something else, that I could associate with the table that would "catch/detect" the insert error. If an error occurs it would then do a "fresh" insert with no specified ID so the sequence would naturally be incremented?
You are really fighting against the design of the system here. I suggest you avoid doing inserts to this table concurrently and put logic in the insertion code to simply find what would be the next identifier and use it. Sequences are meant to be used for performance and simplicity - your requirements are incompatible with both.
The better option if you can manage it is to increase your identifier space to bigint and forget about wrap-around. Re-using identifiers is simply not a good practice.
David J.
That was just an example. I am reaching the max size of integers.
From: Wong, Kam Fook (TR Technology) <kamfook.wong@thomsonreuters.com>
Sent: Thursday, January 23, 2025 1:16 PM
To: David G. Johnston <david.g.johnston@gmail.com>; Campbell, Lance <lance@illinois.edu>
Cc: Tom Lane <tgl@sss.pgh.pa.us>; pgsql-admin@postgresql.org
Subject: RE: [EXT] Re: Sequence Cycle question
Lance,
Why can’t you change the max_value to 2,000,000 or higher? I can’t think of a reason if this will cause any other problems, including performance. Other please correct otherwise.
Thank you
Kam
From: David G. Johnston <david.g.johnston@gmail.com>
Sent: Thursday, January 23, 2025 12:59 PM
To: Campbell, Lance <lance@illinois.edu>
Cc: Tom Lane <tgl@sss.pgh.pa.us>; pgsql-admin@postgresql.org
Subject: [EXT] Re: Sequence Cycle question
External Email: Use caution with links and attachments. |
On Thu, Jan 23, 2025 at 11:47 AM Campbell, Lance <lance@illinois.edu> wrote:
Lets say I was to set the cycle=true. Once the IDs start back at 1, lets say we get to an ID of 5 where there is a duplicate.
Is there a trigger or something else, that I could associate with the table that would "catch/detect" the insert error. If an error occurs it would then do a "fresh" insert with no specified ID so the sequence would naturally be incremented?
You are really fighting against the design of the system here. I suggest you avoid doing inserts to this table concurrently and put logic in the insertion code to simply find what would be the next identifier and use it. Sequences are meant to be used for performance and simplicity - your requirements are incompatible with both.
The better option if you can manage it is to increase your identifier space to bigint and forget about wrap-around. Re-using identifiers is simply not a good practice.
David J.
Lance,
How about this?
1) Create a new column with bigint datatype (double the max limits of int).
2) Write a proc to copy the existing PK to this new column.
3) If #2 and #4 below have a big time gap, write a trigger to auto copy the existing PK to this new column for any new inserts/deletes/updates.
4) App deploy/changes to use the new PK/Bigint/column.
5) Then this will buy you time to consider other design options for PK.
Thank you
Kam
From: Campbell, Lance <lance@illinois.edu>
Sent: Thursday, January 23, 2025 1:24 PM
To: Wong, Kam Fook (TR Technology) <kamfook.wong@thomsonreuters.com>; David G. Johnston <david.g.johnston@gmail.com>
Cc: Tom Lane <tgl@sss.pgh.pa.us>; pgsql-admin@postgresql.org
Subject: RE: [EXT] Re: Sequence Cycle question
That was just an example. I am reaching the max size of integers.
From: Wong, Kam Fook (TR Technology) <kamfook.wong@thomsonreuters.com>
Sent: Thursday, January 23, 2025 1:16 PM
To: David G. Johnston <david.g.johnston@gmail.com>; Campbell, Lance <lance@illinois.edu>
Cc: Tom Lane <tgl@sss.pgh.pa.us>; pgsql-admin@postgresql.org
Subject: RE: [EXT] Re: Sequence Cycle question
Lance,
Why can’t you change the max_value to 2,000,000 or higher? I can’t think of a reason if this will cause any other problems, including performance. Other please correct otherwise.
Thank you
Kam
From: David G. Johnston <david.g.johnston@gmail.com>
Sent: Thursday, January 23, 2025 12:59 PM
To: Campbell, Lance <lance@illinois.edu>
Cc: Tom Lane <tgl@sss.pgh.pa.us>; pgsql-admin@postgresql.org
Subject: [EXT] Re: Sequence Cycle question
External Email: Use caution with links and attachments. |
On Thu, Jan 23, 2025 at 11:47 AM Campbell, Lance <lance@illinois.edu> wrote:
Lets say I was to set the cycle=true. Once the IDs start back at 1, lets say we get to an ID of 5 where there is a duplicate.
Is there a trigger or something else, that I could associate with the table that would "catch/detect" the insert error. If an error occurs it would then do a "fresh" insert with no specified ID so the sequence would naturally be incremented?
You are really fighting against the design of the system here. I suggest you avoid doing inserts to this table concurrently and put logic in the insertion code to simply find what would be the next identifier and use it. Sequences are meant to be used for performance and simplicity - your requirements are incompatible with both.
The better option if you can manage it is to increase your identifier space to bigint and forget about wrap-around. Re-using identifiers is simply not a good practice.
David J.
> On Jan 23, 2025, at 12:37 PM, Wong, Kam Fook (TR Technology) <kamfook.wong@thomsonreuters.com> wrote: > > 1) Create a new column with bigint datatype (double the max limits of int). Double the width, ~4,000,000,000 times max limit > ... > 5) Then this will buy you time to consider other design options for PK. Like, until the sun burns out and engulfs the earth ;-) -- Scott Ribe scott_ribe@elevated-dev.com https://www.linkedin.com/in/scottribe/