Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with HTTPS or Subversion.

Download ZIP
Browse files

fix mysql2pgsql migration script

  • Loading branch information...
commit 100396e895f3e272a4ab5913a4d6c8771f03077d 1 parent 078dbcd
@pjstevns authored
Showing with 90 additions and 56 deletions.
  1. +56 −56 contrib/sql2sql/mysql2pgsql.sh
  2. +34 −0 contrib/sql2sql/mysql2pgsql.yml
View
112 contrib/sql2sql/mysql2pgsql.sh
@@ -1,109 +1,109 @@
#!/bin/bash
+# this script can be used to migrate from MySQL to PostgreSQL
+#
+# check postgresql.conf:
+#
+# bytea_output = 'escape'
+# escape_string_warning = off
+# standard_conforming_strings = off
+#
+# this script requires py-mysql2pgsql which utilizes the yaml script in
+# this directory. Please edit the yaml file to match your setup.
+#
+
+set -e
+
MYDB="dbmail"
PGDB="dbmail"
PGDD="../../sql/postgresql/create_tables.pgsql"
-TMPDIR="/opt/tmp"
export tables="
dbmail_users
dbmail_mailboxes
dbmail_physmessage
dbmail_messages
-dbmail_messageblks
dbmail_aliases
dbmail_acl
+dbmail_authlog
dbmail_auto_notifications
dbmail_auto_replies
-dbmail_ccfield
-dbmail_datefield
-dbmail_envelope
-dbmail_fromfield
-dbmail_headername
-dbmail_headervalue
-dbmail_pbsp
-dbmail_referencesfield
+dbmail_filters
+dbmail_keywords
dbmail_replycache
-dbmail_replytofield
dbmail_sievescripts
-dbmail_subjectfield
dbmail_subscription
-dbmail_tofield
dbmail_usermap
"
-export_mysql()
-{
- dumpfile=$TMPDIR/dbmail.mysqldata
- [ -e "$dumpfile" ] && return 1
- echo -n "export from mysql ..."
- mysqldump --skip-opt --single-transaction --hex-blob --compatible=postgresql -q -t -c $MYDB $tables > $dumpfile
- echo "done"
-}
-
init_pgsql()
{
- dropdb dbmail >/dev/null 2>&1
- createdb dbmail >/dev/null 2>&1
- psql dbmail < ../../sql/postgresql/create_tables.pgsql >/dev/null 2>&1 || { echo "create db failed. abort."; exit 1; }
- echo "delete from dbmail_users;"|psql dbmail
-
+ echo "clean out old DB ..."
+ dropdb $PGDB >/dev/null 2>&1
+ echo "create fresh DB ..."
+ createdb -E UTF-8 -O dbmail $PGDB >/dev/null 2>&1
+ echo "create schema ..."
+ psql $PGDB < $PGDD >/dev/null 2>&1 || { echo "create db failed. abort."; exit 1; }
+ echo "delete from dbmail_users;"|psql $PGDB >/dev/null 2>&1
+ pgsql_owner
}
+
import_pgsql()
{
- dumpfile=$TMPDIR/dbmail.mysqldata
- echo -n "import into pgsql ..."
- cat $dumpfile | psql -q dbmail
- echo "done."
+ for table in `echo $tables`; do
+ echo -n " migrate table: $table ..."
+ mysqldump --compatible=postgresql -t --compact -c dbmail $table|psql dbmail >/dev/null 2>&1
+ echo "done."
+ done
+ echo " migrate tables: mimeparts, partlists ..."
+ py-mysql2pgsql -v 2>/dev/null
+ pgsql_sequences
return $?
}
pgsql_sequences()
{
+ echo -e "reset sequences ..."
qfile=`tempfile`
cat >> $qfile << EOQ
BEGIN;
-SELECT setval('dbmail_alias_idnr_seq', max(alias_idnr)) FROM dbmail_aliases;
-SELECT setval('dbmail_user_idnr_seq', max(user_idnr)) FROM dbmail_users;
-SELECT setval('dbmail_mailbox_idnr_seq', max(mailbox_idnr)) FROM dbmail_mailboxes;
-SELECT setval('dbmail_physmessage_id_seq', max(id)) FROM dbmail_physmessage;
-SELECT setval('dbmail_message_idnr_seq', max(message_idnr)) FROM dbmail_messages;
-SELECT setval('dbmail_messageblk_idnr_seq', max(messageblk_idnr)) FROM dbmail_messageblks;
-SELECT setval('dbmail_seq_pbsp_id', max(idnr)) FROM dbmail_pbsp;
-SELECT setval('dbmail_headername_idnr_seq', max(id)) FROM dbmail_headername;
-SELECT setval('dbmail_headervalue_idnr_seq', max(id)) FROM dbmail_headervalue;
-SELECT setval('dbmail_subjectfield_idnr_seq', max(id)) FROM dbmail_subjectfield;
-SELECT setval('dbmail_datefield_idnr_seq', max(id)) FROM dbmail_datefield;
-SELECT setval('dbmail_referencesfield_idnr_seq', max(id)) FROM dbmail_referencesfield;;
-SELECT setval('dbmail_fromfield_idnr_seq', max(id)) FROM dbmail_fromfield;
-SELECT setval('dbmail_tofield_idnr_seq', max(id)) FROM dbmail_tofield;
-SELECT setval('dbmail_replytofield_idnr_seq', max(id)) FROM dbmail_replytofield;
-SELECT setval('dbmail_ccfield_idnr_seq', max(id)) FROM dbmail_ccfield;
-SELECT setval('dbmail_sievescripts_idnr_seq', max(id)) FROM dbmail_sievescripts;
-SELECT setval('dbmail_envelope_idnr_seq', max(id)) FROM dbmail_envelope;
+SELECT setval('dbmail_alias_idnr_seq', max(alias_idnr)+1) FROM dbmail_aliases;
+SELECT setval('dbmail_user_idnr_seq', max(user_idnr)+1) FROM dbmail_users;
+SELECT setval('dbmail_mailbox_idnr_seq', max(mailbox_idnr)+1) FROM dbmail_mailboxes;
+SELECT setval('dbmail_physmessage_id_seq', max(id)+1) FROM dbmail_physmessage;
+SELECT setval('dbmail_message_idnr_seq', max(message_idnr)+1) FROM dbmail_messages;
+SELECT setval('dbmail_seq_pbsp_id', max(idnr)+1) FROM dbmail_pbsp;
+SELECT setval('dbmail_headername_id_seq', max(id)+1) FROM dbmail_headername;
+SELECT setval('dbmail_headervalue_id_seq', max(id)+1) FROM dbmail_headervalue;
+SELECT setval('dbmail_referencesfield_idnr_seq', max(id)+1) FROM dbmail_referencesfield;;
+SELECT setval('dbmail_sievescripts_idnr_seq', max(id)+1) FROM dbmail_sievescripts;
+SELECT setval('dbmail_envelope_idnr_seq', max(id)+1) FROM dbmail_envelope;
+SELECT setval('dbmail_authlog_id_seq', max(id)+1) FROM dbmail_authlog;
+SELECT setval('dbmail_filters_id_seq', max(id)+1) FROM dbmail_filters;
+SELECT setval('dbmail_mimeparts_id_seq', max(id)+1) FROM dbmail_mimeparts;
END;
EOQ
- psql -q dbmail < $qfile
+ psql -q $PGDB < $qfile >/dev/null 2>&1
+ echo "done."
rm -f $qfile
}
pgsql_owner()
{
- for t in `echo '\d'|psql dbmail|grep root|awk '{print $3}'`; do
- echo "alter table $t owner to dbmail;"|psql -q dbmail
+ echo -n "fix ownership ..."
+ for t in `echo '\d'|psql $PGDB|grep public |awk '{print $3}'`; do
+ echo "alter table $t owner to dbmail;"|psql -q $PGDB >/dev/null 2>&1
done
+ echo "done."
}
main()
{
- install -d -m 7777 $TMPDIR || { echo "unable to access $TMPDIR"; exit 1; }
- #export_mysql || { echo "Export failed"; exit 1; }
init_pgsql
import_pgsql || { echo "Import failed"; exit 1; }
- pgsql_sequences
- pgsql_owner
+ echo "Data migration complete. Now rebuild all caching tables using dbmail-util -by."
}
View
34 contrib/sql2sql/mysql2pgsql.yml
@@ -0,0 +1,34 @@
+
+# if a socket is specified we will use that
+# if tcp is chosen you can use compression
+mysql:
+ hostname: localhost
+ port: 3306
+ socket: /var/run/mysqld/mysqld.sock
+ username: dbmail
+ password:
+ database: dbmail
+ compress: false
+destination:
+ # if file is given, output goes to file, else postgres
+ file:
+ postgres:
+ hostname: localhost
+ port: 5432
+ username: dbmail
+ password:
+ database: dbmail
+
+# if tables is given, only the listed tables will be converted. leave empty to convert all tables.
+only_tables:
+- dbmail_mimeparts
+- dbmail_partlists
+
+# if supress_data is true, only the schema definition will be exported/migrated, and not the data
+supress_data: false
+
+# if supress_ddl is true, only the data will be exported/imported, and not the schema
+supress_ddl: true
+
+# if force_truncate is true, forces a table truncate before table loading
+force_truncate: false
Please sign in to comment.
Something went wrong with that request. Please try again.