Tools to migrate with inserts

This commit is contained in:
Carlos Ruiz 2007-02-27 08:22:39 +00:00
parent 479bc28b99
commit dc0120c7a6
7 changed files with 454 additions and 0 deletions

View File

@ -0,0 +1,160 @@
CREATE OR REPLACE PROCEDURE generate_insert_as
AUTHID CURRENT_USER
AS
dbsource VARCHAR2 (30) := 'SOURCE';
dbtarget VARCHAR2 (30) := 'TARGET';
liscolcommon VARCHAR2 (4000);
liscoltarget VARCHAR2 (4000);
liscolsource VARCHAR2 (4000);
where_ids VARCHAR2 (4000);
insertstmt VARCHAR2 (4000);
deletestmt VARCHAR2 (4000);
hasclient BOOLEAN;
-- CREATE OR REPLACE DIRECTORY dir_tmp AS '/tmp'
-- grant execute on utl_file to target
f UTL_FILE.file_type;
BEGIN
f := UTL_FILE.fopen ('DIR_TMP', '04_InsertMigr.sql', 'w');
UTL_FILE.put_line (f, '-- Started ' || SYSDATE);
-- for each table common in source and target
FOR t IN (SELECT object_name AS table_name
FROM all_objects
WHERE owner = dbsource AND object_type = 'TABLE'
-- AND object_name = 'AD_ATTACHMENTNOTE'
INTERSECT
SELECT object_name
FROM all_objects
WHERE owner = dbtarget AND object_type = 'TABLE'
ORDER BY 1)
LOOP
liscolcommon := NULL;
liscoltarget := NULL;
liscolsource := NULL;
where_ids := NULL;
insertstmt := NULL;
hasclient := FALSE;
-- construct list of common columns
FOR c IN (SELECT column_name
FROM all_tab_columns
WHERE owner = dbsource AND table_name = t.table_name
INTERSECT
SELECT column_name
FROM all_tab_columns
WHERE owner = dbtarget AND table_name = t.table_name)
LOOP
IF liscolcommon IS NULL
THEN
liscolcommon := c.column_name;
ELSE
liscolcommon := liscolcommon || ',' || CHR (10) || c.column_name;
END IF;
IF c.column_name LIKE '%\_ID' ESCAPE '\'
THEN
IF where_ids IS NULL
THEN
where_ids := c.column_name || '>=1000000';
ELSE
where_ids :=
where_ids || ' OR ' || CHR (10) || c.column_name
|| '>=1000000';
END IF;
END IF;
IF c.column_name = 'AD_CLIENT_ID'
THEN
hasclient := TRUE;
END IF;
END LOOP;
-- construct list of columns only in target (to review how to fill them)
FOR c IN (SELECT column_name
FROM all_tab_columns
WHERE owner = dbtarget AND table_name = t.table_name
MINUS
SELECT column_name
FROM all_tab_columns
WHERE owner = dbsource AND table_name = t.table_name)
LOOP
IF liscoltarget IS NULL
THEN
liscoltarget := c.column_name;
ELSE
liscoltarget := liscoltarget || ', ' || c.column_name;
END IF;
END LOOP;
-- construct list of columns only in source (to review - data can be lost)
FOR c IN (SELECT column_name
FROM all_tab_columns
WHERE owner = dbsource AND table_name = t.table_name
MINUS
SELECT column_name
FROM all_tab_columns
WHERE owner = dbtarget AND table_name = t.table_name)
LOOP
IF liscoltarget IS NULL
THEN
liscoltarget := c.column_name;
ELSE
liscoltarget := liscoltarget || ', ' || c.column_name;
END IF;
END LOOP;
UTL_FILE.put_line (f, CHR (10) || '-- migrate table ' || t.table_name);
IF liscoltarget IS NOT NULL
THEN
UTL_FILE.put_line (f, '-- columns in target: ' || liscoltarget);
END IF;
IF liscolsource IS NOT NULL
THEN
UTL_FILE.put_line (f, '-- columns in source: ' || liscolsource);
END IF;
deletestmt :=
'DELETE FROM '
|| dbtarget
|| '.'
|| t.table_name
|| CASE
WHEN where_ids IS NOT NULL
THEN CHR (10) || 'WHERE (' || where_ids || ')'
END
|| ';'
|| CHR (10);
UTL_FILE.put_line (f, deletestmt);
insertstmt :=
'INSERT INTO '
|| dbtarget
|| '.'
|| t.table_name
|| '('
|| liscolcommon
|| ')'
|| CHR (10)
|| 'SELECT '
|| liscolcommon
|| ' FROM '
|| dbsource
|| '.'
|| t.table_name
|| CASE
WHEN where_ids IS NOT NULL AND hasclient
THEN CHR (10)
|| 'WHERE AD_CLIENT_ID<>11 AND ('
|| where_ids
|| ')'
WHEN where_ids IS NOT NULL AND NOT hasclient
THEN CHR (10) || 'WHERE (' || where_ids || ')'
END
|| ';';
UTL_FILE.put_line (f, insertstmt);
END LOOP;
UTL_FILE.put_line (f, '-- End ' || SYSDATE);
UTL_FILE.fclose (f);
END;

