Re: Synchronizing a table that is two different databases : Need to dump a table a insert from db1 and change the insert statements into UPDATE statements

From: Chris Curvey <chris(at)chriscurvey(dot)com>
To: Khangelani Gama <kgama(at)argility(dot)com>, pgsql <pgsql-general(at)postgresql(dot)org>
Subject: Re: Synchronizing a table that is two different databases : Need to dump a table a insert from db1 and change the insert statements into UPDATE statements
Date: 2014-03-27 13:07:44
Message-ID: CADfwSsBv2yoJm2P5gUu9HvvVSb42ZmrRGQ8ZtD6wY-eWREYmhw@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

On Thu, Mar 27, 2014 at 6:16 AM, Khangelani Gama <kgama(at)argility(dot)com> wrote:

> Hi all
>
>
>
> Synchronizing a *table* that is in two different databases(e.g *db1 and
> db2*).
>
>
>
> Please help me with this. I need to dump a table as INSERTS from db1
> (postgres 9.1.2) and change the INSERT statements into UPDATE statements in
> order to apply that change in *db2(postgres 8.3.0.112)* which has the
> same *table* as *db1*. Where the record does not exist I need to insert
> that record. There is more than 1000 INSERTS I need to convert to UPDATES
> for the same table. Please help .
>
>
>
> *Example:*
>
>
>
> Below it's the INSERT from postgres 9.1.2 DATABASE which should convert to
> UPDATE statement.
>
>
>
> INSERT INTO* table* (br_cde, br_desc, br_active, br_closed, grp_cde,
> ctry_cde, state_cde, br_addr_line1, br_addr_line2, br_addr_line3,
> br_addr_line4, br_addr_cde, br_post_addr_line1, br_post_addr_line2,
> br_post_addr_line3, br_post_addr_line4, br_post_addr_cde, br_phone,
> tax_cde, br_server_name, br_lang_ind, bureau_cde, br_risk_typ_cde,
> br_access_ccd, br_access_bureau, br_network_active, br_desc_short,
> br_is_trading, br_is_test, br_is_nomodem, br_is_whs, br_is_merch,
> br_is_cco, br_is_central, br_is_merch_active, br_central_brn, br_merch_brn,
> br_cco_brn, br_cgo_brn, br_cluster_brn, br_contact, br_tollfree, br_fax,
> br_telex, br_email, ops_cde, ops_director, br_cmpy_reg, br_tax_reg,
> audit_id, comp_cde, br_batch, br_release_pilot_type, br_is_order_active,
> bnk_id, br_class_cde, br_erp_xref, br_to_open, br_to_close, br_comments,
> br_is_hire, br_is_voucher, br_is_clear_center, br_is_headoffice,
> br_is_nsp_active, usr_pass_history, br_network_protocol,
> br_gen_ins_central_brn, br_cpi_ins_central_brn, br_rsc_area, br_rsc_perc,
> br_switch_deduc, br_tvlic_dealer_no, br_cco_followup, br_triad_live,
> br_do_cust_locking, br_is_rainbow, br_nca_live, br_ncr_reg_no, prov_cde,
> br_is_data_archive, br_icu_brn, br_living_expenses_live, br_ab_dorder_live,
> br_ab_receipts_active, br_spiv_max_alloc_perc, br_merger_brn,
> br_dep_bnk_acc, br_merchant_number, br_goods_ins_live, br_cgs_connection,
> whs_cde, br_crm_brn, subscription_active, br_prn_doc_default_active,
> br_use_jms, br_sso_active, br_paym8_properties, creditors_supp_no_prefix,
> br_block_debtors_obo, ccms_branch, br_is_ccms_live, ceres_conv_flag,
> cims_branch, br_is_cims_live, br_accept_sql_releases) VALUES ('9940',
> 'ELLERINES CENTRAL - 9940', true, NULL, '1', 'BAF', 'BAF', '209 SMIT
> STREET', 'BRA', 'Jgf', 'Jrg', '3025', '209 SMIT STREET', 'BRA', 'Jrg',
> NULL, '2017', '(4562) 712 1300', '1', 'dfgike.com', 'ENG', 'ITC', 'L',
> false, false, false, 'BATCH - 9940', false, false, false, false, false,
> false, true, false, '9940', NULL, NULL, '10.52.1.31', '9940', 'DOUG', NULL,
> '(4562) 712 1300' ', NULL, NULL, '001', NULL, '1969/02687/07', NULL, 0,
> NULL, '9940', NULL, false, NULL, NULL, NULL, NULL, NULL, NULL, false,
> false, false, false, false, 30, 'WS2~WS2', '1002', '1002', NULL, NULL,
> false, NULL, NULL, false, true, false, true, 'NC', NULL, true, NULL, true,
> true, NULL, NULL, NULL, NULL, NULL, true, 'oracle_live', NULL, NULL, true,
> NULL, true, false, NULL, NULL, NULL, NULL, NULL, NULL, NULL, false, false);
>
>
>

(For clarity, I'm going to call the table in question "foo".)

Option 1: If you just want to do a full copy of db1.foo to db2.foo, then
do that. Dump foo from db1, truncate foo in db2 and load db2.foo from the
dump. But you might not be able to do that (foreign keys and such). In
that case..

Option 2: Dump the table from db1, then load it into a table with a
different name ("bar") in db2. Then you can do this:

begin;

update foo
set br_desc = bar.br_desc
, br_active = bar.br_active
(rest of columns)
where foo.br_cde = bar.br_cde;

insert into foo (br_cde, br_desc, br_active, ...)
select br_cde, br_desc, br_active, ....
from bar
where not exists
( select *
from foo
where foo.br_cde = bar.br_cde);

commit;

In response to

Responses

Browse pgsql-general by date

  From Date Subject
Next Message Gauthier, Dave 2014-03-27 13:23:18 Re: Synchronizing a table that is two different databases : Need to dump a table a insert from db1 and change the insert statements into UPDATE statements
Previous Message Michael Paquier 2014-03-27 12:29:06 Re: Trimming transaction logs after extended WAL archive failures