1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782 783 784 785 786 787 788 789 790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855 856 857 858 859 860 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877 878 879 880 881 882 883 884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 902 903 904 905 906 907 908 909 910 911 912 913 914 915 916 917 918 919 920 921 922 923 924 925 926 927 928 929 930 931 932 933 934 935 936 937 938 939 940 941 942 943 944 945 946 947 948 949 950 951 952 953 954 955 956 957 958 959 960 961 962 963 964 965 966 967 968 969 970 971 972 973 974 975 976 977 978 979 980 981 982 983 984 985 986 987 988 989 990 991 992 993 994 995 996 997 998 999 1000 1001
|
package SQL::Translator::Producer::MySQL;
=head1 NAME
SQL::Translator::Producer::MySQL - MySQL-specific producer for SQL::Translator
=head1 SYNOPSIS
Use via SQL::Translator:
use SQL::Translator;
my $t = SQL::Translator->new( parser => '...', producer => 'MySQL', '...' );
$t->translate;
=head1 DESCRIPTION
This module will produce text output of the schema suitable for MySQL.
There are still some issues to be worked out with syntax differences
between MySQL versions 3 and 4 ("SET foreign_key_checks," character sets
for fields, etc.).
=head1 ARGUMENTS
This producer takes a single optional producer_arg C<mysql_version>, which
provides the desired version for the target database. By default MySQL v3 is
assumed, and statements pertaining to any features introduced in later versions
(e.g. CREATE VIEW) are not produced.
Valid version specifiers for C<mysql_version> are listed L<here|SQL::Translator::Utils/parse_mysql_version>
=head2 Table Types
Normally the tables will be created without any explicit table type given and
so will use the MySQL default.
Any tables involved in foreign key constraints automatically get a table type
of InnoDB, unless this is overridden by setting the C<mysql_table_type> extra
attribute explicitly on the table.
=head2 Extra attributes.
The producer recognises the following extra attributes on the Schema objects.
=over 4
=item B<field.list>
Set the list of allowed values for Enum fields.
=item B<field.binary>, B<field.unsigned>, B<field.zerofill>
Set the MySQL field options of the same name.
=item B<field.renamed_from>, B<table.renamed_from>
Use when producing diffs to indicate that the current table/field has been
renamed from the old name as given in the attribute value.
=item B<table.mysql_table_type>
Set the type of the table e.g. 'InnoDB', 'MyISAM'. This will be
automatically set for tables involved in foreign key constraints if it is
not already set explicitly. See L<"Table Types">.
Please note that the C<ENGINE> option is the preferred method of specifying
the MySQL storage engine to use, but this method still works for backwards
compatibility.
=item B<table.mysql_charset>, B<table.mysql_collate>
Set the tables default charater set and collation order.
=item B<field.mysql_charset>, B<field.mysql_collate>
Set the fields charater set and collation order.
=back
=cut
use strict;
use warnings;
our ( $DEBUG, %used_names );
our $VERSION = '1.59';
$DEBUG = 0 unless defined $DEBUG;
# Maximum length for most identifiers is 64, according to:
# http://dev.mysql.com/doc/refman/4.1/en/identifiers.html
# http://dev.mysql.com/doc/refman/5.0/en/identifiers.html
my $DEFAULT_MAX_ID_LENGTH = 64;
use Data::Dumper;
use SQL::Translator::Schema::Constants;
use SQL::Translator::Utils qw(debug header_comment
truncate_id_uniquely parse_mysql_version);
#
# Use only lowercase for the keys (e.g. "long" and not "LONG")
#
my %translate = (
#
# Oracle types
#
varchar2 => 'varchar',
long => 'text',
clob => 'longtext',
#
# Sybase types
#
int => 'integer',
money => 'float',
real => 'double',
comment => 'text',
bit => 'tinyint',
#
# Access types
#
'long integer' => 'integer',
'text' => 'text',
'datetime' => 'datetime',
#
# PostgreSQL types
#
bytea => 'BLOB',
);
#
# Column types that do not support lenth attribute
#
my @no_length_attr = qw/
date time timestamp datetime year
/;
sub preprocess_schema {
my ($schema) = @_;
# extra->{mysql_table_type} used to be the type. It belongs in options, so
# move it if we find it. Return Engine type if found in extra or options
# Similarly for mysql_charset and mysql_collate
my $extra_to_options = sub {
my ($table, $extra_name, $opt_name) = @_;
my $extra = $table->extra;
my $extra_type = delete $extra->{$extra_name};
# Now just to find if there is already an Engine or Type option...
# and lets normalize it to ENGINE since:
#
# The ENGINE table option specifies the storage engine for the table.
# TYPE is a synonym, but ENGINE is the preferred option name.
#
# We have to use the hash directly here since otherwise there is no way
# to remove options.
my $options = ( $table->{options} ||= []);
# If multiple option names, normalize to the first one
if (ref $opt_name) {
OPT_NAME: for ( @$opt_name[1..$#$opt_name] ) {
for my $idx ( 0..$#{$options} ) {
my ($key, $value) = %{ $options->[$idx] };
if (uc $key eq $_) {
$options->[$idx] = { $opt_name->[0] => $value };
last OPT_NAME;
}
}
}
$opt_name = $opt_name->[0];
}
# This assumes that there isn't both a Type and an Engine option.
OPTION:
for my $idx ( 0..$#{$options} ) {
my ($key, $value) = %{ $options->[$idx] };
next unless uc $key eq $opt_name;
# make sure case is right on option name
delete $options->[$idx]{$key};
return $options->[$idx]{$opt_name} = $value || $extra_type;
}
if ($extra_type) {
push @$options, { $opt_name => $extra_type };
return $extra_type;
}
};
# Names are only specific to a given schema
local %used_names = ();
#
# Work out which tables need to be InnoDB to support foreign key
# constraints. We do this first as we need InnoDB at both ends.
#
foreach my $table ( $schema->get_tables ) {
$extra_to_options->($table, 'mysql_table_type', ['ENGINE', 'TYPE'] );
$extra_to_options->($table, 'mysql_charset', 'CHARACTER SET' );
$extra_to_options->($table, 'mysql_collate', 'COLLATE' );
foreach my $c ( $table->get_constraints ) {
next unless $c->type eq FOREIGN_KEY;
# Normalize constraint names here.
my $c_name = $c->name;
# Give the constraint a name if it doesn't have one, so it doens't feel
# left out
$c_name = $table->name . '_fk' unless length $c_name;
$c->name( next_unused_name($c_name) );
for my $meth (qw/table reference_table/) {
my $table = $schema->get_table($c->$meth) || next;
# This normalizes the types to ENGINE and returns the value if its there
next if $extra_to_options->($table, 'mysql_table_type', ['ENGINE', 'TYPE']);
$table->options( { 'ENGINE' => 'InnoDB' } );
}
} # foreach constraints
my %map = ( mysql_collate => 'collate', mysql_charset => 'character set');
foreach my $f ( $table->get_fields ) {
my $extra = $f->extra;
for (keys %map) {
$extra->{$map{$_}} = delete $extra->{$_} if exists $extra->{$_};
}
my @size = $f->size;
if ( !$size[0] && $f->data_type =~ /char$/ ) {
$f->size( (255) );
}
}
}
}
sub produce {
my $translator = shift;
local $DEBUG = $translator->debug;
local %used_names;
my $no_comments = $translator->no_comments;
my $add_drop_table = $translator->add_drop_table;
my $schema = $translator->schema;
my $show_warnings = $translator->show_warnings || 0;
my $producer_args = $translator->producer_args;
my $mysql_version = parse_mysql_version ($producer_args->{mysql_version}, 'perl') || 0;
my $max_id_length = $producer_args->{mysql_max_id_length} || $DEFAULT_MAX_ID_LENGTH;
my ($qt, $qf, $qc) = ('','', '');
$qt = '`' if $translator->quote_table_names;
$qf = '`' if $translator->quote_field_names;
debug("PKG: Beginning production\n");
%used_names = ();
my $create = '';
$create .= header_comment unless ($no_comments);
# \todo Don't set if MySQL 3.x is set on command line
my @create = "SET foreign_key_checks=0";
preprocess_schema($schema);
#
# Generate sql
#
my @table_defs =();
for my $table ( $schema->get_tables ) {
# print $table->name, "\n";
push @table_defs, create_table($table,
{ add_drop_table => $add_drop_table,
show_warnings => $show_warnings,
no_comments => $no_comments,
quote_table_names => $qt,
quote_field_names => $qf,
max_id_length => $max_id_length,
mysql_version => $mysql_version
});
}
if ($mysql_version >= 5.000001) {
for my $view ( $schema->get_views ) {
push @table_defs, create_view($view,
{ add_replace_view => $add_drop_table,
show_warnings => $show_warnings,
no_comments => $no_comments,
quote_table_names => $qt,
quote_field_names => $qf,
max_id_length => $max_id_length,
mysql_version => $mysql_version
});
}
}
if ($mysql_version >= 5.000002) {
for my $trigger ( $schema->get_triggers ) {
push @table_defs, create_trigger($trigger,
{ add_drop_trigger => $add_drop_table,
show_warnings => $show_warnings,
no_comments => $no_comments,
quote_table_names => $qt,
quote_field_names => $qf,
max_id_length => $max_id_length,
mysql_version => $mysql_version
});
}
}
# print "@table_defs\n";
push @table_defs, "SET foreign_key_checks=1";
return wantarray ? ($create ? $create : (), @create, @table_defs) : ($create . join('', map { $_ ? "$_;\n\n" : () } (@create, @table_defs)));
}
sub create_trigger {
my ($trigger, $options) = @_;
my $qt = $options->{quote_table_names} || '';
my $qf = $options->{quote_field_names} || '';
my $trigger_name = $trigger->name;
debug("PKG: Looking at trigger '${trigger_name}'\n");
my @statements;
my $events = $trigger->database_events;
for my $event ( @$events ) {
my $name = $trigger_name;
if (@$events > 1) {
$name .= "_$event";
warn "Multiple database events supplied for trigger '${trigger_name}', ",
"creating trigger '${name}' for the '${event}' event\n"
if $options->{show_warnings};
}
my $action = $trigger->action;
$action .= ";" unless $action =~ /;\s*\z/;
push @statements, "DROP TRIGGER IF EXISTS ${qt}${name}${qt}" if $options->{add_drop_trigger};
push @statements, sprintf(
"CREATE TRIGGER ${qt}%s${qt} %s %s ON ${qt}%s${qt}\n FOR EACH ROW BEGIN %s END",
$name, $trigger->perform_action_when, $event, $trigger->on_table, $action,
);
}
# Tack the comment onto the first statement
$statements[0] = "--\n-- Trigger ${qt}${trigger_name}${qt}\n--\n" . $statements[0] unless $options->{no_comments};
return @statements;
}
sub create_view {
my ($view, $options) = @_;
my $qt = $options->{quote_table_names} || '';
my $qf = $options->{quote_field_names} || '';
my $view_name = $view->name;
debug("PKG: Looking at view '${view_name}'\n");
# Header. Should this look like what mysqldump produces?
my $create = '';
$create .= "--\n-- View: ${qt}${view_name}${qt}\n--\n" unless $options->{no_comments};
$create .= 'CREATE';
$create .= ' OR REPLACE' if $options->{add_replace_view};
$create .= "\n";
my $extra = $view->extra;
# ALGORITHM
if( exists($extra->{mysql_algorithm}) && defined(my $algorithm = $extra->{mysql_algorithm}) ){
$create .= " ALGORITHM = ${algorithm}\n" if $algorithm =~ /(?:UNDEFINED|MERGE|TEMPTABLE)/i;
}
# DEFINER
if( exists($extra->{mysql_definer}) && defined(my $user = $extra->{mysql_definer}) ){
$create .= " DEFINER = ${user}\n";
}
# SECURITY
if( exists($extra->{mysql_security}) && defined(my $security = $extra->{mysql_security}) ){
$create .= " SQL SECURITY ${security}\n" if $security =~ /(?:DEFINER|INVOKER)/i;
}
#Header, cont.
$create .= " VIEW ${qt}${view_name}${qt}";
if( my @fields = $view->fields ){
my $list = join ', ', map { "${qf}${_}${qf}"} @fields;
$create .= " ( ${list} )";
}
if( my $sql = $view->sql ){
# do not wrap parenthesis around the selector, mysql doesn't like this
# http://bugs.mysql.com/bug.php?id=9198
$create .= " AS\n ${sql}\n";
}
# $create .= "";
return $create;
}
sub create_table
{
my ($table, $options) = @_;
my $qt = $options->{quote_table_names} || '';
my $qf = $options->{quote_field_names} || '';
my $table_name = quote_table_name($table->name, $qt);
debug("PKG: Looking at table '$table_name'\n");
#
# Header. Should this look like what mysqldump produces?
#
my $create = '';
my $drop;
$create .= "--\n-- Table: $table_name\n--\n" unless $options->{no_comments};
$drop = qq[DROP TABLE IF EXISTS $table_name] if $options->{add_drop_table};
$create .= "CREATE TABLE $table_name (\n";
#
# Fields
#
my @field_defs;
for my $field ( $table->get_fields ) {
push @field_defs, create_field($field, $options);
}
#
# Indices
#
my @index_defs;
my %indexed_fields;
for my $index ( $table->get_indices ) {
push @index_defs, create_index($index, $options);
$indexed_fields{ $_ } = 1 for $index->fields;
}
#
# Constraints -- need to handle more than just FK. -ky
#
my @constraint_defs;
my @constraints = $table->get_constraints;
for my $c ( @constraints ) {
my $constr = create_constraint($c, $options);
push @constraint_defs, $constr if($constr);
unless ( $indexed_fields{ ($c->fields())[0] } || $c->type ne FOREIGN_KEY ) {
push @index_defs, "INDEX ($qf" . ($c->fields())[0] . "$qf)";
$indexed_fields{ ($c->fields())[0] } = 1;
}
}
$create .= join(",\n", map { " $_" }
@field_defs, @index_defs, @constraint_defs
);
#
# Footer
#
$create .= "\n)";
$create .= generate_table_options($table, $options) || '';
# $create .= ";\n\n";
return $drop ? ($drop,$create) : $create;
}
sub quote_table_name {
my ($table_name, $qt) = @_;
$table_name =~ s/\./$qt.$qt/g;
return "$qt$table_name$qt";
}
sub generate_table_options
{
my ($table, $options) = @_;
my $create;
my $table_type_defined = 0;
my $qf = $options->{quote_field_names} ||= '';
my $charset = $table->extra('mysql_charset');
my $collate = $table->extra('mysql_collate');
my $union = undef;
for my $t1_option_ref ( $table->options ) {
my($key, $value) = %{$t1_option_ref};
$table_type_defined = 1
if uc $key eq 'ENGINE' or uc $key eq 'TYPE';
if (uc $key eq 'CHARACTER SET') {
$charset = $value;
next;
} elsif (uc $key eq 'COLLATE') {
$collate = $value;
next;
} elsif (uc $key eq 'UNION') {
$union = "($qf". join("$qf, $qf", @$value) ."$qf)";
next;
}
$create .= " $key=$value";
}
my $mysql_table_type = $table->extra('mysql_table_type');
$create .= " ENGINE=$mysql_table_type"
if $mysql_table_type && !$table_type_defined;
my $comments = $table->comments;
$create .= " DEFAULT CHARACTER SET $charset" if $charset;
$create .= " COLLATE $collate" if $collate;
$create .= " UNION=$union" if $union;
$create .= qq[ comment='$comments'] if $comments;
return $create;
}
sub create_field
{
my ($field, $options) = @_;
my $qf = $options->{quote_field_names} ||= '';
my $field_name = $field->name;
debug("PKG: Looking at field '$field_name'\n");
my $field_def = "$qf$field_name$qf";
# data type and size
my $data_type = $field->data_type;
my @size = $field->size;
my %extra = $field->extra;
my $list = $extra{'list'} || [];
# \todo deal with embedded quotes
my $commalist = join( ', ', map { qq['$_'] } @$list );
my $charset = $extra{'mysql_charset'};
my $collate = $extra{'mysql_collate'};
my $mysql_version = $options->{mysql_version} || 0;
#
# Oracle "number" type -- figure best MySQL type
#
if ( lc $data_type eq 'number' ) {
# not an integer
if ( scalar @size > 1 ) {
$data_type = 'double';
}
elsif ( $size[0] && $size[0] >= 12 ) {
$data_type = 'bigint';
}
elsif ( $size[0] && $size[0] <= 1 ) {
$data_type = 'tinyint';
}
else {
$data_type = 'int';
}
}
#
# Convert a large Oracle varchar to "text"
# (not necessary as of 5.0.3 http://dev.mysql.com/doc/refman/5.0/en/char.html)
#
elsif ( $data_type =~ /char/i && $size[0] > 255 ) {
unless ($size[0] <= 65535 && $mysql_version >= 5.000003 ) {
$data_type = 'text';
@size = ();
}
}
elsif ( $data_type =~ /boolean/i ) {
if ($mysql_version >= 4) {
$data_type = 'boolean';
} else {
$data_type = 'enum';
$commalist = "'0','1'";
}
}
elsif ( exists $translate{ lc $data_type } ) {
$data_type = $translate{ lc $data_type };
}
@size = () if $data_type =~ /(text|blob)/i;
if ( $data_type =~ /(double|float)/ && scalar @size == 1 ) {
push @size, '0';
}
$field_def .= " $data_type";
if ( lc($data_type) eq 'enum' || lc($data_type) eq 'set') {
$field_def .= '(' . $commalist . ')';
}
elsif (
defined $size[0] && $size[0] > 0
&&
! grep lc($data_type) eq $_, @no_length_attr
) {
$field_def .= '(' . join( ', ', @size ) . ')';
}
# char sets
$field_def .= " CHARACTER SET $charset" if $charset;
$field_def .= " COLLATE $collate" if $collate;
# MySQL qualifiers
for my $qual ( qw[ binary unsigned zerofill ] ) {
my $val = $extra{ $qual } || $extra{ uc $qual } or next;
$field_def .= " $qual";
}
for my $qual ( 'character set', 'collate', 'on update' ) {
my $val = $extra{ $qual } || $extra{ uc $qual } or next;
$field_def .= " $qual $val";
}
# Null?
$field_def .= ' NOT NULL' unless $field->is_nullable;
# Default?
SQL::Translator::Producer->_apply_default_value(
$field,
\$field_def,
[
'NULL' => \'NULL',
],
);
if ( my $comments = $field->comments ) {
$field_def .= qq[ comment '$comments'];
}
# auto_increment?
$field_def .= " auto_increment" if $field->is_auto_increment;
return $field_def;
}
sub alter_create_index
{
my ($index, $options) = @_;
my $qt = $options->{quote_table_names} || '';
my $qf = $options->{quote_field_names} || '';
my $table_name = quote_table_name($index->table->name, $qt);
return join( ' ',
'ALTER TABLE',
$table_name,
'ADD',
create_index(@_)
);
}
sub create_index
{
my ( $index, $options ) = @_;
my $qf = $options->{quote_field_names} || '';
return join(
' ',
map { $_ || () }
lc $index->type eq 'normal' ? 'INDEX' : $index->type . ' INDEX',
$index->name
? $qf . truncate_id_uniquely(
$index->name,
$options->{max_id_length} || $DEFAULT_MAX_ID_LENGTH
) . $qf
: '',
'(' . $qf . join( "$qf, $qf", $index->fields ) . $qf . ')'
);
}
sub alter_drop_index
{
my ($index, $options) = @_;
my $qt = $options->{quote_table_names} || '';
my $qf = $options->{quote_field_names} || '';
my $table_name = quote_table_name($index->table->name, $qt);
return join( ' ',
'ALTER TABLE',
$table_name,
'DROP',
'INDEX',
$index->name || $index->fields
);
}
sub alter_drop_constraint
{
my ($c, $options) = @_;
my $qt = $options->{quote_table_names} || '';
my $qc = $options->{quote_field_names} || '';
my $table_name = quote_table_name($c->table->name, $qt);
my @out = ('ALTER','TABLE',$table_name,'DROP');
if($c->type eq PRIMARY_KEY) {
push @out, $c->type;
}
else {
push @out, ($c->type eq FOREIGN_KEY ? $c->type : "INDEX"),
$qc . $c->name . $qc;
}
return join(' ',@out);
}
sub alter_create_constraint
{
my ($index, $options) = @_;
my $qt = $options->{quote_table_names} || '';
my $table_name = quote_table_name($index->table->name, $qt);
return join( ' ',
'ALTER TABLE',
$table_name,
'ADD',
create_constraint(@_) );
}
sub create_constraint
{
my ($c, $options) = @_;
my $qf = $options->{quote_field_names} || '';
my $qt = $options->{quote_table_names} || '';
my $leave_name = $options->{leave_name} || undef;
my $reference_table_name = quote_table_name($c->reference_table, $qt);
my @fields = $c->fields or next;
if ( $c->type eq PRIMARY_KEY ) {
return 'PRIMARY KEY (' . $qf . join("$qf, $qf", @fields). $qf . ')';
}
elsif ( $c->type eq UNIQUE ) {
return sprintf 'UNIQUE %s(%s)',
((defined $c->name && $c->name)
? join ('',
$qf,
truncate_id_uniquely( $c->name, $options->{max_id_length} || $DEFAULT_MAX_ID_LENGTH ),
$qf,
' '
)
: ''
),
( join ', ', map { "${qf}${_}${qf}" } @fields ),
;
}
elsif ( $c->type eq FOREIGN_KEY ) {
#
# Make sure FK field is indexed or MySQL complains.
#
my $table = $c->table;
my $c_name = truncate_id_uniquely( $c->name, $options->{max_id_length} || $DEFAULT_MAX_ID_LENGTH );
my $def = join(' ',
map { $_ || () }
'CONSTRAINT',
$qf . $c_name . $qf,
'FOREIGN KEY'
);
$def .= ' ('.$qf . join( "$qf, $qf", @fields ) . $qf . ')';
$def .= ' REFERENCES ' . $reference_table_name;
my @rfields = map { $_ || () } $c->reference_fields;
unless ( @rfields ) {
my $rtable_name = $c->reference_table;
if ( my $ref_table = $table->schema->get_table( $rtable_name ) ) {
push @rfields, $ref_table->primary_key;
}
else {
warn "Can't find reference table '$rtable_name' " .
"in schema\n" if $options->{show_warnings};
}
}
if ( @rfields ) {
$def .= ' (' . $qf . join( "$qf, $qf", @rfields ) . $qf . ')';
}
else {
warn "FK constraint on " . $table->name . '.' .
join('', @fields) . " has no reference fields\n"
if $options->{show_warnings};
}
if ( $c->match_type ) {
$def .= ' MATCH ' .
( $c->match_type =~ /full/i ) ? 'FULL' : 'PARTIAL';
}
if ( $c->on_delete ) {
$def .= ' ON DELETE '. $c->on_delete;
}
if ( $c->on_update ) {
$def .= ' ON UPDATE '. $c->on_update;
}
return $def;
}
return undef;
}
sub alter_table
{
my ($to_table, $options) = @_;
my $qt = $options->{quote_table_names} || '';
my $table_options = generate_table_options($to_table, $options) || '';
my $table_name = quote_table_name($to_table->name, $qt);
my $out = sprintf('ALTER TABLE %s%s',
$table_name,
$table_options);
return $out;
}
sub rename_field { alter_field(@_) }
sub alter_field
{
my ($from_field, $to_field, $options) = @_;
my $qf = $options->{quote_field_names} || '';
my $qt = $options->{quote_table_names} || '';
my $table_name = quote_table_name($to_field->table->name, $qt);
my $out = sprintf('ALTER TABLE %s CHANGE COLUMN %s %s',
$table_name,
$qf . $from_field->name . $qf,
create_field($to_field, $options));
return $out;
}
sub add_field
{
my ($new_field, $options) = @_;
my $qt = $options->{quote_table_names} || '';
my $table_name = quote_table_name($new_field->table->name, $qt);
my $out = sprintf('ALTER TABLE %s ADD COLUMN %s',
$table_name,
create_field($new_field, $options));
return $out;
}
sub drop_field
{
my ($old_field, $options) = @_;
my $qf = $options->{quote_field_names} || '';
my $qt = $options->{quote_table_names} || '';
my $table_name = quote_table_name($old_field->table->name, $qt);
my $out = sprintf('ALTER TABLE %s DROP COLUMN %s',
$table_name,
$qf . $old_field->name . $qf);
return $out;
}
sub batch_alter_table {
my ($table, $diff_hash, $options) = @_;
# InnoDB has an issue with dropping and re-adding a FK constraint under the
# name in a single alter statment, see: http://bugs.mysql.com/bug.php?id=13741
#
# We have to work round this.
my %fks_to_alter;
my %fks_to_drop = map {
$_->type eq FOREIGN_KEY
? ( $_->name => $_ )
: ( )
} @{$diff_hash->{alter_drop_constraint} };
my %fks_to_create = map {
if ( $_->type eq FOREIGN_KEY) {
$fks_to_alter{$_->name} = $fks_to_drop{$_->name} if $fks_to_drop{$_->name};
( $_->name => $_ );
} else { ( ) }
} @{$diff_hash->{alter_create_constraint} };
my @drop_stmt;
if (scalar keys %fks_to_alter) {
$diff_hash->{alter_drop_constraint} = [
grep { !$fks_to_alter{$_->name} } @{ $diff_hash->{alter_drop_constraint} }
];
@drop_stmt = batch_alter_table($table, { alter_drop_constraint => [ values %fks_to_alter ] }, $options);
}
my @stmts = map {
if (@{ $diff_hash->{$_} || [] }) {
my $meth = __PACKAGE__->can($_) or die __PACKAGE__ . " cant $_";
map { $meth->( (ref $_ eq 'ARRAY' ? @$_ : $_), $options ) } @{ $diff_hash->{$_} }
} else { () }
} qw/rename_table
alter_drop_constraint
alter_drop_index
drop_field
add_field
alter_field
rename_field
alter_create_index
alter_create_constraint
alter_table/;
#quote
my $qt = $options->{quote_table_names} || '';
# rename_table makes things a bit more complex
my $renamed_from = "";
$renamed_from = quote_table_name($diff_hash->{rename_table}[0][0]->name, $qt)
if $diff_hash->{rename_table} && @{$diff_hash->{rename_table}};
return unless @stmts;
# Just zero or one stmts. return now
return (@drop_stmt,@stmts) unless @stmts > 1;
# Now strip off the 'ALTER TABLE xyz' of all but the first one
my $table_name = quote_table_name($table->name, $qt);
my $re = $renamed_from
? qr/^ALTER TABLE (?:\Q$table_name\E|\Q$renamed_from\E) /
: qr/^ALTER TABLE \Q$table_name\E /;
my $first = shift @stmts;
my ($alter_table) = $first =~ /($re)/;
my $padd = " " x length($alter_table);
return @drop_stmt, join( ",\n", $first, map { s/$re//; $padd . $_ } @stmts);
}
sub drop_table {
my ($table, $options) = @_;
my $qt = $options->{quote_table_names} || '';
# Drop (foreign key) constraints so table drops cleanly
my @sql = batch_alter_table($table, { alter_drop_constraint => [ grep { $_->type eq 'FOREIGN KEY' } $table->get_constraints ] }, $options);
my $table_name = quote_table_name($table, $qt);
return (@sql, "DROP TABLE $table");
}
sub rename_table {
my ($old_table, $new_table, $options) = @_;
my $qt = $options->{quote_table_names} || '';
my $old_table_name = quote_table_name($old_table, $qt);
my $new_table_name = quote_table_name($new_table, $qt);
return "ALTER TABLE $old_table_name RENAME TO $new_table_name";
}
sub next_unused_name {
my $name = shift || '';
if ( !defined($used_names{$name}) ) {
$used_names{$name} = $name;
return $name;
}
my $i = 1;
while ( defined($used_names{$name . '_' . $i}) ) {
++$i;
}
$name .= '_' . $i;
$used_names{$name} = $name;
return $name;
}
1;
=pod
=head1 SEE ALSO
SQL::Translator, http://www.mysql.com/.
=head1 AUTHORS
darren chamberlain E<lt>darren@cpan.orgE<gt>,
Ken Youens-Clark E<lt>kclark@cpan.orgE<gt>.
=cut
|