1 Non blocking DBExport
Use this procedure to make database export without exclusive access and avoiding sessions block.
CREATE FUNCTION export_system(load_dir VARCHAR(50) ) RETURNING INTEGER, INTEGER DEFINE rc INTEGER; DEFINE bad INTEGER; DEFINE create_ext_tab LVARCHAR(8192); DEFINE ins LVARCHAR(512); DEFINE drop_ext_tab LVARCHAR(512); DEFINE tname VARCHAR(250); DEFINE dbschema LVARCHAR(1024); DEFINE dbname VARCHAR(250); DEFINE numrows INTEGER; -- SET DEBUG FILE TO "/tmp/spl_debug.log"; -- TRACE ON; LET rc=0; LET bad=0; LET dbname = DBINFO("dbname"); LET dbschema = "dbschema -q -d "||TRIM(dbname)||" -it DR -ss "|| TRIM(load_dir)||"/"||TRIM(dbname)||".sql"; SYSTEM dbschema; SET ISOLATION TO DIRTY READ; FOREACH SELECT TRIM(tabname) ,nrows INTO tname,numrows FROM systables WHERE tabid >99 AND tabtype = "T" LET create_ext_tab = "CREATE EXTERNAL TABLE "||tname||"_ext "|| " SAMEAS "||tname||" USING (" || "DATAFILES('DISK:"||load_dir||"/"||tname||".unl'),"|| "FORMAT 'DELIMITED', "|| "DELIMITER '|', "|| "RECORDEND '', "|| "DELUXE, ESCAPE, "|| "NUMROWS "|| numrows+1||", "|| "MAXERRORS 100, "|| "REJECTFILE '"||load_dir||"/"||tname||".reject' " || " )"; LET ins = "INSERT INTO "||tname||"_ext SELECT * FROM "||tname; LET drop_ext_tab = "DROP TABLE "||tname||"_ext"; EXECUTE IMMEDIATE create_ext_tab; EXECUTE IMMEDIATE ins; EXECUTE IMMEDIATE drop_ext_tab; LET rc = rc + 1; END FOREACH RETURN rc, bad; END FUNCTION;
2 DBImport non blocking export
If you want to restore the previous exported extructure you can do it following this procedure.
First create database where you want to import unloaded files. You can create this database in the dbspace you require. We recommend creating this database without logging and after importing change log mode manually.
$ echo "CREATE DATABASE db_imported IN mydbspace" | dbaccess -
Exported data using the previous DBExport method, can have missing "primary-foreign" keys relationships.
You will need to deal with these problems manually. To avoid issues when loading data, it's recommended to check the sql file created by DBExport procedure and split it.
Search first foreign key creation statement in file and split sql file in two parts:
- First with all statements previous to first foreign key creation.
- Second with all statements after and including first foreign key creation.
You can try to automate this split method by executing this commands:
sed -e '/(foreign/q' db_exported.sql | grep -E -v "\(foreign" > db_exported_part1.sql sed -n `sed -n -e '/(foreign/=' db_exported.sql | head -1`',$p' db_exported.sql > db_exported_part2.sql
Where db_exported.sql is the SQL file generated by your DBExport function execution.
Execute first sql part. This will create all tables and some (not all) indexes.
dbaccess db_imported db_exported_part1.sql
After this, create import_system function and execute it passing the unloaded data folder as a parameter. This will load all unloaded files into the database tables.
echo 'EXECUTE FUNCTION import_system("/data/MYEXPORT")' | dbaccess db_imported
Errors thrown in this execution should be resolved manually by editing sql schema creation files and recreate database, or by editing unload file for table and removing the offending data.
After this procedure completed successfully, you can complete database creation by executing the second sql splitted file.
dbaccess db_imported db_exported_part2.sql
CREATE FUNCTION import_system(load_dir VARCHAR(50) ) RETURNING INTEGER, INTEGER DEFINE rc INTEGER; DEFINE bad INTEGER; DEFINE create_ext_tab LVARCHAR(8192); DEFINE ins LVARCHAR(512); DEFINE drop_ext_tab LVARCHAR(512); DEFINE tname VARCHAR(250); DEFINE dbschema LVARCHAR(1024); DEFINE dbname VARCHAR(250); DEFINE numrows INTEGER; -- SET DEBUG FILE TO "/tmp/spl_debug.log"; -- TRACE ON; LET rc=0; LET bad=0; LET dbname = DBINFO("dbname"); -- Commented. Better do it manually -- LET dbschema = "dbaccess "||TRIM(dbname)||" "||TRIM(load_dir)||"/"||TRIM(dbname)||".sql"; --SYSTEM dbschema; --Do no execute transactional modes in non-transactional db --SET ISOLATION TO DIRTY READ; FOREACH SELECT TRIM(tabname) ,nrows INTO tname,numrows FROM systables WHERE tabid >99 AND tabtype = "T" LET create_ext_tab = "CREATE EXTERNAL TABLE "||tname||"_ext "|| " SAMEAS "||tname||" USING (" || "DATAFILES('DISK:"||load_dir||"/"||tname||".unl'),"|| "FORMAT 'DELIMITED', "|| "DELIMITER '|', "|| "RECORDEND '', "|| "DELUXE, ESCAPE, "|| "NUMROWS "|| numrows+1||", "|| "MAXERRORS 100, "|| "REJECTFILE '"||load_dir||"/"||tname||".reject' " || " )"; LET ins = "INSERT INTO "||tname||" SELECT * FROM "||tname||"_ext"; LET drop_ext_tab = "DROP TABLE "||tname||"_ext"; EXECUTE IMMEDIATE create_ext_tab; EXECUTE IMMEDIATE ins; EXECUTE IMMEDIATE drop_ext_tab; LET rc = rc + 1; END FOREACH RETURN rc, bad; END FUNCTION;