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