-
Notifications
You must be signed in to change notification settings - Fork 161
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
Best practice to handle "no old tuple data for UPDATE in table"? #283
Comments
@qianl15 there are a few cases related to this message. Read about REPLICA IDENTITY. Postgres writes the information (old tuple) in the WAL that identifies the row that it is updating or deleting. This message generally means: a. REPLICA IDENTITY DEFAULT: your table does not contain a primary key. That's the common case. If it is case (a) and you don't want to add a primary key, you have 2 options:
|
Thanks @eulerto for your quick response! Just to clarify that my table contains a primary key and uses REPLICA IDENTITY DEFAULT. In my test, I insert 10,000 rows into that table, peek changes, export changes to another database, and finally advance the replication slot. I repeat this test process many times a day, but this empty identity issue only happens once every few days. More precisely, occasionally only one out of thousands of update records would have an empty identity field. The table looks like this:
My workload simply updates the The peek slot command I used:
where I limit to peek up to 5000 changes each time. Environment: RDS Postgres 16.1 |
What's your Postgres version? Are you using the latest wal2json version? What's the SQL command to advance the replication slot? Did you observe any pattern from the missing old tuples? Could you share a test case that we can reproduce the issue? (Even if the test case takes several hour to reproduce.) |
Postgres version: PostgreSQL 16.1 on x86_64-pc-linux-gnu, compiled by gcc (GCC) 7.3.1 20180712 (Red Hat 7.3.1-12), 64-bit Advance slot command: I didn't see any particular pattern as it appears to happen rarely at random intervals. I will try to reproduce on my end as well. The actual test depends on a larger internal system on our side, but here's the simplified description of it.
|
This only occurred once since I first reported, even though the test continuously runs every hour. Another observation: if I run Is there any other traces I can provide to help figure out the issue? |
I need a test case. Maybe the WAL records might be useful. Use |
Hello! I will get back to you in a bit regarding the In this particular case, no |
Hi @eulerto here's the
The Postgres log:
But when I retried |
The only explanation for the OIDs in Lines 2453 to 2462 in 75629c2
The |
What would be the cause for a And retrying |
See RelationCacheInvalidate. You should also check inval.c. Logical replication processes some invalidation messages when calls AcceptInvalidationMessages. This function removes some catalog caches and relation cache that are not useful anymore. It also rebuilds the entries that are still useful. The only workaround is to retry |
Hello, I've been using wal2json to export changes from a Postgres instance. I use
pg_logical_slot_peek_changes
to obtain changes and thenpg_replication_slot_advance
to advance the slot separately. However, very occasionally I would get ano old tuple data for UPDATE in table
warning message emitted from wal2json, and the update record would have an empty identity field.I found the source code that emits this message, but I wonder why could it happen? If this happens, should I retry
pg_logical_slot_peek_changes
again? What is the best practice to handle this situation?I also couldn't find a way to reproduce this issue. This happens randomly once every few days on a database with low load.
Any help would be appreciated. Thanks!
The text was updated successfully, but these errors were encountered: