Thread: pg_dump 'die_on_errors'
The default setting of 'false' is a pain. And the fact it can't be changed by an option is even more of a pain. Any objections to adding an option to pg_restore to allow 'die_on_errors' to be set to 'true'? -D(?) --die-on-errors ---------------------------------------------------------------- Philip Warner | __---_____ Albatross Consulting Pty. Ltd. |----/ - \ (A.B.N. 75 008 659 498) | /(@) ______---_ Tel: (+61) 0500 83 82 81 | _________ \ Fax: (+61) 03 5330 3172 | ___________ | Http://www.rhyme.com.au | / \| | --________-- PGP key available upon request, | / and from pgp.mit.edu:11371 |/
Dear Philip, > The default setting of 'false' is a pain. And the fact it can't be > changed by an option is even more of a pain. Any objections to adding an > option to pg_restore to allow 'die_on_errors' to be set to 'true'? If I remember correctly, I'm the one who implemented that ignore error feature so that pg_restore auto-connection behaves as pg_restore|psql. Before that, the result was different whether you would pipe or you would connect, so it was somehow also a pain... because a non-super user could not really use it to restore a base for himself has some commands would fail and stop the processing. I implemented it so that it is easy to add an option to change the behavior, but in the end it was decided that the option would wait for more motivation. Maybe the time has come;-) BTW, Why is the default behavior such a pain? -- Fabien Coelho - coelho@cri.ensmp.fr
Philip Warner <pjw@rhyme.com.au> writes: > The default setting of 'false' is a pain. And the fact it can't be changed > by an option is even more of a pain. Any objections to adding an option to > pg_restore to allow 'die_on_errors' to be set to 'true'? If you like, but that change was deliberate and the result of considerable experience that says die_on_errors is NOT the right behavior for pg_restore. regards, tom lane
At 02:33 AM 12/08/2004, Fabien COELHO wrote: >Maybe the time has come;-) Sounds good to me. We've had the original behaviour since 7.1, I can understand there may be a desire to make it consistent with the carr-on-regardless behaviour of psql, but changing it in one release without the ability to revert to old behaviour is not ideal. >BTW, Why is the default behavior such a pain? I expect a script (shell, perl, or sql) to die when it hits an error; carr-on-regardless is IMO dangerous and just a hangover from piping to psql. One possible problem is illustrated by: - dump a db - use pg_restore in 'create' mode - for some reason DB creation fails result: template1 (or other DB) ends up with junk. Or ends up with deleted tables if the initial connection was to a db with the same table names. One of my motivations in doing the original pg_dump restructure and custom dump format was to allow for better error handling during a restore. ---------------------------------------------------------------- Philip Warner | __---_____ Albatross Consulting Pty. Ltd. |----/ - \ (A.B.N. 75 008 659 498) | /(@) ______---_ Tel: (+61) 0500 83 82 81 | _________ \ Fax: (+61) 03 5330 3172 | ___________ | Http://www.rhyme.com.au | / \| | --________-- PGP key available upon request, | / and from pgp.mit.edu:11371 |/
At 02:31 AM 12/08/2004, Tom Lane wrote: >result of >considerable experience that says die_on_errors is NOT the right >behavior for pg_restore. Can you point me to examples? Is it just an expectation problem that could be fixed with better docs? I tend to expect scripts to die when they encounter an error. ---------------------------------------------------------------- Philip Warner | __---_____ Albatross Consulting Pty. Ltd. |----/ - \ (A.B.N. 75 008 659 498) | /(@) ______---_ Tel: (+61) 0500 83 82 81 | _________ \ Fax: (+61) 03 5330 3172 | ___________ | Http://www.rhyme.com.au | / \| | --________-- PGP key available upon request, | / and from pgp.mit.edu:11371 |/
Philip Warner <pjw@rhyme.com.au> writes: > At 02:31 AM 12/08/2004, Tom Lane wrote: >> result of >> considerable experience that says die_on_errors is NOT the right >> behavior for pg_restore. > Can you point me to examples? Trawl the archives for pg_restore complaints ... but basically the point is that if you fail to restore object N, that doesn't mean you should refuse to even try to restore the objects after it. A typical example is that ALTER OWNER TO fails because the original owner doesn't exist in the new DB. There is no reason here not to keep plugging. If you abort, the user will have to erase the DB, add the user (whether he wants to or not, and whether he has the privileges to or not), and start over. If you don't abort, the worst case is that he has to do exactly that anyway; but he may not care, and even if he does care it may be a lot faster to fix things by hand afterwards. It probably would be a good idea to try to fix things to make the restore operation less noisy (eg, ditch all the NOTICEs about creating indexes) so that people could see the actual errors more easily. That's not at all the same thing as putting in die-on-error, though. regards, tom lane
Tom Lane wrote: > Philip Warner <pjw@rhyme.com.au> writes: > > At 02:31 AM 12/08/2004, Tom Lane wrote: > >> result of > >> considerable experience that says die_on_errors is NOT the right > >> behavior for pg_restore. > > > Can you point me to examples? > > Trawl the archives for pg_restore complaints ... but basically the point > is that if you fail to restore object N, that doesn't mean you should > refuse to even try to restore the objects after it. A typical example > is that ALTER OWNER TO fails because the original owner doesn't exist in > the new DB. There is no reason here not to keep plugging. If you > abort, the user will have to erase the DB, add the user (whether he > wants to or not, and whether he has the privileges to or not), and start > over. If you don't abort, the worst case is that he has to do exactly > that anyway; but he may not care, and even if he does care it may be a > lot faster to fix things by hand afterwards. > > It probably would be a good idea to try to fix things to make the > restore operation less noisy (eg, ditch all the NOTICEs about creating > indexes) so that people could see the actual errors more easily. That's > not at all the same thing as putting in die-on-error, though. Set client_min_messages to WARNING? -- Bruce Momjian | http://candle.pha.pa.us pgman@candle.pha.pa.us | (610) 359-1001+ If your life is a hard drive, | 13 Roberts Road + Christ can be your backup. | Newtown Square, Pennsylvania19073
At 01:27 PM 12/08/2004, Bruce Momjian wrote: >Set client_min_messages to WARNING? Sounds like a plan. ---------------------------------------------------------------- Philip Warner | __---_____ Albatross Consulting Pty. Ltd. |----/ - \ (A.B.N. 75 008 659 498) | /(@) ______---_ Tel: (+61) 0500 83 82 81 | _________ \ Fax: (+61) 03 5330 3172 | ___________ | Http://www.rhyme.com.au | / \| | --________-- PGP key available upon request, | / and from pgp.mit.edu:11371 |/
At 02:32 PM 12/08/2004, Philip Warner wrote: >At 01:27 PM 12/08/2004, Bruce Momjian wrote: >Set client_min_messages to WARNING? > >Sounds like a plan. Attached patch sets client_min_messages as above and gives some context to errors messages, eg: pg_restore: [archiver (db)] Error from TOC Entry 19; 1255 16438403 FUNCTION foo() pjw pg_restore: [archiver (db)] could not execute query: ERROR: no schema has been selected to create in pg_restore: [archiver (db)] could not execute query: ERROR: schema "public" does not exist pg_restore: [archiver (db)] Error from TOC Entry 1475; 0 0 ACL public postgres pg_restore: [archiver (db)] could not execute query: ERROR: schema "public" does not exist pg_restore: [archiver (db)] could not execute query: ERROR: schema "public" does not exist pg_restore: [archiver (db)] could not execute query: ERROR: schema "public" does not exist pg_restore: [archiver (db)] could not execute query: ERROR: schema "public" does not exist ---------------------------------------------------------------- Philip Warner | __---_____ Albatross Consulting Pty. Ltd. |----/ - \ (A.B.N. 75 008 659 498) | /(@) ______---_ Tel: (+61) 0500 83 82 81 | _________ \ Fax: (+61) 03 5330 3172 | ___________ | Http://www.rhyme.com.au | / \| | --________-- PGP key available upon request, | / and from pgp.mit.edu:11371 |/
Attachment
Philip Warner <pjw@rhyme.com.au> writes: > Attached patch sets client_min_messages as above and gives some > context to errors messages, eg: > pg_restore: [archiver (db)] Error from TOC Entry 19; 1255 16438403 FUNCTION foo() pjw > pg_restore: [archiver (db)] could not execute query: ERROR: no schema has been selected to create in It'd be substantially *more* helpful if it reported the failing command. (The TOC entry label is not of interest to anyone except pg_dump hackers such as yourself.) I went around a release or so back and made sure that pg_dump would always give the text of a failed query, but I forgot to consider pg_restore :-( regards, tom lane
At 01:32 AM 16/08/2004, Tom Lane wrote: >It'd be substantially *more* helpful if it reported the failing command. They are two different problems; the TOC entry is important for any multiline command or to rerun the command easily later. Whereas displaying the failed SQL command is a matter of fixing the error messages. The latter is complicated by failed COPY commands which, with die-on-errors off, results in the data being processed as a command, so dumping the command will dump all of the data. In the case of long commands, should the whole command be dumped? eg. (eg. several pages of function definition). In the case of the COPY command, I'm not sure what to do. Obviously, it would be best to avoid sending the data, but the data and command are combined (from memory). Also, the 'data' may be in the form of INSERT statements. Attached patch produces the first 125 chars of the command: pg_restore: [archiver (db)] Error while PROCESSING TOC: pg_restore: [archiver (db)] Error from TOC Entry 26; 1255 16449270 FUNCTION plpgsql_call_handler() pjw pg_restore: [archiver (db)] could not execute query: ERROR: function "plpgsql_call_handler" already exists with same argument types Command was: CREATE FUNCTION plpgsql_call_handler() RETURNS language_handler AS '/var/lib/pgsql-8.0b1/lib/plpgsql', 'plpgsql_call_han... pg_restore: [archiver (db)] Error from TOC Entry 27; 1255 16449271 FUNCTION plpgsql_validator(oid) pjw pg_restore: [archiver (db)] could not execute query: ERROR: function "plpgsql_validator" already exists with same argument types Command was: CREATE FUNCTION plpgsql_validator(oid) RETURNS void AS '/var/lib/pgsql-8.0b1/lib/plpgsql', 'plpgsql_validator' LANGU... ---------------------------------------------------------------- Philip Warner | __---_____ Albatross Consulting Pty. Ltd. |----/ - \ (A.B.N. 75 008 659 498) | /(@) ______---_ Tel: (+61) 0500 83 82 81 | _________ \ Fax: (+61) 03 5330 3172 | ___________ | Http://www.rhyme.com.au | / \| | --________-- PGP key available upon request, | / and from pgp.mit.edu:11371 |/
Attachment
Your patch has been added to the PostgreSQL unapplied patches list at: http://momjian.postgresql.org/cgi-bin/pgpatches It will be applied as soon as one of the PostgreSQL committers reviews and approves it. --------------------------------------------------------------------------- Philip Warner wrote: > At 01:32 AM 16/08/2004, Tom Lane wrote: > >It'd be substantially *more* helpful if it reported the failing command. > > They are two different problems; the TOC entry is important for any > multiline command or to rerun the command easily later. > > Whereas displaying the failed SQL command is a matter of fixing the error > messages. > > The latter is complicated by failed COPY commands which, with die-on-errors > off, results in the data being processed as a command, so dumping the > command will dump all of the data. > > In the case of long commands, should the whole command be dumped? eg. (eg. > several pages of function definition). > > In the case of the COPY command, I'm not sure what to do. Obviously, it > would be best to avoid sending the data, but the data and command are > combined (from memory). Also, the 'data' may be in the form of INSERT > statements. > > Attached patch produces the first 125 chars of the command: > > pg_restore: [archiver (db)] Error while PROCESSING TOC: > pg_restore: [archiver (db)] Error from TOC Entry 26; 1255 16449270 FUNCTION > plpgsql_call_handler() pjw > pg_restore: [archiver (db)] could not execute query: ERROR: function > "plpgsql_call_handler" already exists with same argument types > Command was: CREATE FUNCTION plpgsql_call_handler() RETURNS > language_handler > AS '/var/lib/pgsql-8.0b1/lib/plpgsql', 'plpgsql_call_han... > pg_restore: [archiver (db)] Error from TOC Entry 27; 1255 16449271 FUNCTION > plpgsql_validator(oid) pjw > pg_restore: [archiver (db)] could not execute query: ERROR: function > "plpgsql_validator" already exists with same argument types > Command was: CREATE FUNCTION plpgsql_validator(oid) RETURNS void > AS '/var/lib/pgsql-8.0b1/lib/plpgsql', 'plpgsql_validator' > LANGU... > > > > > > ---------------------------------------------------------------- > Philip Warner | __---_____ > Albatross Consulting Pty. Ltd. |----/ - \ > (A.B.N. 75 008 659 498) | /(@) ______---_ > Tel: (+61) 0500 83 82 81 | _________ \ > Fax: (+61) 03 5330 3172 | ___________ | > Http://www.rhyme.com.au | / \| > | --________-- > PGP key available upon request, | / > and from pgp.mit.edu:11371 |/ [ Attachment, skipping... ] > > ---------------------------(end of broadcast)--------------------------- > TIP 5: Have you checked our extensive FAQ? > > http://www.postgresql.org/docs/faqs/FAQ.html -- Bruce Momjian | http://candle.pha.pa.us pgman@candle.pha.pa.us | (610) 359-1001+ If your life is a hard drive, | 13 Roberts Road + Christ can be your backup. | Newtown Square, Pennsylvania19073
Patch applied. Thanks. --------------------------------------------------------------------------- Philip Warner wrote: > At 01:32 AM 16/08/2004, Tom Lane wrote: > >It'd be substantially *more* helpful if it reported the failing command. > > They are two different problems; the TOC entry is important for any > multiline command or to rerun the command easily later. > > Whereas displaying the failed SQL command is a matter of fixing the error > messages. > > The latter is complicated by failed COPY commands which, with die-on-errors > off, results in the data being processed as a command, so dumping the > command will dump all of the data. > > In the case of long commands, should the whole command be dumped? eg. (eg. > several pages of function definition). > > In the case of the COPY command, I'm not sure what to do. Obviously, it > would be best to avoid sending the data, but the data and command are > combined (from memory). Also, the 'data' may be in the form of INSERT > statements. > > Attached patch produces the first 125 chars of the command: > > pg_restore: [archiver (db)] Error while PROCESSING TOC: > pg_restore: [archiver (db)] Error from TOC Entry 26; 1255 16449270 FUNCTION > plpgsql_call_handler() pjw > pg_restore: [archiver (db)] could not execute query: ERROR: function > "plpgsql_call_handler" already exists with same argument types > Command was: CREATE FUNCTION plpgsql_call_handler() RETURNS > language_handler > AS '/var/lib/pgsql-8.0b1/lib/plpgsql', 'plpgsql_call_han... > pg_restore: [archiver (db)] Error from TOC Entry 27; 1255 16449271 FUNCTION > plpgsql_validator(oid) pjw > pg_restore: [archiver (db)] could not execute query: ERROR: function > "plpgsql_validator" already exists with same argument types > Command was: CREATE FUNCTION plpgsql_validator(oid) RETURNS void > AS '/var/lib/pgsql-8.0b1/lib/plpgsql', 'plpgsql_validator' > LANGU... > > > > > > ---------------------------------------------------------------- > Philip Warner | __---_____ > Albatross Consulting Pty. Ltd. |----/ - \ > (A.B.N. 75 008 659 498) | /(@) ______---_ > Tel: (+61) 0500 83 82 81 | _________ \ > Fax: (+61) 03 5330 3172 | ___________ | > Http://www.rhyme.com.au | / \| > | --________-- > PGP key available upon request, | / > and from pgp.mit.edu:11371 |/ [ Attachment, skipping... ] > > ---------------------------(end of broadcast)--------------------------- > TIP 5: Have you checked our extensive FAQ? > > http://www.postgresql.org/docs/faqs/FAQ.html -- Bruce Momjian | http://candle.pha.pa.us pgman@candle.pha.pa.us | (610) 359-1001 + If your life is a hard drive, | 13 Roberts Road + Christ can be your backup. | Newtown Square, Pennsylvania 19073