Thread: Backup failure Postgres
Failed : pg_dump: error: Dumping the contents of table "botsession" failed: PQgetResult() failed. pg_dump: error: Error message from server: ERROR: canceling statement due to conflict with recovery DETAIL: User query might have needed to see row versions that must be removed. pg_dump: error: The command was: COPY public.botsession (id, userid, data, iscompressed) TO stdout;
I'm frequently facing the below error while performing backup. Someone please tell how solve this issues.Failed : pg_dump: error: Dumping the contents of table "botsession" failed: PQgetResult() failed. pg_dump: error: Error message from server: ERROR: canceling statement due to conflict with recovery DETAIL: User query might have needed to see row versions that must be removed. pg_dump: error: The command was: COPY public.botsession (id, userid, data, iscompressed) TO stdout;
As the error message says, your query was aborted due to it conflicting with recovery. There are many ways to deal with that. You could enable hot_standby_feedback on the replica. You could disconnect the replica from the master for the time the COPY takes (reset primary_conninfo). You could increase max_standby_streaming_delay. Perhaps you could also wrap the COPY operation in pg_wal_replay_pause() / pg_wal_replay_resume().On Thu, May 23, 2024 at 11:59 AM Jethish Jethish <jethish777@gmail.com> wrote:I'm frequently facing the below error while performing backup. Someone please tell how solve this issues.Failed : pg_dump: error: Dumping the contents of table "botsession" failed: PQgetResult() failed. pg_dump: error: Error message from server: ERROR: canceling statement due to conflict with recovery DETAIL: User query might have needed to see row versions that must be removed. pg_dump: error: The command was: COPY public.botsession (id, userid, data, iscompressed) TO stdout;
Hi Torsten,I have tried by increasing the max_standby_streaming_delay but I'm facing lag issues on the replica server.When i increase the max_standby_streaming_delay even if a query runs for 2 minutes I'm facing lag issues for 2 minutes.Please suggest here.Data size is 3TBOn Thu, May 23, 2024, 3:53 PM Torsten Förtsch <tfoertsch123@gmail.com> wrote:As the error message says, your query was aborted due to it conflicting with recovery. There are many ways to deal with that. You could enable hot_standby_feedback on the replica. You could disconnect the replica from the master for the time the COPY takes (reset primary_conninfo). You could increase max_standby_streaming_delay. Perhaps you could also wrap the COPY operation in pg_wal_replay_pause() / pg_wal_replay_resume().On Thu, May 23, 2024 at 11:59 AM Jethish Jethish <jethish777@gmail.com> wrote:I'm frequently facing the below error while performing backup. Someone please tell how solve this issues.Failed : pg_dump: error: Dumping the contents of table "botsession" failed: PQgetResult() failed. pg_dump: error: Error message from server: ERROR: canceling statement due to conflict with recovery DETAIL: User query might have needed to see row versions that must be removed. pg_dump: error: The command was: COPY public.botsession (id, userid, data, iscompressed) TO stdout;
On 2024-May-23, Jethish Jethish wrote: > I have tried by increasing the max_standby_streaming_delay but I'm facing > lag issues on the replica server. > > When i increase the max_standby_streaming_delay even if a query runs for 2 > minutes I'm facing lag issues for 2 minutes. You could use a separate replica for backups, with a larger max delay. > Data size is 3TB I think pg_dump is not an appropriate tool for backups on an instance this size. Have you considered using pgbarman or such, instead? -- Álvaro Herrera PostgreSQL Developer — https://www.EnterpriseDB.com/