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