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