View File

@ -0,0 +1,4 @@
arreglar el script 04 para filtrar
ad_field -> Jasper Report
ad_column -> JasperReport
ad_element -> JasperReport

View File

@ -0,0 +1,11 @@
--------------------------------------------------------------------------
-- Play this script in COMPIERE252D@LINUXQSS/XE to make it look like SOURCE@LINUXQSS/XE
-- --
-- Please review the script before using it to make sure it won't --
-- cause any unacceptable data loss. --
-- --
-- COMPIERE252D@LINUXQSS/XE Schema Extracted by User COMPIERE252D
-- SOURCE@LINUXQSS/XE Schema Extracted by User COMPIERE252D
-- Here will be the generated statements with TOAD

View File

@ -0,0 +1,75 @@
/*************************************************************************
* The contents of this file are subject to the Compiere License. You may
* obtain a copy of the License at http://www.compiere.org/license.html
* Software is on an "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either
* express or implied. See the License for details. Code: Compiere ERP+CRM
* Copyright (C) 1999-2002 Jorg Janke, ComPiere, Inc. All Rights Reserved.
*************************************************************************
* $Id: DBA_Trg_Disable.sql,v 1.1 2006/04/21 17:51:58 jjanke Exp $
***
* Title: Disable all triggers and felf referencing constraints
* Description:
* - required for initial DB create
************************************************************************/
DECLARE
-- Trigger
CURSOR cur_trg
IS
SELECT trigger_name
FROM user_triggers
WHERE status <> 'DISABLED'
ORDER BY 1;
CURSOR cur_constraintr
IS
SELECT table_name, constraint_name
FROM user_constraints c
WHERE c.constraint_type <> 'P' AND c.status <> 'DISABLED'
ORDER BY 1;
CURSOR cur_constraintp
IS
SELECT table_name, constraint_name
FROM user_constraints c
WHERE c.constraint_type = 'P' AND c.status <> 'DISABLED'
ORDER BY 1;
v_cmd VARCHAR2 (256);
BEGIN
DBMS_OUTPUT.put_line ('Disabling:');
FOR t IN cur_trg
LOOP
DBMS_OUTPUT.put_line ('.. ' || t.trigger_name);
v_cmd := 'ALTER TRIGGER ' || t.trigger_name || ' DISABLE';
EXECUTE IMMEDIATE v_cmd;
END LOOP;
FOR c IN cur_constraintr
LOOP
DBMS_OUTPUT.put_line ('.. ' || c.table_name || ' ' || c.constraint_name);
v_cmd :=
'ALTER TABLE '
|| c.table_name
|| ' MODIFY CONSTRAINT '
|| c.constraint_name
|| ' DISABLE';
EXECUTE IMMEDIATE v_cmd;
END LOOP;
FOR c IN cur_constraintp
LOOP
DBMS_OUTPUT.put_line ('.. ' || c.table_name || ' ' || c.constraint_name);
v_cmd :=
'ALTER TABLE '
|| c.table_name
|| ' MODIFY CONSTRAINT '
|| c.constraint_name
|| ' DISABLE';
EXECUTE IMMEDIATE v_cmd;
END LOOP;
END;

