3 # MySQL to PostgreSQL dump file converter
5 # For usage: perl mysql2pgsql.perl --help
7 # ddl statments are changed but none or only minimal real data
9 # data consistency is up to the DBA.
11 # (c) 2004-2007 Jose M Duarte and Joseph Speigle ... gborg
13 # (c) 2000-2004 Maxim Rudensky <fonin@omnistaronline.com>
14 # (c) 2000 Valentine Danilchuk <valdan@ziet.zhitomir.ua>
15 # All rights reserved.
17 # Redistribution and use in source and binary forms, with or without
18 # modification, are permitted provided that the following conditions
20 # 1. Redistributions of source code must retain the above copyright
21 # notice, this list of conditions and the following disclaimer.
22 # 2. Redistributions in binary form must reproduce the above copyright
23 # notice, this list of conditions and the following disclaimer in the
24 # documentation and/or other materials provided with the distribution.
25 # 3. All advertising materials mentioning features or use of this software
26 # must display the following acknowledgement:
27 # This product includes software developed by the Max Rudensky
28 # and its contributors.
29 # 4. Neither the name of the author nor the names of its contributors
30 # may be used to endorse or promote products derived from this software
31 # without specific prior written permission.
32 # THIS SOFTWARE IS PROVIDED BY THE AUTHOR AND CONTRIBUTORS ``AS IS'' AND
33 # ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE
34 # IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE
35 # ARE DISCLAIMED. IN NO EVENT SHALL THE AUTHOR OR CONTRIBUTORS BE LIABLE
36 # FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL
37 # DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS
38 # OR SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION)
39 # HOWEVER CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT
40 # LIABILITY, OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY
41 # OUT OF THE USE OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF
54 # 1 variable declarations
56 # 3 get commandline options and specify help statement
57 # 4 loop through file and process
58 # 5. print_plpgsql function prototype
60 #################################################################
61 # 1. variable declarations
62 #################################################################
63 # command line options
64 my( $ENC_IN, $ENC_OUT, $PRESERVE_CASE, $HELP, $DEBUG, $SCHEMA, $LOWERCASE, $CHAR2VARCHAR, $NODROP, $SEP_FILE, $opt_debug, $opt_help, $opt_schema, $opt_preserve_case, $opt_char2varchar, $opt_nodrop, $opt_sepfile, $opt_enc_in, $opt_enc_out );
65 # variables for constructing pre-create-table entities
66 my $pre_create_sql=''; # comments, 'enum' constraints preceding create table statement
67 my $auto_increment_seq= ''; # so we can easily substitute it if we need a default value
68 my $create_sql=''; # all the datatypes in the create table section
69 my $post_create_sql=''; # create indexes, foreign keys, table comments
70 my $function_create_sql = ''; # for the set (function,trigger) and CURRENT_TIMESTAMP ( function,trigger )
72 my ($type, $column_valuesStr, @column_values, $value );
73 my %constraints=(); # holds values constraints used to emulate mysql datatypes (e.g. year, set)
74 # datatype conversion variables
76 my ( $column_name, $col, $quoted_column);
77 my ( @year_holder, $year, $constraint_table_name);
78 my $table=""; # table_name for create sql statements
79 my $table_no_quotes=""; # table_name for create sql statements
80 my $sl = '^\s+\w+\s+'; # matches the column name
81 my $tables_first_timestamp_column= 1; # decision to print warnings about default_timestamp not being in postgres
82 my $mysql_numeric_datatypes = "TINYINT|SMALLINT|MEDIUMINT|INT|INTEGER|BIGINT|REAL|DOUBLE|FLOAT|DECIMAL|NUMERIC";
83 my $mysql_datetime_datatypes = "|DATE|TIME|TIMESTAMP|DATETIME|YEAR";
84 my $mysql_text_datatypes = "CHAR|VARCHAR|BINARY|VARBINARY|TINYBLOB|BLOB|MEDIUMBLOB|LONGBLOB|TINYTEXT|TEXT|MEDIUMTEXT|LONGTEXT|ENUM|SET";
85 my $mysql_datatypesStr = $mysql_numeric_datatypes . "|". $mysql_datetime_datatypes . "|". $mysql_text_datatypes ;
86 # handling INSERT INTO statements
92 [^'\\]* # up to string-end or backslash (escape)
94 \\. # gobble escaped character
95 [^'\\]* # up to string-end of backslash
96 )* # (end group, repeat zero or more)
99 .*? # everything else (not strings)
100 )* # (end group, repeat zero or more)
105 my ($insert_table, $valueString);
107 ########################################################
111 # print_post_create_sql()
113 # make_plpgsql($table,$column_name) -- at end of file
114 ########################################################
116 # returns an identifier with the given suffix doing controlled
117 # truncation if necessary
118 sub get_identifier($$$) {
119 my ($table, $col, $suffix) = @_;
121 $table=~s/\"//g; # make sure that $table doesn't have quotes so we don't end up with redundant quoting
122 # in the case of multiple columns
123 my @cols = split(/,/,$col);
125 # in case all columns together too long we have to truncate them
126 if (length($col) > 55) {
127 my $totaltocut = length($col)-55;
128 my $tocut = ceil($totaltocut / @cols);
129 @cols = map {substr($_,0,abs(length($_)-$tocut))} @cols;
136 my $max_table_length = 63 - length("_${col}_$suffix");
138 if (length($table) > $max_table_length) {
139 $table = substr($table, length($table) - $max_table_length, $max_table_length);
141 return quote_and_lc("${table}_${col}_${suffix}");
147 # called when we encounter next CREATE TABLE statement
148 # also called at EOF to print out for last table
149 # prints comments, indexes, foreign key constraints (the latter 2 possibly to a separate file)
150 sub print_post_create_sql() {
151 my ( @create_idx_comments_constraints_commandsArr, $stmts, $table_field_combination);
153 # loop to check for duplicates in $post_create_sql
154 # Needed because of duplicate key declarations ( PRIMARY KEY and KEY), auto_increment columns
156 @create_idx_comments_constraints_commandsArr = split(';\n?', $post_create_sql);
158 open(SEP_FILE, ">>:encoding($ENC_OUT)", $SEP_FILE) or die "Unable to open $SEP_FILE for output: $!\n";
161 foreach (@create_idx_comments_constraints_commandsArr) {
162 if (m/CREATE INDEX "*(\S+)"*\s/i) { # CREATE INDEX korean_english_wordsize_idx ON korean_english USING btree (wordsize);
163 $table_field_combination = $1;
164 # if this particular table_field_combination was already used do not print the statement:
166 print SEP_FILE "$_;\n" if !defined($stmts{$table_field_combination});
168 print OUT "$_;\n" if !defined($stmts{$table_field_combination});
170 $stmts{$table_field_combination} = 1;
172 elsif (m/COMMENT/i) { # COMMENT ON object IS 'text'; but comment may be part of table name so use 'elsif'
174 } else { # foreign key constraint or comments (those preceded by -- )
176 print SEP_FILE "$_;\n";
187 # empty %constraints for next " create table" statement
190 # quotes a string or a multicolumn string (comma separated)
191 # and optionally lowercase (if LOWERCASE is set)
192 # lowercase .... if user wants default postgres behavior
193 # quotes .... to preserve keywords and to preserve case when case-sensitive tables are to be used
201 my @cols = split(/,\s?/, $col);
202 @cols = map {"\"$_\""} @cols;
203 return join(', ', @cols);
209 ########################################################
210 # 3. get commandline options and maybe print help
211 ########################################################
213 GetOptions("help", "debug"=> \$opt_debug, "schema=s" => \$SCHEMA, "preserve_case" => \$opt_preserve_case, "char2varchar" => \$opt_char2varchar, "nodrop" => \$opt_nodrop, "sepfile=s" => \$opt_sepfile, "enc_in=s" => \$opt_enc_in, "enc_out=s" => \$opt_enc_out );
215 $HELP = $opt_help || 0;
216 $DEBUG = $opt_debug || 0;
217 $PRESERVE_CASE = $opt_preserve_case || 0;
218 if ($PRESERVE_CASE == 1) { $LOWERCASE = 0; }
219 else { $LOWERCASE = 1; }
220 $CHAR2VARCHAR = $opt_char2varchar || 0;
221 $NODROP = $opt_nodrop || 0;
222 $SEP_FILE = $opt_sepfile || 0;
223 $ENC_IN = $opt_enc_in || 'utf8';
224 $ENC_OUT = $opt_enc_out || 'utf8';
226 if (($HELP) || ! defined($ARGV[0]) || ! defined($ARGV[1])) {
227 print "\n\nUsage: perl $0 {--help --debug --preserve_case --char2varchar --nodrop --schema --sepfile --enc_in --enc_out } mysql.sql pg.sql\n";
228 print "\t* OPTIONS WITHOUT ARGS\n";
229 print "\t--help: prints this message \n";
230 print "\t--debug: output the commented-out mysql line above the postgres line in pg.sql \n";
231 print "\t--preserve_case: prevents automatic case-lowering of column and table names\n";
232 print "\t\tIf you want to preserve case, you must set this flag. For example,\n";
233 print "\t\tIf your client application quotes table and column-names and they have cases in them, set this flag\n";
234 print "\t--char2varchar: converts all char fields to varchar\n";
235 print "\t--nodrop: strips out DROP TABLE statements\n";
236 print "\t\totherise harmless warnings are printed by psql when the dropped table does not exist\n";
237 print "\n\t* OPTIONS WITH ARGS\n";
238 print "\t--schema: outputs a line into the postgres sql file setting search_path \n";
239 print "\t--sepfile: output foreign key constraints and indexes to a separate file so that it can be\n";
240 print "\t\timported after large data set is inserted from another dump file\n";
241 print "\t--enc_in: encoding of mysql in file (default utf8) \n";
242 print "\t--enc_out: encoding of postgres out file (default utf8) \n";
243 print "\n\t* REQUIRED ARGUMENTS\n";
244 if (defined ($ARGV[0])) {
245 print "\tmysql.sql ($ARGV[0])\n";
247 print "\tmysql.sql (undefined)\n";
249 if (defined ($ARGV[1])) {
250 print "\tpg.sql ($ARGV[1])\n";
252 print "\tpg.sql (undefined)\n";
257 ########################################################
258 # 4. process through mysql_dump.sql file
260 ########################################################
262 # open in and out files
263 open(IN,"<:encoding($ENC_IN)", $ARGV[0]) || die "can't open mysql dump file $ARGV[0]";
264 open(OUT,">:encoding($ENC_OUT)", $ARGV[1]) || die "can't open pg dump file $ARGV[1]";
268 print OUT "-- Generated from mysql2pgsql.perl\n";
269 print OUT "-- http://gborg.postgresql.org/project/mysql2psql/\n";
270 print OUT "-- (c) 2001 - 2007 Jose M. Duarte, Joseph Speigle\n";
273 print OUT "-- warnings are printed for drop tables if they do not exist\n";
274 print OUT "-- please see http://archives.postgresql.org/pgsql-novice/2004-10/msg00158.php\n\n";
275 print OUT "-- ##############################################################\n";
278 print OUT "set search_path='" . $SCHEMA . "'\\g\n" ;
281 # loop through mysql file on a per-line basis
284 ############## flow #########################
285 # (the lines are directed to different string variables at different times)
287 # handle drop table , unlock, connect statements
288 # if ( start of create table) {
289 # print out post_create table (indexes, foreign key constraints, comments from previous table)
290 # add drop table statement if !$NODROP to pre_create_sql
293 # else if ( inside create table) {
294 # add comments in this portion to create_sql
295 # if ( end of create table) {
296 # delete mysql-unique CREATE TABLE commands
297 # print pre_create_sql
298 # print the constraint tables for set and year datatypes
300 # print function_create_sql (this is for the enum columns only)
304 # -- NUMERIC DATATYPES
305 # -- CHARACTER DATATYPES
306 # -- DATE AND TIME DATATYPES
307 # -- KEY AND UNIQUE CREATIONS
308 # and append them to create_sql
310 # print inserts on-the-spot (this script only changes default timestamp of 0000-00-00)
314 ########################################################
317 if (!/^\s*insert into/i) { # not inside create table so don't worry about data corruption
318 s/`//g; # '`pgsql uses no backticks to denote table name (CREATE TABLE `sd`) or around field
319 # and table names like mysql
320 # doh! we hope all dashes and special chars are caught by the regular expressions :)
322 if (/^\s*USE\s*([^;]*);/) {
323 print OUT "\\c ". $1;
326 if (/^(UN)?LOCK TABLES/i || /drop\s+table/i ) {
329 # DROP TABLE is added when we see the CREATE TABLE
332 if (/(create\s+table\s+)([-_\w]+)\s/i) { # example: CREATE TABLE `english_english`
333 print_post_create_sql(); # for last table
334 $tables_first_timestamp_column= 1; # decision to print warnings about default_timestamp not being in postgres
336 $table_no_quotes = $2 ;
337 $table=quote_and_lc($2);
338 if ( !$NODROP ) { # always print drop table if user doesn't explicitly say not to
339 # to drop a table that is referenced by a view or a foreign-key constraint of another table,
340 # CASCADE must be specified. (CASCADE will remove a dependent view entirely, but in the
341 # in the foreign-key case it will only remove the foreign-key constraint, not the other table entirely.)
342 # (source: 8.1.3 docs, section "drop table")
343 warn "table $table will be dropped CASCADE\n";
344 $pre_create_sql .= "DROP TABLE $table CASCADE;\n"; # custom dumps may be missing the 'dump' commands
347 s/(create\s+table\s+)([-_\w]+)\s/$1 $table /i;
349 $create_sql .= '-- ' . $_;
354 if ($create_sql ne "") { # we are inside create table statement so lets process datatypes
355 # print out comments or empty lines in context
357 $create_sql .= '-- ' . $_;
359 if (/^#/ || /^$/ || /^\s*--/) {
360 s/^#/--/; # Two hyphens (--) is the SQL-92 standard indicator for comments
365 if (/\).*;/i) { # end of create table squence
367 s/INSERT METHOD[=\s+][^;\s]+//i;
368 s/PASSWORD=[^;\s]+//i;
369 s/ROW_FORMAT=(?:DEFAULT|DYNAMIC|FIXED|COMPRESSED|REDUNDANT|COMPACT)+//i;
370 s/KEY_BLOCK_SIZE=8//i;
371 s/DELAY KEY WRITE=[^;\s]+//i;
372 s/INDEX DIRECTORY[=\s+][^;\s]+//i;
373 s/DATA DIRECTORY=[^;\s]+//i;
374 s/CONNECTION=[^;\s]+//i;
375 s/CHECKSUM=[^;\s]+//i;
376 s/Type=[^;\s]+//i; # ISAM , # older versions
377 s/COLLATE=[^;\s]+//i; # table's collate
378 s/COLLATE\s+[^;\s]+//i; # table's collate
379 # possible AUTO_INCREMENT starting index, it is used in mysql 5.0.26, not sure since which version
380 if (/AUTO_INCREMENT=(\d+)/i) {
381 # should take < ---- ) ENGINE=MyISAM AUTO_INCREMENT=16 DEFAULT CHARSET=latin1;
382 # and should ouput ---> CREATE SEQUENCE "rhm_host_info_id_seq" START WITH 16;
383 my $start_value = $1;
384 print $auto_increment_seq . "--\n";
385 # print $pre_create_sql . "--\n";
386 $pre_create_sql =~ s/(CREATE SEQUENCE $auto_increment_seq )/$1 START WITH $start_value /;
388 s/AUTO_INCREMENT=\d+//i;
389 s/PACK_KEYS=\d//i; # mysql 5.0.22
390 s/DEFAULT CHARSET=[^;\s]+//i; # my mysql version is 4.1.11
391 s/ENGINE\s*=\s*[^;\s]+//i; # my mysql version is 4.1.11
392 s/ROW_FORMAT=[^;\s]+//i; # my mysql version is 5.0.22
393 s/KEY_BLOCK_SIZE=8//i;
394 s/MIN_ROWS=[^;\s]+//i;
395 s/MAX_ROWS=[^;\s]+//i;
396 s/AVG_ROW_LENGTH=[^;\s]+//i;
397 if (/COMMENT='([^']*)'/) { # ) ENGINE=MyISAM DEFAULT CHARSET=utf8 COMMENT='must be country zones';
398 $post_create_sql.="COMMENT ON TABLE $table IS '$1'\;"; # COMMENT ON table_name IS 'text';
399 s/COMMENT='[^']*'//i;
401 $create_sql =~ s/,$//g; # strip last , inside create table
402 # make sure we end in a comma, as KEY statments are turned
403 # into post_create_sql indices
404 # they often are the last line so leaving a 'hanging comma'
405 my @array = split("\n", $create_sql);
406 for (my $a = $#array; $a >= 0; $a--) { #loop backwards
407 if ($a == $#array && $array[$a] =~ m/,\s*$/) { # for last line
408 $array[$a] =~ s/,\s*$//;
411 if ($array[$a] !~ m/create table/i) { # i.e. if there was more than one column in table
412 if ($a != $#array && $array[$a] !~ m/,\s*$/ ) { # for second to last
413 $array[$a] =~ s/$/,/;
416 elsif ($a != $#array && $array[$a] =~ m/,\s*$/ ) { # for second to last
421 $create_sql = join("\n", @array) . "\n";
424 # put comments out first
425 print OUT $pre_create_sql;
427 # create separate table to reference and to hold mysql's possible set data-type
428 # values. do that table's creation before create table
430 foreach $column_name (keys %constraints) {
431 $type=$constraints{$column_name}{'type'};
432 $column_valuesStr = $constraints{$column_name}{'values'};
433 $constraint_table_name = get_identifier(${table},${column_name} ,"constraint_table");
434 if ($type eq 'set') {
435 print OUT qq~DROP TABLE $constraint_table_name CASCADE\\g\n~ ;
436 print OUT qq~create table $constraint_table_name ( set_values varchar UNIQUE)\\g\n~ ;
437 $function_create_sql .= make_plpgsql($table,$column_name);
438 } elsif ($type eq 'year') {
439 print OUT qq~DROP TABLE $constraint_table_name CASCADE\\g\n~ ;
440 print OUT qq~create table $constraint_table_name ( year_values varchar UNIQUE)\\g\n~ ;
442 @column_values = split /,/, $column_valuesStr;
443 foreach $value (@column_values) {
444 print OUT qq~insert into $constraint_table_name values ( $value )\\g\n~; # ad ' for ints and varchars
448 $create_sql =~ s/double double/double precision/g;
450 # print create table and reset create table vars
451 # when moving from each "create table" to "insert" part of dump
452 print OUT $create_sql;
453 print OUT $function_create_sql;
455 $auto_increment_seq="";
457 $function_create_sql='';
459 # the post_create_sql for this table is output at the beginning of the next table def
460 # in case we want to make indexes after doing inserting
463 if (/^\s*(\w+)\s+.*COMMENT\s*'([^']*)'/) { #`zone_country_id` int(11) COMMENT 'column comment here',
464 $quoted_column=quote_and_lc($1);
465 $post_create_sql.="COMMENT ON COLUMN $table"."."." $quoted_column IS '$2'\;"; # COMMENT ON table_name.column_name IS 'text';
466 s/COMMENT\s*'[^']*'//i;
472 # auto_increment -> sequences
473 # UNSIGNED conversions
480 # DOUBLE [PRECISION], REAL
481 # DECIMAL(M,D), NUMERIC(M,D)
485 s/(\w*int)\(\d+\)/$1/g; # hack of the (n) stuff for e.g. mediumint(2) int(3)
487 if (/^(\s*)(\w+)\s*.*numeric.*auto_increment/i) { # int,auto_increment -> serial
488 $seq = get_identifier($table, $2, 'seq');
489 $quoted_column=quote_and_lc($2);
490 # Smash datatype to int8 and autogenerate the sequence.
491 s/^(\s*)(\w+)\s*.*NUMERIC(.*)auto_increment([^,]*)/$1 $quoted_column serial8 $4/ig;
495 if (/^\s*(\w+)\s+.*int.*auto_increment/i) { # example: data_id mediumint(8) unsigned NOT NULL auto_increment,
496 $seq = get_identifier($table, $1, 'seq');
497 $quoted_column=quote_and_lc($1);
498 s/(\s*)(\w+)\s+.*int.*auto_increment([^,]*)/$1 $quoted_column serial8 $3/ig;
506 # convert UNSIGNED to CHECK constraints
507 if (m/^(\s*)(\w+)\s+((float|double precision|double|real|decimal|numeric))(.*)unsigned/i) {
508 $quoted_column = quote_and_lc($2);
509 s/^(\s*)(\w+)\s+((float|double precision|double|real|decimal|numeric))(.*)unsigned/$1 $quoted_column $3 $4 CHECK ($quoted_column >= 0)/i;
511 # example: `wordsize` tinyint(3) unsigned default NULL,
512 if (m/^(\s+)(\w+)\s+(\w+)\s+unsigned/i) {
513 $quoted_column=quote_and_lc($2);
514 s/^(\s+)(\w+)\s+(\w+)\s+unsigned/$1 $quoted_column $3 CHECK ($quoted_column >= 0)/i;
516 if (m/^(\s*)(\w+)\s+(bigint.*)unsigned/) {
517 $quoted_column=quote_and_lc($2);
518 # see http://archives.postgresql.org/pgsql-general/2005-07/msg01178.php
519 # and see http://www.postgresql.org/docs/8.2/interactive/datatype-numeric.html
520 # see http://dev.mysql.com/doc/refman/5.1/en/numeric-types.html max size == 20 digits
521 s/^(\s*)(\w+)\s+bigint(.*)unsigned/$1 $quoted_column NUMERIC (20,0) CHECK ($quoted_column >= 0)/i;
525 # int type conversion
526 # TINYINT (signed) -128 to 127 (unsigned) 0 255
527 # SMALLINT A small integer. The signed range is -32768 to 32767. The unsigned range is 0 to 65535.
528 # MEDIUMINT A medium-sized integer. The signed range is -8388608 to 8388607. The unsigned range is 0 to 16777215.
529 # INT A normal-size integer. The signed range is -2147483648 to 2147483647. The unsigned range is 0 to 4294967295.
530 # BIGINT The signed range is -9223372036854775808 to 9223372036854775807. The unsigned range is 0 to 18446744073709551615
531 # for postgres see http://www.postgresql.org/docs/8.2/static/datatype-numeric.html#DATATYPE-INT
532 s/^(\s+"*\w+"*\s+)tinyint/$1 smallint/i;
533 s/^(\s+"*\w+"*\s+)mediumint/$1 integer/i;
535 # the floating point types
536 # double -> double precision
537 # double(n,m) -> double precision
538 # float - no need for conversion
539 # float(n) - no need for conversion
540 # float(n,m) -> double precision
542 s/(^\s*\w+\s+)double(\(\d+,\d+\))?/$1float/i;
543 s/float(\(\d+,\d+\))/float/i;
550 # binary(M), VARBINARy(M), tinyblob, tinytext,
552 # char(M), varchar(M)
559 # mysql docs: A BLOB is a binary large object that can hold a variable amount of data.
562 # For example, a column specified as SET('one', 'two') NOT NULL can have any of these values:
567 if (/(\w*)\s+set\(((?:['"]\w+['"]\s*,*)+(?:['"]\w+['"])*)\)(.*)$/i) { # example: `au_auth` set('r','w','d') NOT NULL default '',
569 $constraints{$column_name}{'values'} = $2; # 'abc','def', ...
570 $constraints{$column_name}{'type'} = "set"; # 'abc','def', ...
571 $_ = qq~ $column_name varchar , ~;
572 $column_name = quote_and_lc($1);
577 if (/(\S*)\s+enum\(((?:['"][^'"]+['"]\s*,)+['"][^'"]+['"])\)(.*)$/i) { # enum handling
578 # example: `test` enum('?','+','-') NOT NULL default '?'
579 # $2 is the values of the enum 'abc','def', ...
580 $quoted_column=quote_and_lc($1);
581 # "test" NOT NULL default '?' CONSTRAINT test_test_constraint CHECK ("test" IN ('?','+','-'))
582 $_ = qq~ $quoted_column varchar CHECK ($quoted_column IN ( $2 ))$3\n~; # just assume varchar?
586 # Take care of "binary" option for char and varchar
587 # (pre-4.1.2, it indicated a byte array; from 4.1.2, indicates
588 # a binary collation)
589 s/(?:var)?char(?:\(\d+\))? (?:byte|binary)/text/i;
590 if (m/(?:var)?binary\s*\(\d+\)/i) { # c varBINARY(3) in Mysql
591 warn "WARNING in table '$table' '$_': binary type is converted to bytea (unsized) for Postgres\n";
593 s/(?:var)?binary(?:\(\d+\))?/text/i; # c varBINARY(3) in Mysql
594 s/bit(?:\(\d+\))?/bytea/i; # bit datatype -> bytea
599 s/mediumtext/text/gi;
602 # char -> varchar -- if specified as a command line option
603 # PostgreSQL would otherwise pad with spaces as opposed
604 # to MySQL! Your user interface may depend on this!
606 s/(^\s+\S+\s+)char/${1}varchar/gi;
609 # nuke column's collate and character set
610 s/(\S+)\s+character\s+set\s+\w+/$1/gi;
611 s/(\S+)\s+collate\s+\w+/$1/gi;
614 # DATE AND TIME TYPES
622 # these are the same types in postgres, just do the replacement of 0000-00-00 date
624 if (m/default '(\d+)-(\d+)-(\d+)([^']*)'/i) { # we grab the year, month and day
625 # NOTE: times of 00:00:00 are possible and are okay
633 if ($year eq "0000") { $year = '1970'; }
634 if ($month eq "00") { $month = '01'; }
635 if ($day eq "00") { $day = '01'; }
636 s/default '[^']+'/default '$year-$month-$day$time'/i; # finally we replace with $datetime
639 # convert mysql's year datatype to a constraint
640 if (/(\w*)\s+year\(4\)(.*)$/i) { # can be integer OR string 1901-2155
641 $constraint_table_name = get_identifier($table,$1 ,"constraint_table");
642 $column_name=quote_and_lc($1);
647 unless ($year =~ /2155/) { $year .= ','; }
648 push( @year_holder, $year);
650 $constraints{$column_name}{'values'} = join('','',@year_holder); # '1901','1902', ...
651 $constraints{$column_name}{'type'} = "year";
652 $_ = qq~ $column_name varchar CONSTRAINT ${table}_${column_name}_constraint REFERENCES $constraint_table_name ("year_values") $2\n~;
655 } elsif (/(\w*)\s+year\(2\)(.*)$/i) { # same for a 2-integer string
656 $constraint_table_name = get_identifier($table,$1 ,"constraint_table");
657 $column_name=quote_and_lc($1);
662 if ($year =~ /2069/) { next; }
663 push( @year_holder, $year);
665 push( @year_holder, '0000');
666 $constraints{$column_name}{'values'} = join(',',@year_holder); # '1971','1972', ...
667 $constraints{$column_name}{'type'} = "year"; # 'abc','def', ...
668 $_ = qq~ $1 varchar CONSTRAINT ${table}_${column_name}_constraint REFERENCES $constraint_table_name ("year_values") $2\n~;
674 # Default on a dump from MySQL 5.0.22 is in the same form as datetime so let it flow down
675 # to the timestamp section and deal with it there
676 s/(${sl})datetime /$1timestamp without time zone /i;
678 # change not null datetime field to null valid ones
679 # (to support remapping of "zero time" to null
680 # s/($sl)datetime not null/$1timestamp without time zone/i;
685 # nuke datetime representation (not supported in PostgreSQL)
686 # change default time of 0000-00-00 to 1970-01-01
688 # we may possibly need to create a trigger to provide
689 # equal functionality with ON UPDATE CURRENT TIMESTAMP
692 if (m/${sl}timestamp/i) {
693 if ( m/ON UPDATE CURRENT_TIMESTAMP/i ) { # the ... default CURRENT_TIMESTAMP only applies for blank inserts, not updates
694 s/ON UPDATE CURRENT_TIMESTAMP//i ;
695 m/^\s*(\w+)\s+timestamp/i ;
696 # automatic trigger creation
697 $table_no_quotes =~ s/"//g;
698 $function_create_sql .= " CREATE OR REPLACE FUNCTION update_". $table_no_quotes . "() RETURNS trigger AS '
700 NEW.$1 := CURRENT_TIMESTAMP;
703 ' LANGUAGE 'plpgsql';
705 -- before INSERT is handled by 'default CURRENT_TIMESTAMP'
706 CREATE TRIGGER add_current_date_to_".$table_no_quotes." BEFORE UPDATE ON ". $table . " FOR EACH ROW EXECUTE PROCEDURE
707 update_".$table_no_quotes."();\n";
710 if ($tables_first_timestamp_column && m/DEFAULT NULL/i) {
711 # DEFAULT NULL is the same as DEFAULT CURRENT_TIMESTAMP for the first TIMESTAMP column. (MYSQL manual)
712 s/($sl)(timestamp\s+)default null/$1 $2 DEFAULT CURRENT_TIMESTAMP/i;
714 $tables_first_timestamp_column= 0;
715 if (m/${sl}timestamp\s*\(\d+\)/i) { # fix for timestamps with width spec not handled (ID: 1628)
716 warn "WARNING for in table '$table' '$_': your default timestamp width is being ignored for table $table \n";
717 s/($sl)timestamp(?:\(\d+\))/$1datetime/i;
719 } # end timestamp section
721 # KEY AND UNIQUE CREATIONS
724 if ( /^\s+unique\s+\(([^(]+)\)/i ) { # example UNIQUE `name` (`name`), same as UNIQUE KEY
725 # POSTGRESQL: treat same as mysql unique
726 $quoted_column = quote_and_lc($1);
727 s/\s+unique\s+\(([^(]+)\)/ unique ($quoted_column) /i;
730 } elsif ( /^\s+unique\s+key\s*(\w+)\s*\(([^(]+)\)/i ) { # example UNIQUE KEY `name` (`name`)
731 # MYSQL: unique key: allows null=YES, allows duplicates=NO (*)
732 # ... new ... UNIQUE KEY `unique_fullname` (`fullname`) in my mysql v. Ver 14.12 Distrib 5.1.7-beta
733 # POSTGRESQL: treat same as mysql unique
735 $quoted_column = quote_and_lc($2);
736 s/\s+unique\s+key\s*(\w+)\s*\(([^(]+)\)/ unique ($quoted_column) /i;
738 # the index corresponding to the 'key' is automatically created
742 if ( /^\s+fulltext key\s+/i) { # example: FULLTEXT KEY `commenttext` (`commenttext`)
743 # that is key as a word in the first check for a match
744 # the tsvector datatype is made for these types of things
745 # example mysql file:
746 # what is tsvector datatype?
747 # http://www.sai.msu.su/~megera/postgres/gist/tsearch/V2/docs/tsearch-V2-intro.html
748 warn "dba must do fulltext key transformation for $table\n";
751 if ( /^(\s+)constraint (\S+) foreign key \((\S+)\) references (\S+) \((\S+)\)(.*)/i ) {
752 $quoted_column =quote_and_lc($3);
753 $col=quote_and_lc($5);
754 $post_create_sql .= "ALTER TABLE $table ADD FOREIGN KEY ($quoted_column) REFERENCES " . quote_and_lc($4) . " ($col);\n";
757 if ( /^\s*primary key\s*\(([^)]+)\)([,\s]+)/i ) { # example PRIMARY KEY (`name`)
758 # MYSQL: primary key: allows null=NO , allows duplicates=NO
759 # POSTGRESQL: When an index is declared unique, multiple table rows with equal indexed values will not be
760 # allowed. Null values are not considered equal.
761 # POSTGRESQL quote's source: 8.1.3 docs section 11.5 "unique indexes"
762 # so, in postgres, we need to add a NOT NULL to the UNIQUE constraint
763 # and, primary key (mysql) == primary key (postgres) so that we *really* don't need change anything
764 $quoted_column = quote_and_lc($1);
765 s/(\s*)primary key\s+\(([^)]+)\)([,\s]+)/$1 primary key ($quoted_column)$3/i;
766 # indexes are automatically created for unique columns
769 } elsif (m/^\s+key\s[-_\s\w]+\((.+)\)/i ) { # example: KEY `idx_mod_english_def_word` (`word`),
770 # regular key: allows null=YES, allows duplicates=YES
771 # MYSQL: KEY is normally a synonym for INDEX. http://dev.mysql.com/doc/refman/5.1/en/create-table.html
773 # * MySQL: ALTER TABLE {$table} ADD KEY $column ($column)
774 # * PostgreSQL: CREATE INDEX {$table}_$column_idx ON {$table}($column) // Please note the _idx "extension"
775 # PRIMARY KEY (`postid`),
776 # KEY `ownerid` (`ownerid`)
777 # create an index for everything which has a key listed for it.
779 # TODO we don't have a translation for the substring syntax in text columns in MySQL (e.g. "KEY my_idx (mytextcol(20))")
780 # for now just getting rid of the brackets and numbers (the substring specifier):
782 $quoted_column = quote_and_lc($col);
786 $index = get_identifier($table, $col, 'idx');
787 $post_create_sql.="CREATE INDEX $index ON $table USING btree ($quoted_column)\;";
788 # just create index do not add to create table statement
792 # handle 'key' declared at end of column
793 if (/\w+.*primary key/i) { # mysql: key is normally just a synonym for index
794 # just leave as is ( postgres has primary key type)
797 } elsif (/(\w+\s+(?:$mysql_datatypesStr)\s+.*)key/i) { # mysql: key is normally just a synonym for index
798 # I can't find a reference for 'key' in a postgres command without using the word 'primary key'
800 $index = get_identifier($table, $1, 'idx');
801 $quoted_column =quote_and_lc($1);
802 $post_create_sql.="CREATE INDEX $index ON $table USING btree ($quoted_column) \;";
808 # do we really need this anymore?
809 # remap colums with names of existing system attribute
812 print STDERR "WARNING: table $table uses column \"oid\" which is renamed to \"_oid\"\nYou should fix application manually! Press return to continue.";
816 s/oid/_oid/i if (/key/i && /oid/i); # fix oid in key
818 # FINAL QUOTING OF ALL COLUMNS
819 # quote column names which were not already quoted
820 # perhaps they were not quoted because they were not explicitly handled
821 if (!/^\s*"(\w+)"(\s+)/i) {
822 /^(\s*)(\w+)(\s+)(.*)$/i ;
823 $quoted_column= quote_and_lc($2);
824 s/^(\s*)(\w+)(\s+)(.*)$/$1 $quoted_column $3 $4 /;
827 # END of if ($create_sql ne "") i.e. were inside create table statement so processed datatypes
829 # add "not in create table" comments or empty lines to pre_create_sql
830 elsif (/^#/ || /^$/ || /^\s*--/) {
831 s/^#/--/; # Two hyphens (--) is the SQL-92 standard indicator for comments
832 $pre_create_sql .= $_ ; # printed above create table statement
835 elsif (/^\s*insert into/i) { # not inside create table and doing insert
836 # fix mysql's zero/null value for timestamps
837 s/'0000-00-00/'1970-01-01/gi;
838 # commented out to fix bug "Field contents interpreted as a timestamp", what was the point of this line anyway?
839 #s/([12]\d\d\d)([01]\d)([0-3]\d)([0-2]\d)([0-6]\d)([0-6]\d)/'$1-$2-$3 $4:$5:$6'/;
841 #---- fix data in inserted data: (from MS world)
845 s!\x85!... !g; # \ldots
848 print OUT $pre_create_sql; # print comments preceding the insert section
850 $auto_increment_seq = "";
852 s/'((?:[^'\\]++|\\.)*+)'(?=[),])/E'$1'/g;
853 # for the E'' see http://www.postgresql.org/docs/8.2/interactive/release-8-1.html
854 s!\\\\!\\\\\\\\!g; # replace \\ with ]\\\\
856 # split 'extended' INSERT INTO statements to something PostgreSQL can understand
857 ( $insert_table, $valueString) = $_ =~ m/^INSERT\s+INTO\s+['`"]*(.*?)['`"]*\s+VALUES\s*(.*)/i;
858 $insert_table = quote_and_lc($insert_table);
860 s/^INSERT INTO.*?\);//i; # hose the statement which is to be replaced whether a run-on or not
861 # guarantee table names are quoted
862 print OUT qq(INSERT INTO $insert_table VALUES $valueString \n);
865 print OUT $_ ; # example: /*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */;
867 # keep looping and get next line of IN file
871 print_post_create_sql(); # in case there is extra from the last table
873 #################################################################
874 # 5. print_plgsql function prototype
875 # emulate the set datatype with the following plpgsql function
876 # looks ugly so putting at end of file
877 #################################################################
880 my ($table,$column_name) = ($_[0],$_[1]);
881 $table=~s/\"//g; # make sure that $table doesn't have quotes so we don't end up with redundant quoting
882 my $constraint_table = get_identifier($table,$column_name ,"constraint_table");
884 -- this function is called by the insert/update trigger
885 -- it checks if the INSERT/UPDATE for the 'set' column
886 -- contains members which comprise a valid mysql set
887 -- this TRIGGER function therefore acts like a constraint
888 -- provided limited functionality for mysql's set datatype
889 -- just verifies and matches for string representations of the set at this point
890 -- though the set datatype uses bit comparisons, the only supported arguments to our
891 -- set datatype are VARCHAR arguments
892 -- to add a member to the set add it to the ".$table."_".$column_name." table
893 CREATE OR REPLACE FUNCTION check_".$table."_".$column_name."_set( ) RETURNS TRIGGER AS \$\$\n
901 str_in VARCHAR := NEW.$column_name;
905 IF str_in IS NULL THEN RETURN NEW ; END IF;
906 arg_str := REGEXP_REPLACE(str_in, '\\',\\'', ','); -- str_in is CONSTANT
907 arg_str := REGEXP_REPLACE(arg_str, '^\\'', '');
908 arg_str := REGEXP_REPLACE(arg_str, '\\'\$', '');
909 -- RAISE NOTICE 'arg_str %',arg_str;
910 psn := POSITION(',' in arg_str);
912 psn := psn - 1; -- minus-1 from comma position
913 -- RAISE NOTICE 'psn %',psn;
914 argx := SUBSTRING(arg_str FROM 1 FOR psn); -- get one set member
915 psn := psn + 2; -- go to first starting letter
916 arg_str := SUBSTRING(arg_str FROM psn); -- hack it off
918 psn := 0; -- minus-1 from comma position
921 -- RAISE NOTICE 'argx %',argx;
922 -- RAISE NOTICE 'new arg_str: %',arg_str;
924 EXECUTE 'SELECT count(*) FROM $constraint_table WHERE set_values = ' || quote_literal(argx) INTO rec_count;
925 IF rec_count = 0 THEN RAISE EXCEPTION 'one of the set values was not found';
928 psn := psn - 1; -- minus-1 from comma position
929 -- RAISE NOTICE 'psn %',psn;
930 argx := SUBSTRING(arg_str FROM 1 FOR psn); -- get one set member
931 psn := psn + 2; -- go to first starting letter
932 arg_str := SUBSTRING(arg_str FROM psn); -- hack it off
933 psn := POSITION(',' in arg_str);
936 -- RAISE NOTICE 'next argx % and next arg_str %', argx, arg_str;
941 \$\$ LANGUAGE 'plpgsql' VOLATILE;
943 drop trigger set_test ON $table;
944 -- make a trigger for each set field
945 -- make trigger and hard-code in column names
946 -- see http://archives.postgresql.org/pgsql-interfaces/2005-02/msg00020.php
947 CREATE TRIGGER set_test
948 BEFORE INSERT OR UPDATE ON $table FOR EACH ROW
949 EXECUTE PROCEDURE check_".$table."_".$column_name."_set();\n";
950 } # end sub make_plpgsql();