Thread: how do I do dump and restore without bugging with constraint?
1- Dump schema.
pg_dump -h server_source -U username -s -Fp -f schema.sql database
2- Dump data only.
pg_dump -h server_source -U username -a -Fc -f data.dmp database
3- Modify schema.
4- Restore schema in new host.
psql -U username -d database -h server_destination -f modified_schema.sql
5- Restore data disabling triggers
pg_restore -h server_destination -U username -d database --disable-triggers -a data.dmp
-----Original Message-----
From: Net Tree Inc. <nettreeinc@gmail.com>
To: pgsql-admin@postgresql.org, pgsql-general@postgresql.org
Subject: [ADMIN] how do I do dump and restore without bugging with constraint?
Date: Tue, 23 Feb 2010 12:50:27 +0800
Hi all,
I am dumping both schema and data from old database to new one. The new database schema is somehow contain slightly different schema then the old one. When I do restore it shown alot errors related with constraints. How can I dump and to restore from old to new without dealing with constraint and just forces data dump to where it suppose to belong?
Steven
Using pg_dump from your new host (that is, newer version)
1- Dump schema.
pg_dump -h server_source -U username -s -Fp -f schema.sql database
2- Dump data only.
pg_dump -h server_source -U username -a -Fc -f data.dmp database
3- Modify schema.
4- Restore schema in new host.
psql -U username -d database -h server_destination -f modified_schema.sql
5- Restore data disabling triggers
pg_restore -h server_destination -U username -d database --disable-triggers -a data.dmp
-----Original Message-----
From: Net Tree Inc. <nettreeinc@gmail.com>
To: pgsql-admin@postgresql.org, pgsql-general@postgresql.org
Subject: [ADMIN] how do I do dump and restore without bugging with constraint?
Date: Tue, 23 Feb 2010 12:50:27 +0800
Hi all,
I am dumping both schema and data from old database to new one. The new database schema is somehow contain slightly different schema then the old one. When I do restore it shown alot errors related with constraints. How can I dump and to restore from old to new without dealing with constraint and just forces data dump to where it suppose to belong?
--
---------------------------------------
Steven Huang
To avoid contraints you have to use –disable-triggers flag during restore. That is done in step 5.
In order to modify schema you have to locate what is failing. So, first restore old schema without modifications in your new database, watch for errors and fix them.
For example:
psql -U username -d database -h server_destination -f schema.sql 2>import_error.log
You’ll find all import errors in import_error.log. Since you are only going to launch an schema definition, It will only take a few seconds, so test all you need.
After locating errors, open schema.sql with your favorite editor and fix them. There are minor changes between postgresql versions and you’ll probably have no problems in order to fix them, or ask here if you have many problems.
Once fixed, you will have your new modified_schema.sql and you can proceed with steps 4 and 5.
Obviously, if errors are related to indexes, functions, broken dependencies, etc without touching table definitions, everything will go well. However if you have to modify table definitions, you will probably not be able to import data in that new schema and it will be necesary to look for a new strategy.
De: Net Tree Inc. [mailto:nettreeinc@gmail.com]
Enviado el: martes, 23 de febrero de 2010 17:36
Para: Iñigo Martinez Lasala
CC: pgsql-admin@postgresql.org; pgsql-general@postgresql.org
Asunto: Re: [ADMIN] how do I do dump and restore without bugging with constraint?
Thanks. Is it by doing these steps I can avoid constrain restriction? for step 3, how should I modify the schema? and which schema? the target DB's schema that I am trying to dump the schema and data in? But this is the problem, I am not sure whats different between the two schema's, there are just too many tables to check. What's your tips?
Steven
On Tue, Feb 23, 2010 at 7:03 PM, Iñigo Martinez Lasala <imartinez@vectorsf.com> wrote:
Using pg_dump from your new host (that is, newer version)
1- Dump schema.
pg_dump -h server_source -U username -s -Fp -f schema.sql database
2- Dump data only.
pg_dump -h server_source -U username -a -Fc -f data.dmp database
3- Modify schema.
4- Restore schema in new host.
psql -U username -d database -h server_destination -f modified_schema.sql
5- Restore data disabling triggers
pg_restore -h server_destination -U username -d database --disable-triggers -a data.dmp
-----Original Message-----
From: Net Tree Inc. <nettreeinc@gmail.com>
To: pgsql-admin@postgresql.org, pgsql-general@postgresql.org
Subject: [ADMIN] how do I do dump and restore without bugging with constraint?
Date: Tue, 23 Feb 2010 12:50:27 +0800
Hi all,
I am dumping both schema and data from old database to new one. The new database schema is somehow contain slightly different schema then the old one. When I do restore it shown alot errors related with constraints. How can I dump and to restore from old to new without dealing with constraint and just forces data dump to where it suppose to belong?
--
---------------------------------------
Steven Huang
- Quote: "However if you have to modify table definitions, you will probably not be able to import data in that new schema and it will be necesary to look for a new strategy."
- For schema, are we talking about attribute columns (structure of table) and "table definitions" referraled you talking about things like "data types"?
- If error came out during restore are related with table definitions then it's probably no help?
- DEFERRABLE
NOT DEFERRABLE- DEFERRABLE
This controls whether the constraint can be deferred. A constraint that is not deferrable will be checked immediately after every command. Checking of constraints that are deferrable can be postponed until the end of the transaction (using the SET CONSTRAINTS command). NOT DEFERRABLE is the default. Only foreign key constraints currently accept this clause. All other constraint types are not deferrable.
- INITIALLY IMMEDIATE
INITIALLY DEFERRED If a constraint is deferrable, this clause specifies the default time to check the constraint. If the constraint is INITIALLY IMMEDIATE, it is checked after each statement. This is the default. If the constraint is INITIALLY DEFERRED, it is checked only at the end of the transaction. The constraint check time can be altered with the SET CONSTRAINTS command.
To avoid contraints you have to use –disable-triggers flag during restore. That is done in step 5.
In order to modify schema you have to locate what is failing. So, first restore old schema without modifications in your new database, watch for errors and fix them.
For example:
psql -U username -d database -h server_destination -f schema.sql 2>import_error.log
You’ll find all import errors in import_error.log. Since you are only going to launch an schema definition, It will only take a few seconds, so test all you need.
After locating errors, open schema.sql with your favorite editor and fix them. There are minor changes between postgresql versions and you’ll probably have no problems in order to fix them, or ask here if you have many problems.
Once fixed, you will have your new modified_schema.sql and you can proceed with steps 4 and 5.
Obviously, if errors are related to indexes, functions, broken dependencies, etc without touching table definitions, everything will go well. However if you have to modify table definitions, you will probably not be able to import data in that new schema and it will be necesary to look for a new strategy.
De: Net Tree Inc. [mailto:nettreeinc@gmail.com]
Enviado el: martes, 23 de febrero de 2010 17:36
Para: Iñigo Martinez Lasala
CC: pgsql-admin@postgresql.org; pgsql-general@postgresql.org
Asunto: Re: [ADMIN] how do I do dump and restore without bugging with constraint?
Thanks. Is it by doing these steps I can avoid constrain restriction? for step 3, how should I modify the schema? and which schema? the target DB's schema that I am trying to dump the schema and data in? But this is the problem, I am not sure whats different between the two schema's, there are just too many tables to check. What's your tips?
StevenOn Tue, Feb 23, 2010 at 7:03 PM, Iñigo Martinez Lasala <imartinez@vectorsf.com> wrote:
Using pg_dump from your new host (that is, newer version)
1- Dump schema.
pg_dump -h server_source -U username -s -Fp -f schema.sql database
2- Dump data only.
pg_dump -h server_source -U username -a -Fc -f data.dmp database
3- Modify schema.
4- Restore schema in new host.
psql -U username -d database -h server_destination -f modified_schema.sql
5- Restore data disabling triggers
pg_restore -h server_destination -U username -d database --disable-triggers -a data.dmp
-----Original Message-----
From: Net Tree Inc. <nettreeinc@gmail.com>
To: pgsql-admin@postgresql.org, pgsql-general@postgresql.org
Subject: [ADMIN] how do I do dump and restore without bugging with constraint?
Date: Tue, 23 Feb 2010 12:50:27 +0800
Hi all,
I am dumping both schema and data from old database to new one. The new database schema is somehow contain slightly different schema then the old one. When I do restore it shown alot errors related with constraints. How can I dump and to restore from old to new without dealing with constraint and just forces data dump to where it suppose to belong?
--
---------------------------------------
Steven Huang
--
---------------------------------------
Steven Huang
- DEFERRABLE
NOT DEFERRABLE- DEFERRABLE
This controls whether the constraint can be deferred. A constraint that is not deferrable will be checked immediately after every command. Checking of constraints that are deferrable can be postponed until the end of the transaction (using the SET CONSTRAINTS command). NOT DEFERRABLE is the default. Only foreign key constraints currently accept this clause. All other constraint types are not deferrable.
- INITIALLY IMMEDIATE
INITIALLY DEFERRED If a constraint is deferrable, this clause specifies the default time to check the constraint. If the constraint is INITIALLY IMMEDIATE, it is checked after each statement. This is the default. If the constraint is INITIALLY DEFERRED, it is checked only at the end of the transaction. The constraint check time can be altered with the SET CONSTRAINTS command.
Hi all,I am dumping both schema and data from old database to new one. The new database schema is somehow contain slightly different schema then the old one. When I do restore it shown alot errors related with constraints. How can I dump and to restore from old to new without dealing with constraint and just forces data dump to where it suppose to belong?
--
---------------------------------------
Steven Huang
Re: [GENERAL] how do I do dump and restore without bugging with constraint?
I have tried like this. But in my case it is not working when trying to access a column that is not exists in the table. Example: CREATE TABLE test_str (te_id text); INSERT INTO test_str VALUES ('a'); INSERT INTO test_str VALUES ('b'); INSERT INTO test_str VALUES ('c'); SELECT t.name from test_str t; I am getting error like this. ERROR: column t.name does not exist --- On Wed, 24/2/10, Net Tree Inc. <nettreeinc@gmail.com> wrote:
|
Your Mail works best with the New Yahoo Optimized IE8. Get it NOW!.
If you change a varchar to text or a integer to numeric, you will not have any problems. But if you add extra columns, for example, data import will fail.
So, if you are planning to perform and in-depth modification of your data structure, do it in your server before export, or at least perform those changes that modify data structure of your schema.
-----Original Message-----
From: Net Tree Inc. <nettreeinc@gmail.com>
To: Iñigo Martinez Lasala <imartinez@vectorsf.com>
Cc: pgsql-admin@postgresql.org, pgsql-general@postgresql.org
Subject: Re: [ADMIN] how do I do dump and restore without bugging with constraint?
Date: Wed, 24 Feb 2010 09:56:35 +0800
- Quote: "However if you have to modify table definitions, you will probably not be able to import data in that new schema and it will be necesary to look for a new strategy."
For schema, are we talking about attribute columns (structure of table) and "table definitions" referraled you talking about things like "data types"?
DEFERRABLE
NOT DEFERRABLE
This controls whether the constraint can be deferred. A constraint that is not deferrable will be checked immediately after every command. Checking of constraints that are deferrable can be postponed until the end of the transaction (using the SET CONSTRAINTS command). NOT DEFERRABLE is the default. Only foreign key constraints currently accept this clause. All other constraint types are not deferrable.
INITIALLY DEFERRED
If a constraint is deferrable, this clause specifies the default time to check the constraint. If the constraint is INITIALLY IMMEDIATE, it is checked after each statement. This is the default. If the constraint is INITIALLY DEFERRED, it is checked only at the end of the transaction. The constraint check time can be altered with the SET CONSTRAINTS command.
On Wed, Feb 24, 2010 at 1:49 AM, Iñigo Martinez Lasala <imartinez@vectorsf.com> wrote:
To avoid contraints you have to use –disable-triggers flag during restore. That is done in step 5.
In order to modify schema you have to locate what is failing. So, first restore old schema without modifications in your new database, watch for errors and fix them.
For example:
psql -U username -d database -h server_destination -f schema.sql 2>import_error.log
You’ll find all import errors in import_error.log. Since you are only going to launch an schema definition, It will only take a few seconds, so test all you need.
After locating errors, open schema.sql with your favorite editor and fix them. There are minor changes between postgresql versions and you’ll probably have no problems in order to fix them, or ask here if you have many problems.
Once fixed, you will have your new modified_schema.sql and you can proceed with steps 4 and 5.
Obviously, if errors are related to indexes, functions, broken dependencies, etc without touching table definitions, everything will go well. However if you have to modify table definitions, you will probably not be able to import data in that new schema and it will be necesary to look for a new strategy.
De: Net Tree Inc. [mailto:nettreeinc@gmail.com]
Enviado el: martes, 23 de febrero de 2010 17:36
Para: Iñigo Martinez Lasala
CC: pgsql-admin@postgresql.org; pgsql-general@postgresql.org
Asunto: Re: [ADMIN] how do I do dump and restore without bugging with constraint?
Thanks. Is it by doing these steps I can avoid constrain restriction? for step 3, how should I modify the schema? and which schema? the target DB's schema that I am trying to dump the schema and data in? But this is the problem, I am not sure whats different between the two schema's, there are just too many tables to check. What's your tips?
Steven
On Tue, Feb 23, 2010 at 7:03 PM, Iñigo Martinez Lasala <imartinez@vectorsf.com> wrote:
Using pg_dump from your new host (that is, newer version)
1- Dump schema.
pg_dump -h server_source -U username -s -Fp -f schema.sql database
2- Dump data only.
pg_dump -h server_source -U username -a -Fc -f data.dmp database
3- Modify schema.
4- Restore schema in new host.
psql -U username -d database -h server_destination -f modified_schema.sql
5- Restore data disabling triggers
pg_restore -h server_destination -U username -d database --disable-triggers -a data.dmp
-----Original Message-----
From: Net Tree Inc. <nettreeinc@gmail.com>
To: pgsql-admin@postgresql.org, pgsql-general@postgresql.org
Subject: [ADMIN] how do I do dump and restore without bugging with constraint?
Date: Tue, 23 Feb 2010 12:50:27 +0800
Hi all,
I am dumping both schema and data from old database to new one. The new database schema is somehow contain slightly different schema then the old one. When I do restore it shown alot errors related with constraints. How can I dump and to restore from old to new without dealing with constraint and just forces data dump to where it suppose to belong?
--
---------------------------------------
Steven Huang
--
---------------------------------------
Steven Huang