View File

@ -0,0 +1,82 @@
-- Just a sample, this script is generated using the 00_GENERATE_INSERT_AS.sql procedure
-- Started 26-FEB-07
-- migrate table A_ASSET
-- columns in target: C_BPARTNERSR_ID, C_PROJECT_ID, LASTMAINTENANCEDATE, LASTMAINTENANCENOTE, LASTMAINTENANCEUNIT, LASTMAINTENANCEUSEUNIT, LASTMAINTENENCEDATE, LEASETERMINATIONDATE, LEASE_BPARTNER_ID, M_INOUTLINE_ID, NEXTMAINTENANCEUSEUNIT, NEXTMAINTENENCEDATE, NEXTMAINTENENCEUNIT
DELETE FROM target.a_asset
WHERE ( ad_client_id >= 1000000
OR ad_org_id >= 1000000
OR ad_user_id >= 1000000
OR a_asset_group_id >= 1000000
OR a_asset_id >= 1000000
OR c_bpartner_id >= 1000000
OR c_bpartner_location_id >= 1000000
OR c_location_id >= 1000000
OR m_attributesetinstance_id >= 1000000
OR m_locator_id >= 1000000
OR m_product_id >= 1000000
);
INSERT INTO target.a_asset
(ad_client_id, ad_org_id, ad_user_id, assetdepreciationdate,
assetdisposaldate, assetservicedate, a_asset_group_id,
a_asset_id, created, createdby, c_bpartner_id,
c_bpartner_location_id, c_location_id, description,
guaranteedate, HELP, isactive, isdepreciated, isdisposed,
isfullydepreciated, isinposession, isowned, lifeuseunits,
locationcomment, lot, m_attributesetinstance_id, m_locator_id,
m_product_id, NAME, processing, qty, serno, updated, updatedby,
uselifemonths, uselifeyears, useunits, VALUE, versionno)
SELECT ad_client_id, ad_org_id, ad_user_id, assetdepreciationdate,
assetdisposaldate, assetservicedate, a_asset_group_id, a_asset_id,
created, createdby, c_bpartner_id, c_bpartner_location_id,
c_location_id, description, guaranteedate, HELP, isactive,
isdepreciated, isdisposed, isfullydepreciated, isinposession,
isowned, lifeuseunits, locationcomment, lot,
m_attributesetinstance_id, m_locator_id, m_product_id, NAME,
processing, qty, serno, updated, updatedby, uselifemonths,
uselifeyears, useunits, VALUE, versionno
FROM source.a_asset
WHERE ad_client_id <> 11
AND ( ad_client_id >= 1000000
OR ad_org_id >= 1000000
OR ad_user_id >= 1000000
OR a_asset_group_id >= 1000000
OR a_asset_id >= 1000000
OR c_bpartner_id >= 1000000
OR c_bpartner_location_id >= 1000000
OR c_location_id >= 1000000
OR m_attributesetinstance_id >= 1000000
OR m_locator_id >= 1000000
OR m_product_id >= 1000000
);
-- migrate table A_ASSET_ACCT
DELETE FROM target.a_asset_acct
WHERE ( ad_client_id >= 1000000
OR ad_org_id >= 1000000
OR a_asset_id >= 1000000
OR a_depreciation_id >= 1000000
OR c_acctschema_id >= 1000000
);
INSERT INTO target.a_asset_acct
(ad_client_id, ad_org_id, a_accumdepreciation_acct, a_asset_acct,
a_asset_id, a_depreciation_acct, a_depreciation_id,
a_disposal_gain, a_disposal_loss, created, createdby,
c_acctschema_id, isactive, updated, updatedby)
SELECT ad_client_id, ad_org_id, a_accumdepreciation_acct, a_asset_acct,
a_asset_id, a_depreciation_acct, a_depreciation_id, a_disposal_gain,
a_disposal_loss, created, createdby, c_acctschema_id, isactive,
updated, updatedby
FROM source.a_asset_acct
WHERE ad_client_id <> 11
AND ( ad_client_id >= 1000000
OR ad_org_id >= 1000000
OR a_asset_id >= 1000000
OR a_depreciation_id >= 1000000
OR c_acctschema_id >= 1000000
);
-- End 26-FEB-07

