db_migrator
is a PostgreSQL extension that provides functions for
migrating databases from other data sources to PostgreSQL.
This requires a foreign data wrapper for the data source you
want to migrate.
You also need a plugin for db_migrator
that contains the code specific
to the targeted data source.
Currently, plugins exist for the following data sources:
- Oracle:
ora_migrator
- MySQL/MariaDB:
mysql_migrator
- Microsoft SQL Server:
mssql_migrator
See the section Plugin API below if you want to develop a plugin (I'd be happy to add it to the list above).
See Setup below for installation instructions, Architecture so that you understand what is going on and Usage for instructions how to best migrate a database.
This is a complete example of a simple migration of an Oracle database
using the ora_migrator
plugin.
A superuser sets the stage:
CREATE EXTENSION oracle_fdw;
CREATE SERVER oracle FOREIGN DATA WRAPPER oracle_fdw
OPTIONS (dbserver '//dbserver.mydomain.com/ORADB');
GRANT USAGE ON FOREIGN SERVER oracle TO migrator;
CREATE USER MAPPING FOR migrator SERVER oracle
OPTIONS (user 'orauser', password 'orapwd');
PostgreSQL user migrator
has the privilege to create PostgreSQL schemas
and Oracle user orauser
has the SELECT ANY DICTIONARY
privilege.
Now we connect as migrator
and perform the migration so that all objects
will belong to this user:
CREATE EXTENSION ora_migrator;
SELECT db_migrate(
plugin => 'ora_migrator',
server => 'oracle',
only_schemas => '{TESTSCHEMA1,TESTSCHEMA2}'
);
NOTICE: Creating staging schemas "fdw_stage" and "pgsql_stage" ...
NOTICE: Creating foreign metadata views in schema "fdw_stage" ...
NOTICE: Creating schemas ...
NOTICE: Creating sequences ...
NOTICE: Creating foreign tables ...
NOTICE: Migrating table testschema1.baddata ...
WARNING: Error loading table data for testschema1.baddata
DETAIL: invalid byte sequence for encoding "UTF8": 0x00:
NOTICE: Migrating table testschema1.log ...
NOTICE: Migrating table testschema1.tab1 ...
NOTICE: Migrating table testschema1.tab2 ...
NOTICE: Migrating table testschema2.tab3 ...
NOTICE: Creating UNIQUE and PRIMARY KEY constraints ...
WARNING: Error creating primary key or unique constraint on table testschema1.baddata
DETAIL: relation "testschema1.baddata" does not exist:
NOTICE: Creating FOREIGN KEY constraints ...
NOTICE: Creating CHECK constraints ...
NOTICE: Creating indexes ...
NOTICE: Setting column default values ...
NOTICE: Dropping staging schemas ...
NOTICE: Migration completed with 2 errors.
db_migrate
------------
2
(1 row)
Even though the migration of one table failed because of bad data in the Oracle database, the rest of the data were migrated successfully.
You need to install the foreign data wrapper for the data source from which you want to migrate. Follow the installation instructions of that software. A list of available foreign data wrappers is available in the PostgreSQL Wiki.
You need to define these objects:
-
a foreign server that describes how to connect to the remote data source
-
a user mapping for the server to provide credentials for the user that performs the migration
You need a database user with
-
the
CREATE
privilege on the current database -
the
USAGE
privilege on the schemas where the extensions are installed -
the
USAGE
privilege on the foreign server -
EXECUTE
privileges on all required migration functions (this is usually granted by default)
The permissions can be reduced once the migration is complete.
You also need to install the db_migrator
plugin for the data source from
which you want to migrate. Again, follow the installation instructions
provided with the software.
The extension files must be placed in the extension
subdirectory of
the PostgreSQL shared files directory, which can be found with
pg_config --sharedir
If the extension building infrastructure PGXS is installed, you can do that simply with
make install
The extension is installed in the database to which you want to migrate the data with the SQL command
CREATE EXTENSION db_migrator;
This statement can be executed by any user with the right to create
functions in the public
schema (or the schema you specified in the
optional SCHEMA
clause of CREATE EXTENSION
).
db_migrator
uses two auxiliary schemas, the "FDW staging schema" and the
"Postgres staging schema". The names are fdw_stage
and pgsql_stage
by
default, but you can choose different names.
In a first step, db_migrator
calls the plugin to populate the FDW stage
with foreign tables that provide information about the metadata of the remote
data source in a standardized way (see Plugin API for details).
In the second step, the data are copied to tables in the Postgres stage, resulting in a kind of snapshot of the data in the FDW stage. These tables are described in detail at the end of this chapter. During this snapshot, table and column names may be translated using a function provided by the plugin. The plugin also provides a default mapping of remote data types to PostgreSQL data types.
As a next step, the user modifies the data in the Postgres stage to fit
the requirements for the migration (different data types, edits to function
and view definitions etc.). This is done with updates to the tables in the
Postgres stage. Also, most tables have a boolean
column migrate
that
should be set to TRUE
for all objects that should be migrated.
The next step is to create schemas in the PostgreSQL database and populate them with foreign tables that point to the objects in the remote data source. These tables are then "materialized", that is, local tables are created, and the data from the foreign tables is inserted into the local tables.
Then the other objects and finally the indexes and constraints can be migrated.
Once migration is complete, the FDW stage and the PostgreSQL stage (and the foreign data wrapper) are not needed any more and can be removed.
Only edit the columns that are indicated. For example, it you want to change a schema or table name, it is better to rename the schema or table once you are done with the migration.
-
schema
(typename
): name of the schema -
orig_schema
(typetext
): schema name as used in the remote data source
-
schema
(typename
): schema of the table -
table_name
(typename
): name of the table -
orig_table
(typetext
): table name as used in the remote data source -
migrate
(typeboolean
, defaultTRUE
):TRUE
if the table should be migratedModify this column if desired.
-
schema
(typename
): schema of the table containing the column -
table_name
(typename
): table containing the column -
column_name
(typename
): name of the column -
column_options
(typejsonb
): plugin-specific column options -
orig_column
(typetext
): column name as used in the remote data source -
position
(typeinteger
): defines the order of the columns (1 for the first column) -
type_name
(typetext
): PostgreSQL data type (including type modifiers)Modify this column if desired.
-
orig_type
(typetext
): data type in the remote data source -
nullable
(typeboolean
):FALSE
if the column isNOT NULL
Modify this column if desired.
-
default_value
(typetext
):Modify this column if desired.
-
schema
(typename
): schema of the table with the constraint -
table_name
(typename
): table with the constraint -
constraint_name
(typename
): name of the constraint -
orig_name
(typetext
): name of the constraint in the remote data source -
deferrable
(typeboolean
):TRUE
if the constraint can be deferredModify this column if desired.
-
deferred
(typeboolean
):TRUE
if the constraint isINITIALLY DEFERRED
Modify this column if desired.
-
condition
(typetext
): condition to be checkedModify this column if desired.
-
migrate
(typeboolean
, defaultTRUE
):TRUE
if the constraint should be migratedModify this column if desired.
-
schema
(typename
): schema of the table with the constraint -
table_name
(typename
): table with the constraint -
constraint_name
(typename
): name of the constraint -
orig_name
(typetext
): name of the constraint in the remote source -
deferrable
(typeboolean
):TRUE
if the constraint can be deferredModify this column if desired.
-
deferred
(typeboolean
):TRUE
if the constraint isINITIALLY DEFERRED
Modify this column if desired.
-
column_name
(typename
): name of a column that is part of the key -
position
(typeinteger
): defines the order of columns in the constraint -
is_primary
(typeboolean
):TRUE
if this is a primary key -
migrate
(typeboolean
, defaultTRUE
):TRUE
if the constraint should be migratedModify this column if desired.
-
schema
(typename
): schema of the table with the index -
table_name
(typename
): table with the index -
index_name
(typename
): name of the index -
orig_name
(typetext
): name of the index in the remote source -
uniqueness
(typeboolean
):TRUE
if this is a unique indexModify this column if desired.
-
where_clause
(typetext
): expression attached to a partial indexNULL
means no filter applies. -
migrate
(typeboolean
, defaultTRUE
):TRUE
if the constraint should be migratedModify this column if desired.
-
schema
(typename
): schema of the table with the index -
table_name
(typename
): table with the index -
index_name
(typename
): name of the index -
position
(typeinteger
): determines the index column order -
descend
(typeboolean
):TRUE
if the index column is sortedDESC
Modify this column if desired.
-
is_expression
(typeboolean
):TRUE
if the index column is an expression rather than a column name -
column_name
(typetext
): name of the column or indexed expression (expressions usually must be surounded with parentheses)Modify this column if desired.
Delete rows from this table if you don't want a partitioned table in PostgreSQL. Alternatively, you can add rows if you want to migrate a non-partitioned table to a partitioned PostgreSQL table.
-
schema
(typename
): schema of the partitioned table -
table_name
(typename
): name of the partitioned table -
partition_name
(typename
): name of the partition -
orig_name
(typename
): name of the partition in the remote source -
type
(typetext
): one of the supported partitioning methodsLIST
,RANGE
orHASH
-
key
(typetext
): column name or expression used as partitioning key -
values
(typetext[]
): partition bound specifications -
values
are partition bound specifications-
for list partitioning,
values
contains the list -
for range partitioning,
values
contains the lower and upper bound (where the lower end is included, but the upper end is excluded) -
for hash partitioning, the only entry in
values
is the remainder for this partition
Non-numeric values like timestamps have to be quoted as string constants (for example
ARRAY['''2022-01-01''','''2023-01-01''']
). -
-
is_default
(typeboolean
, defaultFALSE
);TRUE
if it is the default partition
Delete rows from this table if you don't want a subpartitioned table in PostgreSQL. Alternatively, you can add rows if you want to migrate a table without subpartitions to a PostgreSQL table with subpartitions.
-
schema
(typename
): schema of the partitioned table -
table_name
(typename
): name of the partitioned table -
partition_name
(typename
): name of the parent partition -
subpartition_name
(typename
): name of the subpartition -
orig_name
(typename
): name of the subpartition in the remote source -
type
(typetext
): one of the supported partitioning methodsLIST
,RANGE
orHASH
-
key
(typetext
): column name or expression used as partitioning key -
values
(typetext[]
): partition bound specificationsSee the documentation of
values
for thepartitions
table above. -
is_default
(typeboolean
, defaultFALSE
);TRUE
if it is the default subpartition
-
schema
(typename
): schema of the table with the view -
view_name
(typename
): name of the view -
definition
(typetext
): SQL statement defining the viewModify this column if desired.
-
orig_def
(typetext
): view definition on the remote data source -
migrate
(typeboolean
, defaultTRUE
):TRUE
if the constraint should be migratedModify this column if desired.
-
verified
(typeboolean
): can be used however you wantThis may be useful to store if the view has been translated successfully.
-
schema
(typename
): schema of the sequence -
sequence_name
(typename
): name of the sequence -
min_value
(typebigint
): minimal value for the generated valueModify this column if desired.
-
max_value
(typebigint
): maximal value for the generated valueModify this column if desired.
-
increment_by
(typebigint
): difference between generated valuesModify this column if desired.
-
cyclical
(typeboolean
):TRUE
if the sequence "wraps around"Modify this column if desired.
-
cache_size
(typeinteger
): number of sequence values cached on the client sideModify this column if desired.
-
last_value
(typebigint
): current position of the sequenceModify this column if desired.
-
orig_value
(typebigint
): current position on the remote data source
-
schema
(typename
): schema of the function or procedure -
function_name
(typename
): name of the function or procedure -
is_procedure
(typeboolean
):TRUE
if it is a procedureModify this column if desired.
-
source
(typetext
): source code of the function or procedureModify this column if desired.
-
orig_source
(typetext
): source code on the remote data source -
migrate
(typeboolean
, defaultFALSE
):TRUE
is the object should be migratedModify this column if desired. Note that since the default value is
FALSE
, functions and procedures will not be migrated by default. -
verified
(typeboolean
): can be used however you wantThis may be useful to store if the source code has been translated successfully.
-
schema
(typename
): schema of the table with the trigger -
table_name
(typename
): name of the table with the trigger -
trigger_name
(typename
): name of the trigger -
trigger_type
(typetext
):BEFORE
,AFTER
orINSTEAD OF
Modify this column if desired.
-
triggering_event
(typetext
):INSERT
,UPDATE
,DELETE
orTRUNCATE
(if more than one, combine withOR
)Modify this column if desired.
-
for_each_row
(typeboolean
):TRUE
if the trigger is executed for each modified row rather than once per triggering statementModify this column if desired.
-
when_clause
(typetext
): condition for the trigger executionModify this column if desired.
-
trigger_body
(typetext
): the function body for the triggerModify this column if desired.
-
orig_source
(typetext
): the trigger source code on the remote data source -
migrate
(typeboolean
, defaultFALSE
):TRUE
if the trigger should be migratedModify this column if desired. Note that since the default value is
FALSE
, functions and procedures will not be migrated by default. -
verified
(typeboolean
): can be used however you wantThis may be useful to store if the trigger has been translated successfully.
These are not migrated by db_migrator
, but can be used by the migration
script to migrate permissions.
-
schema
(typename
): schema of the table with the privilege -
table_name
(typename
): name of the table with the privilege -
privilege
(typetext
): name of the privilege -
grantor
(typename
): user who granted the privilege -
grantee
(typename
): user who receives the permission -
grantable
(typeboolean
):TRUE
if the grantee can grant the privilege to others
These are not migrated by db_migrator
, but can be used by the migration
script to migrate permissions.
-
schema
(typename
): -
table_name
(typename
): -
column_name
(typename
): -
privilege
(typetext
): -
grantor
(typename
): -
grantee
(typename
): -
grantable
(typeboolean
):
The database user that performs the migration will be the owner of all migrated schemas and objects. Ownership can be transferred once migration is complete. Permissions on database objects are not migrated (but the plugin may offer information about the permissions on the data source).
There is no special support for translating procedural code (functions, procedures and triggers), you will have to do that yourself.
For very simple cases (no stored procedures or triggers to migrate, all
views in standard SQL, no data type adaptions required) you can simply call
the db_migrate
function to migrate the database schemas you want.
For more complicated migrations, you will compose an SQL script that does the following (or parts thereof):
-
Call
db_migrate_prepare
to create and populate the FDW and Postgres staging schemas (see Architecture for details). -
Now you can update the tables in the Postgres stage to change data types, stored procedure code, views and similar. This is also the time to set the
migrate
flag in the tables in the Postgres stage to indicate which objects should be migrated and which ones not. -
At any given point before you call
db_migrate_mkforeign
, you can calldb_migrate_refresh
to update the snapshot in the Postgres stage with current metadata. -
Next, you call
db_migrate_mkforeign
to migrate the schemas and created foreign tables that point to the remote objects containing data that should be migrated. -
Now you can use
ALTER FOREIGN TABLE
if you need to make adjustments to these foreign tables. -
Next, you call
db_migrate_tables
to replace the foreign tables with actual PostgreSQL tables and migrate the data. This step will usually take the most time. Note that there is the option to perform a "schema-only" migration to test the object definitions without having to migrate all the data. -
If you wish to migrate such objects, you can now call the
db_migrate_functions
,db_migrate_triggers
anddb_migrate_views
functions to migrate these objects. If views depend on functions, calldb_migrate_views
last. -
Then you call
db_migrate_constraints
to migrate indexes and constraints for the migrated tables. It is usually a good idea to do this last, since indexes and constraints can depend on functions. -
Finally, call
db_migrate_finish
to remove the FDW and Postgres staging schemas created bydb_migrate_prepare
.
An errors (except connection problems) that happen during database migration
will not terminate processing. Rather, they will be reported as warnings.
Additionally, such errors are logged in the table migrate_log
in the
PostgreSQL staging schema.
Later errors can be consequences of earlier errors: for example, any failure to migrate an Oracle table will also make all views and constraints that depend on that table fail.
After you are done, drop the migration extensions to remove all traces of the migration.
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
server
(typename
, required): name of the foreign server that describes the data source from which to migrate -
staging_schema
(typename
, defaultfdw_stage
): name of the remote staging schema -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema -
only_schemas
(typename[]
, default all schemas): list of schemas to migrateThese must be written exactly like they are on the remote data source.
-
options
(typejsonb
, optional): options to pass to the pluginConsult the documentation of the plugin for available options.
This function must be called first. It creates the staging schemas.
The remote staging schema is populated by the plugin. db_migrate_refresh
is called to create a snapshot of the remote stage in the Postgres stage.
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
staging_schema
(typename
, defaultfdw_stage
): name of the remote staging schema -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema -
only_schemas
(typename[]
, default all schemas): list of schemas to migrate
You can call this function to refresh the Postgres stage with a new snapshot of the remote stage. This will work as long as no objects on the remote data source are renamed or deleted (adding tables and columns will work fine). Edits made to the Postgres stage will be preserved.
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
server
(typename
, required): name of the foreign server that describes the data source from which to migrate -
staging_schema
(typename
, defaultfdw_stage
): name of the remote staging schema -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema -
options
(typejsonb
, optional): options to pass to the pluginConsult the documentation of the plugin for available options.
Call this function once you have edited the Postgres stage to your satisfaction. It will create all schemas that should be migrated and foreign tables for all remote tables you want to migrate.
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema -
with_data
(typeboolean
, defaultTRUE
): ifFALSE
, migrate everything but the table dataThis is useful to test the migration of the metadata.
This function calls materialize_foreign_table
to replace all foreign tables
created by db_migrate_mkforeign
with actual tables.
The table data are migrated unless with_data
is FALSE
.
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema
Call this to migrate functions and procedures.
Note that migrate
is set to FALSE
by default for functions and procedures,
so you will have to change that flag if you want to migrate functions.
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema
Call this to migrate views.
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema
Call this to migrate triggers.
Note that migrate
is set to FALSE
by default for triggers, so you will
have to change that flag if you want to migrate functions.
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema
Call this to migrate user-defined indexes for the migrated tables.
This function should run after migrating the functions, so that all functions that are needed by indexes are already there.
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema
Call this to migrate constraints and column defaults for the migrated tables.
This function has to run after everything else has been migrated, so that all functions that may be needed by column defaults are already there and foreign key constraints can use user-defined indexes to speed-up data validation.
Parameters:
-
staging_schema
(typename
, defaultfdw_stage
): name of the remote staging schema -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema
Call this function after you have migrated everything you need. It will drop the staging schemas and all their content.
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
server
(typename
, required): name of the foreign server that describes the data source from which to migrate -
staging_schema
(typename
, defaultfdw_stage
): name of the remote staging schema -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema -
only_schemas
(typename[]
, default all schemas): list of schemas to migrateThese must be written exactly like they are on the remote data source.
-
options
(typejsonb
, optional): options to pass to the pluginConsult the documentation of the plugin for available options.
This function provides "one-click" migration by calling the other functions in the following order:
-
db_migrate_prepare
-
db_migrate_mkforeign
-
db_migrate_tables
-
db_migrate_functions
-
db_migrate_views
-
db_migrate_triggers
-
db_migrate_indexes
-
db_migrate_constraints
-
db_migrate_finish
This provides a simple way to migrate simple databases (no user defined functions and triggers, standard compliant view definitions, no data type modifications necessary).
Note that it will not migrate functions and triggers, since migrate
is FALSE
by default for these objects.
These functions are called by migration functions detailed above.
They are provided as a low-level alternative and are particularly useful if you want to migrate several relations in parallel to improve processing speed with your own external tools.
Parameters:
-
schema
(typename
, required): schema of the table to migrate -
table_name
(typename
, required): name of the table to migrate -
with_data
(typeboolean
, defaultTRUE
): ifFALSE
, migrate everything but the table dataThis is useful to test the migration of the metadata.
-
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema
This function replaces a single foreign table created by db_migrate_mkforeign
with an actual table.
If there are any entries for this table in the partitions
tables, the table
will be created as a partitioned table. Subpartitions are created if there are
corresponding entries in subpartitions
.
The table data are migrated unless with_data
is FALSE
.
Parameters:
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema
Will return a table composed by following columns:
-
schema_name
(typename
): name of the schema -
statement
(typetext
): related CREATE SCHEMA statement of the schema
Parameters:
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema
Will return a table composed by following columns:
-
schema_name
(typename
): schema of the sequence -
sequence_name
(typename
): name of the sequence -
statement
(typetext
): related CREATE SEQUENCE statement of the sequence
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
server
(typename
, required): name of the foreign server that describes the data source from which to migrate -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema -
options
(typejsonb
, optional): options to pass to the plugin
Will return a table composed by following columns:
-
schema_name
(typename
): schema of the table with the foreign table -
table_name
(typename
): name of the foreign table -
statement
(typetext
): related CREATE FOREIGN TABLE statement of the foreign table
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema
Will return a table composed by following columns:
-
schema_name
(typename
): schema of the table with the function -
function_name
(typename
): name of the function or procedure -
statement
(typetext
): related CREATE FUNCTION or CREATE PROCEDURE statement of the function
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema
Will return a table composed by following columns:
-
schema_name
(typename
): schema of the table with the function -
view_name
(typename
): name of the view -
statements
(typetext[]
): related SET LOCAL search_path and CREATE VIEW statements of the view
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema
Will return a table composed by following columns:
-
schema_name
(typename
): schema of the table with the trigger -
trigger_name
(typename
): name of the trigger -
statements
(typetext[]
): related CREATE FUNCTION and CREATE TRIGGER statements of the trigger
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema
Will return a table composed by following columns:
-
schema_name
(typename
): schema of the table with the index -
index_name
(typename
): name of the index -
statement
(typetext
): related CREATE INDEX statement of the index
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema
Will return a table composed by following columns:
-
schema_name
(typename
): schema of the table -
table_name
(typename
): name of the table that has the key constraint -
statement
(typetext
): related ADD CONSTRAINT statement of the table
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema
Will return a table composed by following columns:
-
schema_name
(typename
): schema of the table -
table_name
(typename
): name of the table that has the foreign key constraint -
statement
(typetext
): related ADD CONSTRAINT statement of the table
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema
Will return a table composed by following columns:
-
schema_name
(typename
): schema of the table -
table_name
(typename
): name of the table that has the check constraint -
statement
(typetext
): related ADD CONSTRAINT statement of the table
Parameters:
-
plugin
(typename
, required): name of thedb_migrator
plugin to use -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema
Will return a table composed by following columns:
-
schema_name
(typename
): schema of the table -
table_name
(typename
): name of the table whose column has a default value -
statement
(typetext
): related ALTER SET DEFAULT statement of the table
Parameters:
-
operation
(typetext
, required): arbitrary operation description -
schema
(typename
, required): schema of the statements related object -
object_name
(typename
, required): name of the relation concerned by the statements -
statements
(typetext[]
, required): statements to execute in the same subtransaction -
pgstage_schema
(typename
, defaultpgsql_stage
): name of the Postgres staging schema where themigrate_log
table has been created
This function iterates through an array of SQL statements and executes them
inside a subtransaction. If one fails, it raises a detailed warning and inserts
the failed statement and its context into migrate_log
table and all previous
successful statements in the subtransaction are rollbacked.
Returns false
on failure.
A plugin for db_migrator
must be a PostgreSQL extension and provide
a number of functions:
There are no input parameters. The output parameters are:
-
create_metadata_views_fun
(typeregprocedure
): the "metadata view creation function" that populates the FDW stage -
translate_datatype_fun
(typeregprocedure
): the "data type translation function" that tranlates data types from the remote data source into PostgreSQL data types -
translate_identifier_fun
(typeregprocedure
): the "identifier translation function" that translates identifier names from the remote data source into PostgreSQL identifiers -
translate_expression_fun
(typeregprocedure
): the "expression translation function" that makes an effort at translating SQL expressions from the remote data source to PostgreSQL -
create_foreign_table_fun
(typeregprocedure
): the "foreign table creation function" that generates an SQL string to define a foreign table
These functions can have arbitrary names and are described in the following.
Parameters:
-
server
(typename
, required): the name of the foreign server whose metadata we want to access -
schema
(typename
): the name of the FDW staging schema -
options
(typejsonb
, optional): plugin-specific parameters
This function is called by db_migrate_prepare
after creating the FDW
staging schema. It has to create a number of foreign tables (or views on
foreign tables) that provide access to the metadata of the remote data
source.
If the remote data source does not provide a certain feature (for example, if the data source has no concept of triggers), you can create an empty table instead of the corresponding foreign table.
It is allowed to create additional objects in the FDW staging schema if the plugin provides additional features. Similarly, it is allowed to provide other columns beside the ones required by the API specification.
These foreign tables or views must be created:
schemas (
schema text NOT NULL
)
sequences (
schema text NOT NULL,
sequence_name text NOT NULL,
min_value numeric,
max_value numeric,
increment_by numeric NOT NULL,
cyclical boolean NOT NULL,
cache_size integer NOT NULL,
last_value numeric NOT NULL
)
-
min_value
andmax_value
are the minimal and maximal values the sequence value can assume -
last_value
is the current position of the sequence value -
increment_by
is the difference between generated values -
cyclical
isTRUE
for sequences that should continue withmin_value
ifmax_value
is exceeded -
cache_size
is the number of sequence values cached on the client side
tables (
schema text NOT NULL,
table_name text NOT NULL
)
columns (
schema text NOT NULL,
table_name text NOT NULL,
column_name text NOT NULL,
position integer NOT NULL,
type_name text NOT NULL,
length integer NOT NULL,
precision integer,
scale integer,
nullable boolean NOT NULL,
default_value text
)
Note that this table has to contain columns for both the tables
and the views
table.
-
position
defines the order of the table columns -
length
denotes the length limit for variables length data types likecharacter varying
Set this to 0 for data types that have fixed length or where
precision
andscale
apply. -
precision
denotes the number of significant digits for numeric data types of variables size -
scale
denotes the maximum number of significant digits after the decimal point for numeric data types of variable size -
default_value
is the SQL expression from theDEFAULT
clause of the column definition
checks (
schema text NOT NULL,
table_name text NOT NULL,
constraint_name text NOT NULL,
deferrable boolean NOT NULL,
deferred boolean NOT NULL,
condition text NOT NULL
)
-
constraint_name
identifies the constraint, but the name won't be migrated -
deferrable
should beTRUE
if the constraint execution can be deferred to the end of the transaction -
deferred
should beTRUE
if the constraint is automatically deferred -
condition
is the SQL expression that defines the check constraintdb_migrator
will not migrate check constraints of the formcol IS NOT NULL
. You should make sure thatcolumns.nullable
is FALSE for such columns.
keys (
schema text NOT NULL,
table_name text NOT NULL,
constraint_name text NOT NULL,
deferrable boolean NOT NULL,
deferred boolean NOT NULL,
column_name text NOT NULL,
position integer NOT NULL,
is_primary boolean NOT NULL
)
-
constraint_name
identifies the constraint, but the name won't be migrated -
deferrable
should beTRUE
if the constraint execution can be deferred to the end of the transaction -
deferred
should beTRUE
if the constraint is automatically deferred -
position
defines the order of columns in a multi-column constraint -
is_primary
isFALSE
for unique constraints andTRUE
for primary keys
For a multi-column constraint, the table will have one row per column.
foreign_keys (
schema text NOT NULL,
table_name text NOT NULL,
constraint_name text NOT NULL,
deferrable boolean NOT NULL,
deferred boolean NOT NULL,
delete_rule text NOT NULL,
column_name text NOT NULL,
position integer NOT NULL,
remote_schema text NOT NULL,
remote_table text NOT NULL,
remote_column text NOT NULL
)
-
constraint_name
identifies the constraint, but the name won't be migrated -
deferrable
should beTRUE
if the constraint execution can be deferred to the end of the transaction -
deferred
should beTRUE
if the constraint is automatically deferred -
position
defines the order of columns in a multi-column constraint
For a multi-column constraint, the table will have one row per column.
partitions (
schema name NOT NULL,
table_name name NOT NULL,
partition_name name NOT NULL,
type text NOT NULL,
key text NOT NULL,
is_default boolean NOT NULL,
values text[]
)
-
type
is one of the supported partitioning methodsLIST
,RANGE
orHASH
-
key
column name or expression that defines the partitioning key -
values
are partition bound specifications-
for list partitioning,
values
contains the list -
for range partitioning,
values
contains the lower and upper bound (where the lower end is included, but the upper end is excluded) -
for hash partitioning, the only entry in
values
is the remainder for this partition
Non-numeric values like timestamps have to be quoted as string constants (for example
ARRAY['''2022-01-01''','''2023-01-01''']
). -
-
is_default
isTRUE
if it is the default partition
subpartitions (
schema name NOT NULL,
table_name name NOT NULL,
partition_name name NOT NULL,
subpartition_name name NOT NULL,
type text NOT NULL,
key text NOT NULL,
is_default boolean NOT NULL,
values text[]
)
For explanations, see partitions
above.
views (
schema text NOT NULL,
view_name text NOT NULL,
definition text NOT NULL
)
definition
is theSELECT
statement that defines the view
The columns of the view are defines in the columns
table.
functions (
schema text NOT NULL,
function_name text NOT NULL,
is_procedure boolean NOT NULL,
source text NOT NULL
)
-
is_procedure
isFALSE
for functions andTRUE
for procedures -
source
is the source code of the function, including the parameter list and the return type
indexes (
schema text NOT NULL,
table_name text NOT NULL,
index_name text NOT NULL,
uniqueness boolean NOT NULL,
where_clause text
)
-
index_name
identifies the index, but the name won't be migrated -
uniqueness
isTRUE
for unique indexes -
where_clause
is a partial index expression or NULL
index_columns (
schema text NOT NULL,
table_name text NOT NULL,
index_name text NOT NULL,
position integer NOT NULL,
descend boolean NOT NULL,
is_expression boolean NOT NULL,
column_name text NOT NULL
)
-
position
defines the order of columns in a multi-column index -
descend
isFALSE
for index columns in ascending sort order andTRUE
for index columns in descending sort order -
is_expression
isFALSE
ifcolumn_name
is a regular column name rather than an expression -
column_name
is the indexed column name or expression
triggers (
schema text NOT NULL,
table_name text NOT NULL,
trigger_name text NOT NULL,
trigger_type text NOT NULL,
triggering_event text NOT NULL,
for_each_row boolean NOT NULL,
when_clause text,
trigger_body text NOT NULL
)
-
trigger_type
should beBEFORE
,AFTER
orINSTEAD OF
-
triggering_event
describes the DML events that cause trigger execution, likeDELETE
orINSERT OR UPDATE
-
for_each_row
isFALSE
for statement level triggers andTRUE
for row level triggers -
when_clause
is an SQL expression for conditional trigger execution -
trigger_body
is the source code of the trigger
table_privs (
schema text NOT NULL,
table_name text NOT NULL,
privilege text NOT NULL,
grantor text NOT NULL,
grantee text NOT NULL,
grantable boolean NOT NULL
)
column_privs (
schema text NOT NULL,
table_name text NOT NULL,
column_name text NOT NULL,
privilege text NOT NULL,
grantor text NOT NULL,
grantee text NOT NULL,
grantable boolean NOT NULL
)
Parameters:
-
type name (type
text
): the name of the data type on the remote data source -
length (type
integer
): the maximal length for non-numeric data types of variable length -
precision (type
integer
): the maximal number of significant digits for numeric data types of variable length -
scale (type
integer
): the number of digits after the decimal point for numeric data types of variable length
Result type: text
This function translates data types from the remote data source to PostgreSQL
data types. The result should include the type modifiers if applicable,
for example character varying(20)
.
Parameters:
- identifier name (type
text
): the name of the identifier on the remote data source
Result type: name
This function should generate a PostgreSQL object or column name. If no translation is required, the function should just return its argument, which will automatically be truncated to 63 bytes.
Parameters:
- SQL expression (type
text
): SQL expression from the remote data source as used in column defaults, check constraints or index definitions
Result type: text
This function should make a best effort in automatically translating expressions between the SQL dialects. Anything that this function cannot translate will have to be translated by hand during the migration.
Parameters:
-
foreign server (type
name
): the PostgreSQL foreign server to migrate -
schema (type
name
): PostgreSQL schema name for the foreign table -
table name (type
name
): PostgreSQL name of the foreign table -
original schema (type
text
): schema of the table on the remote data source -
original table name (type
text
): name of the table on the remote data source -
column names (type
name[]
): names for the foreign table columns -
column options (type
jsonb[]
): plugin-specific FDW column options -
original column names (type
text[]
): names of the columns on the remote data source -
data types (type
text[]
): data types for the foreign table columns -
nullable (type
boolean[]
):FALSE
if the foreign table column isNOT NULL
-
extra options (type
jsonb
): options specific to the plugin; this is passed through from theoptions
argument ofdb_migrate_mkforeign
Result type: text
This function generates a CREATE FOREIGN TABLE
statement that creates
a foreign table with these definitions. This is required because the syntax
varies between foreign data wrappers.
Contributions are always welcome!
See CONTRIBUTING.md for ways to get started.
Create an issue on Github or contact CYBERTEC PostgreSQL International GmbH.