1.安装ora2pg
1.1 安装perl依赖
1.2 安装DBI模块
1.3 安装DBD::Oracle模块
1.4 安装DBD::Pg模块
1.5 安装ORA2PG
1.6 查看软件是否安装成功
2. 简单使用
2.1 迁移表
2.2 迁移视图
2.3 迁移存储过程
2.4 迁移成本评估
ora2pg是一款免费迁移工具,能将oracle迁移到pg,简单使用并记录过程如下
官方文档:http://ora2pg.darold.net/
环境:
虚拟机 rocky linux 8.4
oracle 19c 19.12
pg 14.0
Ora2Pg v22.1
1.安装ora2pg
1.1 安装perl依赖
ora2pg是Perl语言编写的,所以需要先安装相关环境依赖
[root@localhost ~]$ yum install -y perl perl-ExtUtils-CBuilder perl-ExtUtils-MakeMaker
(省略中间...)
Complete!
[root@localhost ~]$
1.2 安装DBI模块
DBI,Database Independent Interface,是Perl语言连接数据库的接口
下载地址https://metacpan.org/release/DBI 下载出DBI-1.643.tar.gz
然后解压安装
[root@localhost /usr/local]$ tar -xzvf DBI-1.643.tar.gz
[root@localhost /usr/local/DBI-1.643]$ cd DBI-1.643/
[root@localhost /usr/local/DBI-1.643]$ perl Makefile.PL
[root@localhost /usr/local/DBI-1.643]$ make
[root@localhost /usr/local/DBI-1.643]$ make install
1.3 安装oracle-instantclient
#下载 InstantClient(Basic、SDK和Sqlplus的zip包)
http://www.oracle.com/technetwor ... -64soft-092277.html
#解压后放到 /u01/app/oracle 目录下
unzip instantclient-basic-linux.x64-19.12.0.0.0dbru.zip
unzip instantclient-sdk-linux.x64-19.12.0.0.0dbru.zip
unzip instantclient-sqlplus-linux.x64-19.12.0.0.0dbru.zip
mkdir /u01/app/oracle -p
mv instantclient_19_12 /u01/app/oracle
#修改权限并配置环境变量
cd /u01/app/oracle
chmod 755 instantclient_19_12/
vi /etc/profile
export PATH=/u01/app/oracle/instantclient_19_12/:$PATH
export LD_LIBRARY_PATH=/u01/app/oracle/instantclient_19_12/:$LD_LIBRARY_PATH
# source /etc/profile
1.4 安装DBD::Oracle模块
安装DBD-Oracle驱动,下载地址https://metacpan.org/pod/release ... 0/lib/DBD/Oracle.pm,下载出DBD-Oracle-1.80.tar.gz
# tar -zxvf DBD-Oracle-1.80.tar.gz
# cd DBD-Oracle-1.80/
# perl Makefile.PL
# make
# make install
1.5 安装DBD::Pg模块
安装DBD-Pg驱动,下载地址https://metacpan.org/release/DBD-Pg,下载出DBD-Pg-3.15.0.tar.gz
# cd DBD-Pg-3.15.0/
# perl Makefile.PL
输入:pg_config绝对位置
# make
# make install
1.6 安装ORA2PG
下载地址https://sourceforge.net/projects/ora2pg/
# tar -xvf ora2pg-22.1.tar.bz2
# cd ora2pg-22.1/
# ls
changelog doc INSTALL lib LICENSE Makefile.PL MANIFEST packaging README scripts
# perl Makefile.PL
# make
# make install
Installing default configuration file (ora2pg.conf.dist) to /etc/ora2pg
#
1.7 查看软件是否安装成功
# cat check.pl
#!/usr/bin/perl
use strict;
use ExtUtils::Installed;
my $inst=ExtUtils::Installed->new();
my @modules = $inst->modules();
foreach(@modules){
my $ver = $inst->version($_) || "???";
printf("%-12s -- %s\n",$_,$ver);
}
exit;
# perl check.pl
[root@pgserver sztech]# perl /setup/ora2pg-22.1/check.pl
DBD::Oracle -- 1.80
DBD::Pg -- 3.15.0
DBI -- 1.643
Ora2Pg -- 22.1
Perl -- 5.26.3
[root@pgserver sztech]#
测试一下
[root@pgserver sztech]# cat ora2pg_oracle.conf
ORACLE_HOME /u01/app/oracle/instantclient_19_12
ORACLE_DSN dbi:Oracle:host=192.168.133.130;sid=emrep;port=1521
ORACLE_USER hr
ORACLE_PWD hr
INDEXS_RENAMING 1
TYPE TABLE,INSERT,VIEW,SEQUENCE
NLS_LANG AMERICAN_AMERICA.AL32UTF8
SCHEMA hr
DEFAULT_NUMRIC numeric
PG_NUMERIC_TYPE 1
PG_INTEGER_TYPE 1
USER_GRANTS 1
SKIP fkeys pkeys ukeys indexes checks
OUTPUT hr.sql
OUTPUT_DIR /opt/tmp/sztech
[root@pgserver sztech]# ora2pg -t SHOW_VERSION -c ora2pg_oracle.conf
WARNING: target PostgreSQL version must be set in PG_VERSION configuration directive. Using default: 11
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0
2. 简单使用
oracle以hr这个schema为例,做迁移
2.1.1 编写配置文件
创建ora2pg_table.conf,导出表结构的配置文件,内容见测试部分
创建ora2pg_data.conf,导出数据,内容如下
[root@localhost ~]$ cat ora2pg_table.conf
ORACLE_HOME /u01/app/oracle/instantclient_19_12
ORACLE_DSN dbi:Oracle:host=192.168.133.130;sid=emrep;port=1521
ORACLE_USER hr
ORACLE_PWD hr
INDEXS_RENAMING 1
TYPE TABLE
NLS_LANG AMERICAN_AMERICA.AL32UTF8
SCHEMA hr
DEFAULT_NUMRIC numeric
PG_NUMERIC_TYPE 1
PG_INTEGER_TYPE 1
USER_GRANTS 1
SKIP fkeys pkeys ukeys indexes checks
OUTPUT hr_table.sql
OUTPUT_DIR /opt/tmp/sztech
[root@pgserver sztech]# cat ora2pg_data.conf
ORACLE_HOME /u01/app/oracle/instantclient_19_12
ORACLE_DSN dbi:Oracle:host=192.168.133.130;sid=emrep;port=1521
ORACLE_USER hr
ORACLE_PWD hr
INDEXS_RENAMING 1
TYPE COPY
NLS_LANG AMERICAN_AMERICA.AL32UTF8
SCHEMA hr
DEFAULT_NUMRIC numeric
PG_NUMERIC_TYPE 1
PG_INTEGER_TYPE 1
USER_GRANTS 1
SKIP fkeys pkeys ukeys indexes checks
OUTPUT data.sql
OUTPUT_DIR /opt/tmp/sztech
[root@localhost ~]$
2.1.2 导出数据
执行导出命令,导出表结构和数据
[root@pgserver sztech]# ora2pg -c ora2pg_table.conf
WARNING: target PostgreSQL version must be set in PG_VERSION configuration directive. Using default: 11
[========================>] 10/10 tables (100.0%) end of scanning.
Retrieving table partitioning information...
[========================>] 10/10 tables (100.0%) end of table export.
Fixing function calls in output files...
[root@pgserver sztech]# ora2pg -c ora2pg_data.conf
WARNING: target PostgreSQL version must be set in PG_VERSION configuration directive. Using default: 11
[========================>] 10/10 tables (100.0%) end of scanning.
[========================>] 25/25 rows (100.0%) Table COUNTRIES (25 recs/sec)
[====> ] 25/131 total rows (19.1%) - (0 sec., avg: 25 recs/sec).
[========================>] 8/8 rows (100.0%) Table DEPARTMENTS (8 recs/sec)
[======> ] 33/131 total rows (25.2%) - (0 sec., avg: 33 recs/sec).
[========================>] 20/20 rows (100.0%) Table EMPLOYEES (20 recs/sec)
[=========> ] 53/131 total rows (40.5%) - (0 sec., avg: 53 recs/sec).
[========================>] 3/1 rows (300.0%) Table FLIGHTS (3 recs/sec)
[==========> ] 56/131 total rows (42.7%) - (0 sec., avg: 56 recs/sec).
[========================>] 19/19 rows (100.0%) Table JOBS (19 recs/sec)
[=============> ] 75/131 total rows (57.3%) - (0 sec., avg: 75 recs/sec).
[========================>] 6/6 rows (100.0%) Table JOB_GRADES (6 recs/sec)
[==============> ] 81/131 total rows (61.8%) - (0 sec., avg: 81 recs/sec).
[========================>] 10/10 rows (100.0%) Table JOB_HISTORY (10 recs/sec)
[================> ] 91/131 total rows (69.5%) - (0 sec., avg: 91 recs/sec).
[========================>] 23/23 rows (100.0%) Table LOCATIONS (23 recs/sec)
[====================> ] 114/131 total rows (87.0%) - (0 sec., avg: 114 recs/sec).
[========================>] 4/4 rows (100.0%) Table REGIONS (4 recs/sec)
[=====================> ] 118/131 total rows (90.1%) - (0 sec., avg: 118 recs/sec).
[========================>] 15/15 rows (100.0%) Table RETIRED_EMPLOYEES (15 recs/sec)
[========================>] 133/131 total rows (101.5%) - (0 sec., avg: 133 recs/sec).
[========================>] 131/131 rows (100.0%) on total estimated data (1 sec., avg: 131 recs/sec)
Fixing function calls in output files...
查看导出的sql
[root@pgserver sztech]# cat hr.sql
-- Generated by Ora2Pg, the Oracle database Schema converter, version 22.1
-- Copyright 2000-2021 Gilles DAROLD. All rights reserved.
-- DATASOURCE: dbi:Oracle:host=192.168.133.130;sid=emrep;port=1521
SET client_encoding TO 'UTF8';
\set ON_ERROR_STOP ON
SET check_function_bodies = false;
CREATE TABLE countries (
country_id char(2) NOT NULL,
country_name varchar(40),
region_id bigint
) ;
COMMENT ON TABLE countries IS E'country table. Contains 25 rows. References with locations table.';
COMMENT ON COLUMN countries.country_id IS E'Primary key of countries table.';
COMMENT ON COLUMN countries.country_name IS E'Country name';
COMMENT ON COLUMN countries.region_id IS E'Region ID for the country. Foreign key to region_id column in the departments table.';
CREATE TABLE departments (
department_id smallint NOT NULL,
department_name varchar(30) NOT NULL,
manager_id integer,
location_id smallint
) ;
COMMENT ON TABLE departments IS E'Departments table that shows details of departments where employees
work. Contains 27 rows; references with locations, employees, and job_history tables.';
COMMENT ON COLUMN departments.department_id IS E'Primary key column of departments table.';
COMMENT ON COLUMN departments.department_name IS E'A not null column that shows name of a department. Administration,
Marketing, Purchasing, Human Resources, Shipping, IT, Executive, Public
Relations, Sales, Finance, and Accounting. ';
COMMENT ON COLUMN departments.location_id IS E'Location id where a department is located. Foreign key to location_id column of locations table.';
COMMENT ON COLUMN departments.manager_id IS E'Manager_id of a department. Foreign key to employee_id column of employees table. The manager_id column of the employee table references this column.';
CREATE TABLE employees (
employee_id integer NOT NULL,
first_name varchar(20),
last_name varchar(25) NOT NULL,
email varchar(25) NOT NULL,
phone_number varchar(20),
hire_date timestamp NOT NULL,
job_id varchar(10) NOT NULL,
salary double precision,
commission_pct real,
manager_id integer,
department_id smallint
) ;
COMMENT ON TABLE employees IS E'employees table. Contains 107 rows. References with departments,
jobs, job_history tables. Contains a self reference.';
COMMENT ON COLUMN employees.commission_pct IS E'Commission percentage of the employee; Only employees in sales
department elgible for commission percentage';
COMMENT ON COLUMN employees.department_id IS E'Department id where employee works; foreign key to department_id
column of the departments table';
COMMENT ON COLUMN employees.email IS E'Email id of the employee';
COMMENT ON COLUMN employees.employee_id IS E'Primary key of employees table.';
COMMENT ON COLUMN employees.first_name IS E'First name of the employee. A not null column.';
COMMENT ON COLUMN employees.hire_date IS E'Date when the employee started on this job. A not null column.';
COMMENT ON COLUMN employees.job_id IS E'Current job of the employee; foreign key to job_id column of the
jobs table. A not null column.';
COMMENT ON COLUMN employees.last_name IS E'Last name of the employee. A not null column.';
COMMENT ON COLUMN employees.manager_id IS E'Manager id of the employee; has same domain as manager_id in
departments table. Foreign key to employee_id column of employees table.
(useful for reflexive joins and CONNECT BY query)';
COMMENT ON COLUMN employees.phone_number IS E'Phone number of the employee; includes country code and area code';
COMMENT ON COLUMN employees.salary IS E'Monthly salary of the employee. Must be greater
than zero (enforced by constraint emp_salary_min)';
CREATE TABLE flights (
source varchar(25),
destin varchar(25),
flight_time real
) ;
CREATE TABLE jobs (
job_id varchar(10) NOT NULL,
job_title varchar(35) NOT NULL,
min_salary integer,
max_salary integer
) ;
COMMENT ON TABLE jobs IS E'jobs table with job titles and salary ranges. Contains 19 rows.
References with employees and job_history table.';
COMMENT ON COLUMN jobs.job_id IS E'Primary key of jobs table.';
COMMENT ON COLUMN jobs.job_title IS E'A not null column that shows job title, e.g. AD_VP, FI_ACCOUNTANT';
COMMENT ON COLUMN jobs.max_salary IS E'Maximum salary for a job title';
COMMENT ON COLUMN jobs.min_salary IS E'Minimum salary for a job title.';
CREATE TABLE job_grades (
grade_level char(1),
lowest_sal bigint,
highest_sal bigint
) ;
CREATE TABLE job_history (
employee_id integer NOT NULL,
start_date timestamp NOT NULL,
end_date timestamp NOT NULL,
job_id varchar(10) NOT NULL,
department_id smallint
) ;
COMMENT ON TABLE job_history IS E'Table that stores job history of the employees. If an employee
changes departments within the job or changes jobs within the department,
new rows get inserted into this table with old job information of the
employee. Contains a complex primary key: employee_id+start_date.
Contains 25 rows. References with jobs, employees, and departments tables.';
COMMENT ON COLUMN job_history.department_id IS E'Department id in which the employee worked in the past; foreign key to deparment_id column in the departments table';
COMMENT ON COLUMN job_history.employee_id IS E'A not null column in the complex primary key employee_id+start_date.
Foreign key to employee_id column of the employee table';
COMMENT ON COLUMN job_history.end_date IS E'Last day of the employee in this job role. A not null column. Must be
greater than the start_date of the job_history table.
(enforced by constraint jhist_date_interval)';
COMMENT ON COLUMN job_history.job_id IS E'Job role in which the employee worked in the past; foreign key to
job_id column in the jobs table. A not null column.';
COMMENT ON COLUMN job_history.start_date IS E'A not null column in the complex primary key employee_id+start_date.
Must be less than the end_date of the job_history table. (enforced by
constraint jhist_date_interval)';
CREATE TABLE locations (
location_id smallint NOT NULL,
street_address varchar(40),
postal_code varchar(12),
city varchar(30) NOT NULL,
state_province varchar(25),
country_id char(2)
) ;
COMMENT ON TABLE locations IS E'Locations table that contains specific address of a specific office,
warehouse, and/or production site of a company. Does not store addresses /
locations of customers. Contains 23 rows; references with the
departments and countries tables. ';
COMMENT ON COLUMN locations.city IS E'A not null column that shows city where an office, warehouse, or
production site of a company is located. ';
COMMENT ON COLUMN locations.country_id IS E'Country where an office, warehouse, or production site of a company is
located. Foreign key to country_id column of the countries table.';
COMMENT ON COLUMN locations.location_id IS E'Primary key of locations table';
COMMENT ON COLUMN locations.postal_code IS E'Postal code of the location of an office, warehouse, or production site
of a company. ';
COMMENT ON COLUMN locations.state_province IS E'State or Province where an office, warehouse, or production site of a
company is located.';
COMMENT ON COLUMN locations.street_address IS E'Street address of an office, warehouse, or production site of a company.
Contains building number and street name';
CREATE TABLE regions (
region_id bigint NOT NULL,
region_name varchar(25)
) ;
CREATE TABLE retired_employees (
employee_id integer,
first_name varchar(20),
last_name varchar(20),
email varchar(25),
retired_date timestamp,
job_id varchar(20),
salary double precision,
manager_id smallint,
department_id integer
) ;
[root@pgserver sztech]#
[root@pgserver sztech]# cat data.sql
BEGIN;
COPY countries (country_id,country_name,region_id) FROM STDIN;
AR Argentina 2
AU Australia 3
BE Belgium 1
BR Brazil 2
CA Canada 2
CH Switzerland 1
CN China 3
DE Germany 1
DK Denmark 1
EG Egypt 4
FR France 1
IL Israel 4
IN India 3
IT Italy 1
JP Japan 3
KW Kuwait 4
ML Malaysia 3
MX Mexico 2
NG Nigeria 4
NL Netherlands 1
SG Singapore 3
UK United Kingdom 1
US United States of America 2
ZM Zambia 4
ZW Zimbabwe 4
\.
COPY departments (department_id,department_name,manager_id,location_id) FROM STDIN;
10 Administration 200 1700
20 Marketing 201 1800
50 Shipping 124 1500
60 IT 103 1400
80 Sales 149 2500
90 Executive 100 1700
110 Accounting 205 1700
190 Contracting \N 1700
\.
COPY employees (employee_id,first_name,last_name,email,phone_number,hire_date,job_id,salary,commission_pct,manager_id,department_id) FROM STDIN;
100 Steven King SKING 515.123.4567 2011-06-17 00:00:00 AD_PRES 24000 \N \N 90
101 Neena Kochhar NKOCHHAR 515.123.4568 2009-09-21 00:00:00 AD_VP 17000 \N 100 90
102 Lex De Haan LDEHAAN 515.123.4569 2009-01-13 00:00:00 AD_VP 17000 \N 100 90
103 Alexander Hunold AHUNOLD 590.423.4567 2014-01-03 00:00:00 IT_PROG 9000 \N 102 60
104 Bruce Ernst BERNST 590.423.4568 2015-05-21 00:00:00 IT_PROG 6000 \N 103 60
107 Diana Lorentz DLORENTZ 590.423.5567 2015-02-07 00:00:00 IT_PROG 4200 \N 103 60
124 Kevin Mourgos KMOURGOS 650.123.5234 2015-11-16 00:00:00 ST_MAN 5800 \N 100 50
141 Trenna Rajs TRAJS 650.121.8009 2011-10-17 00:00:00 ST_CLERK 3500 \N 124 50
142 Curtis Davies CDAVIES 650.121.2994 2013-01-29 00:00:00 ST_CLERK 3100 \N 124 50
143 Randall Matos RMATOS 650.121.2874 2014-03-15 00:00:00 ST_CLERK 2600 \N 124 50
144 Peter Vargas PVARGAS 650.121.2004 2014-07-09 00:00:00 ST_CLERK 2500 \N 124 50
149 Eleni Zlotkey EZLOTKEY 011.44.1344.429018 2016-01-29 00:00:00 SA_MAN 10500 .2 100 80
174 Ellen Abel EABEL 011.44.1644.429267 2012-05-11 00:00:00 SA_REP 11000 .3 149 80
176 Jonathon Taylor JTAYLOR 011.44.1644.429265 2014-03-24 00:00:00 SA_REP 8600 .2 149 80
178 Kimberely Grant KGRANT 011.44.1644.429263 2015-05-24 00:00:00 SA_REP 7000 .15 149 \N
200 Jennifer Whalen JWHALEN 515.123.4444 2011-09-17 00:00:00 AD_ASST 4400 \N 101 10
201 Michael Hartstein MHARTSTE 515.123.5555 2012-02-17 00:00:00 MK_MAN 13000 \N 100 20
202 Pat Fay PFAY 603.123.6666 2013-08-17 00:00:00 MK_REP 6000 \N 201 20
205 Shelley Higgins SHIGGINS 515.123.8080 2010-06-07 00:00:00 AC_MGR 12008 \N 101 110
206 William Gietz WGIETZ 515.123.8181 2010-06-07 00:00:00 AC_ACCOUNT 8300 \N 205 110
\.
COPY flights (source,destin,flight_time) FROM STDIN;
San Jose Los Angles 1.3
New York Boston 1.1
Los Angles New York 5.8
\.
COPY jobs (job_id,job_title,min_salary,max_salary) FROM STDIN;
AD_PRES President 20080 40000
AD_VP Administration Vice President 15000 30000
AD_ASST Administration Assistant 3000 6000
FI_MGR Finance Manager 8200 16000
FI_ACCOUNT Accountant 4200 9000
AC_MGR Accounting Manager 8200 16000
AC_ACCOUNT Public Accountant 4200 9000
SA_MAN Sales Manager 10000 20080
SA_REP Sales Representative 6000 12008
PU_MAN Purchasing Manager 8000 15000
PU_CLERK Purchasing Clerk 2500 5500
ST_MAN Stock Manager 5500 8500
ST_CLERK Stock Clerk 2008 5000
SH_CLERK Shipping Clerk 2500 5500
IT_PROG Programmer 4000 10000
MK_MAN Marketing Manager 9000 15000
MK_REP Marketing Representative 4000 9000
HR_REP Human Resources Representative 4000 9000
PR_REP Public Relations Representative 4500 10500
\.
COPY job_grades (grade_level,lowest_sal,highest_sal) FROM STDIN;
A 1000 2999
B 3000 5999
C 6000 9999
D 10000 14999
E 15000 24999
F 25000 40000
\.
COPY job_history (employee_id,start_date,end_date,job_id,department_id) FROM STDIN;
102 2001-01-13 00:00:00 2006-07-24 00:00:00 IT_PROG 60
101 1997-09-21 00:00:00 2001-10-27 00:00:00 AC_ACCOUNT 110
101 2001-10-28 00:00:00 2005-03-15 00:00:00 AC_MGR 110
201 2004-02-17 00:00:00 2007-12-19 00:00:00 MK_REP 20
114 2006-03-24 00:00:00 2007-12-31 00:00:00 ST_CLERK 50
122 2007-01-01 00:00:00 2007-12-31 00:00:00 ST_CLERK 50
200 1995-09-17 00:00:00 2001-06-17 00:00:00 AD_ASST 90
176 2006-03-24 00:00:00 2006-12-31 00:00:00 SA_REP 80
176 2007-01-01 00:00:00 2007-12-31 00:00:00 SA_MAN 80
200 2002-07-01 00:00:00 2006-12-31 00:00:00 AC_ACCOUNT 90
\.
COPY locations (location_id,street_address,postal_code,city,state_province,country_id) FROM STDIN;
1000 1297 Via Cola di Rie 00989 Roma \N IT
1100 93091 Calle della Testa 10934 Venice \N IT
1200 2017 Shinjuku-ku 1689 Tokyo Tokyo Prefecture JP
1300 9450 Kamiya-cho 6823 Hiroshima \N JP
1400 2014 Jabberwocky Rd 26192 Southlake Texas US
1500 2011 Interiors Blvd 99236 South San Francisco California US
1600 2007 Zagora St 50090 South Brunswick New Jersey US
1700 2004 Charade Rd 98199 Seattle Washington US
1800 147 Spadina Ave M5V 2L7 Toronto Ontario CA
1900 6092 Boxwood St YSW 9T2 Whitehorse Yukon CA
2000 40-5-12 Laogianggen 190518 Beijing \N CN
2100 1298 Vileparle (E) 490231 Bombay Maharashtra IN
2200 12-98 Victoria Street 2901 Sydney New South Wales AU
2300 198 Clementi North 540198 Singapore \N SG
2400 8204 Arthur St \N London \N UK
2500 Magdalen Centre, The Oxford Science Park OX9 9ZB Oxford Oxford UK
2600 9702 Chester Road 09629850293 Stretford Manchester UK
2700 Schwanthalerstr. 7031 80925 Munich Bavaria DE
2800 Rua Frei Caneca 1360 01307-002 Sao Paulo Sao Paulo BR
2900 20 Rue des Corps-Saints 1730 Geneva Geneve CH
3000 Murtenstrasse 921 3095 Bern BE CH
3100 Pieter Breughelstraat 837 3029SK Utrecht Utrecht NL
3200 Mariano Escobedo 9991 11932 Mexico City Distrito Federal, MX
\.
COPY regions (region_id,region_name) FROM STDIN;
1 Europe
2 Americas
3 Asia
4 Middle East and Africa
\.
COPY retired_employees (employee_id,first_name,last_name,email,retired_date,job_id,salary,manager_id,department_id) FROM STDIN;
301 Rick Dayle RDAYLE 2010-03-18 00:00:00 AD_PRES 8000 124 90
302 Meena Rac MRAC 2011-09-21 00:00:00 AD_VP 11000 149 90
303 Mex Haan MHAAN 2010-01-13 00:00:00 AD_VP 9500 149 80
304 Alexandera Runold ARUNOLD 2011-01-03 00:00:00 IT_PROG 7500 124 60
305 Bruk Ernst BERNST 2010-05-21 00:00:00 IT_PROG 6000 149 60
306 Dravid Aust DAUST 2009-06-25 00:00:00 IT_PROG 4800 124 60
307 Raj Patil RPATIL 2012-02-05 00:00:00 IT_PROG 4800 201 60
308 Rahul Bose RBOSE 2012-08-17 00:00:00 FI_MGR 12008 124 100
309 Dany Fav DFAV 2011-08-16 00:00:00 FI_ACCOUNT 9000 101 100
310 James Ken JKHEN 2010-09-28 00:00:00 FI_ACCOUNT 8200 101 90
311 Shana Garg SGARG 2010-09-30 00:00:00 FI_ACCOUNT 7700 201 100
312 Supriya Ananth SANANTH 2014-06-07 00:00:00 FI_ACCOUNT 7800 124 100
313 Lui Pops LPOPS 2010-12-07 00:00:00 FI_ACCOUNT 6900 201 100
314 Del Raph DRAPH 2012-12-07 00:00:00 PU_MAN 11000 101 30
315 Alex Khurl AKHURL 2011-05-18 00:00:00 PU_CLERK 3100 149 30
\.
ALTER SEQUENCE IF EXISTS locations_seq RESTART WITH 3400;
ALTER SEQUENCE IF EXISTS departments_seq RESTART WITH 290;
ALTER SEQUENCE IF EXISTS employees_seq RESTART WITH 208;
COMMIT;
[root@pgserver sztech]#
2.1.3 导入到pg
su - postgres
$ psql postgres postgres -f hr_table.sql
$ psql postgres postgres -f hr_data.sql
2.2 迁移视图
oracle建立测试视图
类似迁移表,配置文件的type改为VIEW即可
2.3 迁移存储过程
2.3.1 oracle建立测试存储过程
类似迁移表,配置文件的type改为PROCEDURE即可
2.4 迁移成本评估
ora2pg将检查所有object来估算迁移成本和难易程度
# ora2pg -b /opt/tmp/sztech -d -c ora2pg_oracle.conf -t show_report --estimate_cost --dump_as_html >>debug-info.html
Ora2Pg - Database Migration Report
Version Oracle Database 19c Enterprise Edition Release 19.0.0.0.0
Schema HR
Size 1.75 MB
Object Number Invalid Estimated cost Comments Details
DATABASE LINK 0 0 0.00 Database links will be exported as SQL/MED PostgreSQL's Foreign Data Wrapper (FDW) extensions using oracle_fdw.
GLOBAL TEMPORARY TABLE 0 0 0.00 Global temporary table are not supported by PostgreSQL and will not be exported. You will have to rewrite some application code to match the PostgreSQL temporary table behavior.
INDEX 19 0 3.80 19 index(es) are concerned by the export, others are automatically generated and will do so on PostgreSQL. Bitmap will be exported as btree_gin index(es). Domain index are exported as b-tree but commented to be edited to mainly use FTS. Cluster, bitmap join and IOT indexes will not be exported at all. Reverse indexes are not exported too, you may use a trigram-based index (see pg_trgm) or a reverse() function based index and search. Use 'varchar_pattern_ops', 'text_pattern_ops' or 'bpchar_pattern_ops' operators in your indexes to improve search with the LIKE operator respectively into varchar, text or char columns.
See details
JOB 0 0 0.00 Job are not exported. You may set external cron job with them.
PROCEDURE 2 0 8.00 Total size of procedure code: 772 bytes.
See details
SEQUENCE 3 0 1.00 Sequences are fully supported, but all call to sequence_name.NEXTVAL or sequence_name.CURRVAL will be transformed into NEXTVAL('sequence_name') or CURRVAL('sequence_name').
SYNONYM 0 0 0.00 SYNONYMs will be exported as views. SYNONYMs do not exists with PostgreSQL but a common workaround is to use views or set the PostgreSQL search_path in your session to access object outside the current schema.
TABLE 10 0 2.50 15 check constraint(s).
See details
TRIGGER 2 0 5.00 Total size of trigger code: 127 bytes.
See details
Total 36 0 20.30 20.30 cost migration units means approximatively 1 man-day(s). The migration unit was set to 5 minute(s)
Migration level: A-3
Migration levels:
A - Migration that might be run automatically
B - Migration with code rewrite and a human-days cost up to 5 days
C - Migration with code rewrite and a human-days cost above 5 days
Technical levels:
1 = trivial: no stored functions and no triggers
2 = easy: no stored functions but with triggers, no manual rewriting
3 = simple: stored functions and/or triggers, no manual rewriting
4 = manual: no stored functions but with triggers or views with code rewriting
5 = difficult: stored functions and/or triggers with code rewriting
Details of cost assessment per function
|