View File

@ -0,0 +1,119 @@
/*************************************************************************
* The contents of this file are subject to the Compiere License. You may
* obtain a copy of the License at http://www.compiere.org/license.html
* Software is on an "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either
* express or implied. See the License for details. Code: Compiere ERP+CRM
* Copyright (C) 1999-2002 Jorg Janke, ComPiere, Inc. All Rights Reserved.
*************************************************************************
* $Id: DBA_Trg_Disable.sql,v 1.1 2006/04/21 17:51:58 jjanke Exp $
***
* Title: Enable all triggers and constraints
* Description:
* - required for initial DB create
************************************************************************/
DECLARE
-- Trigger
CURSOR cur_trg
IS
SELECT trigger_name
FROM user_triggers
WHERE status = 'DISABLED'
ORDER BY 1;
CURSOR cur_constraintr
IS
SELECT table_name, constraint_name
FROM user_constraints c
WHERE c.constraint_type <> 'P' AND c.status = 'DISABLED'
ORDER BY 1;
CURSOR cur_constraintp
IS
SELECT table_name, constraint_name
FROM user_constraints c
WHERE c.constraint_type = 'P' AND c.status = 'DISABLED'
ORDER BY 1;
v_cmd VARCHAR2 (256);
BEGIN
DBMS_OUTPUT.put_line ('Enabling:');
FOR t IN cur_trg
LOOP
v_cmd := 'ALTER TRIGGER ' || t.trigger_name || ' ENABLE';
-- DBMS_OUTPUT.put_line (v_cmd);
EXECUTE IMMEDIATE v_cmd;
END LOOP;
FOR c IN cur_constraintp
LOOP
v_cmd :=
'ALTER TABLE '
|| c.table_name
|| ' MODIFY CONSTRAINT '
|| c.constraint_name
|| ' ENABLE';
-- DBMS_OUTPUT.put_line (v_cmd);
EXECUTE IMMEDIATE v_cmd;
END LOOP;
FOR c IN cur_constraintr
LOOP
v_cmd :=
'ALTER TABLE '
|| c.table_name
|| ' MODIFY CONSTRAINT '
|| c.constraint_name
|| ' ENABLE';
-- DBMS_OUTPUT.put_line (v_cmd);
BEGIN
EXECUTE IMMEDIATE v_cmd;
EXCEPTION
WHEN OTHERS
THEN
NULL;
END;
END LOOP;
FOR c IN cur_constraintp
LOOP
v_cmd :=
'ALTER TABLE '
|| c.table_name
|| ' MODIFY CONSTRAINT '
|| c.constraint_name
|| ' ENABLE NOVALIDATE';
DBMS_OUTPUT.put_line (v_cmd);
BEGIN
EXECUTE IMMEDIATE v_cmd;
EXCEPTION
WHEN OTHERS
THEN
NULL;
END;
END LOOP;
FOR c IN cur_constraintr
LOOP
v_cmd :=
'ALTER TABLE '
|| c.table_name
|| ' MODIFY CONSTRAINT '
|| c.constraint_name
|| ' ENABLE NOVALIDATE';
DBMS_OUTPUT.put_line (v_cmd);
BEGIN
EXECUTE IMMEDIATE v_cmd;
EXCEPTION
WHEN OTHERS
THEN
NULL;
END;
END LOOP;
END;

View File

@ -0,0 +1,3 @@
-- Entrar al sistema y ejecutar sequence check
-- TODO: generate a sequence checker in sql