remove extraneous imports
[dbsrgits/SQL-Translator-2.0-ish.git] / lib / SQL / Translator / Producer / SQL / MySQL.pm
CommitLineData
24e6a53a 1use MooseX::Declare;
2role SQL::Translator::Producer::SQL::MySQL {
3 use SQL::Translator::Constants qw(:sqlt_types :sqlt_constants);
4 use SQL::Translator::Types qw(Column Constraint Index Table View);
5 my $DEFAULT_MAX_ID_LENGTH = 64;
6 my %used_names;
7
8 #
9 # Use only lowercase for the keys (e.g. "long" and not "LONG")
10 #
11 my %translate = (
12 #
13 # Oracle types
14 #
15 varchar2 => 'varchar',
16 long => 'text',
17 clob => 'longtext',
18
19 #
20 # Sybase types
21 #
22 int => 'integer',
23 money => 'float',
24 real => 'double',
25 comment => 'text',
26 bit => 'tinyint',
27
28 #
29 # Access types
30 #
31 'long integer' => 'integer',
32 'text' => 'text',
33 'datetime' => 'datetime',
34
35 #
36 # PostgreSQL types
37 #
38 bytea => 'BLOB',
39 );
40
41 #
42 # Column types that do not support lenth attribute
43 #
44 my @no_length_attr = qw/ date time timestamp datetime year /;
45
46 method preprocess_schema($schema) {
47# my ($schema) = @_;
48
49 # extra->{mysql_table_type} used to be the type. It belongs in options, so
50 # move it if we find it. Return Engine type if found in extra or options
51 # Similarly for mysql_charset and mysql_collate
52 my $extra_to_options = sub {
53 my ($table, $extra_name, $opt_name) = @_;
54
55 my $extra = $table->extra;
56
57 my $extra_type = delete $extra->{$extra_name};
58
59 # Now just to find if there is already an Engine or Type option...
60 # and lets normalize it to ENGINE since:
61 #
62 # The ENGINE table option specifies the storage engine for the table.
63 # TYPE is a synonym, but ENGINE is the preferred option name.
64 #
65
66 # We have to use the hash directly here since otherwise there is no way
67 # to remove options.
68 my $options = ( $table->{options} ||= []);
69
70 # If multiple option names, normalize to the first one
71 if (ref $opt_name) {
72 OPT_NAME: for ( @$opt_name[1..$#$opt_name] ) {
73 for my $idx ( 0..$#{$options} ) {
74 my ($key, $value) = %{ $options->[$idx] };
75
76 if (uc $key eq $_) {
77 $options->[$idx] = { $opt_name->[0] => $value };
78 last OPT_NAME;
79 }
80 }
81 }
82 $opt_name = $opt_name->[0];
83
84 }
85
86
87 # This assumes that there isn't both a Type and an Engine option.
88 OPTION:
89 for my $idx ( 0..$#{$options} ) {
90 my ($key, $value) = %{ $options->[$idx] };
91
92 next unless uc $key eq $opt_name;
93
94 # make sure case is right on option name
95 delete $options->[$idx]{$key};
96 return $options->[$idx]{$opt_name} = $value || $extra_type;
97
98 }
99
100 if ($extra_type) {
101 push @$options, { $opt_name => $extra_type };
102 return $extra_type;
103 }
104
105 };
106
107 # Names are only specific to a given schema
108 my %used_names = ();
109
110 #
111 # Work out which tables need to be InnoDB to support foreign key
112 # constraints. We do this first as we need InnoDB at both ends.
113 #
114 foreach my $table ( $schema->get_tables ) {
115
116 $extra_to_options->($table, 'mysql_table_type', ['ENGINE', 'TYPE'] );
117 $extra_to_options->($table, 'mysql_charset', 'CHARACTER SET' );
118 $extra_to_options->($table, 'mysql_collate', 'COLLATE' );
119
120 foreach my $c ( $table->get_constraints ) {
121 next unless $c->type eq FOREIGN_KEY;
122
123 # Normalize constraint names here.
124 my $c_name = $c->name;
125 # Give the constraint a name if it doesn't have one, so it doens't feel
126 # left out
127 $c_name = $table->name . '_fk' unless length $c_name;
128
129 $c->name( $self->next_unused_name($c_name) );
130
131 for my $meth (qw/table reference_table/) {
132 my $table = $schema->get_table($c->$meth) || next;
133 # This normalizes the types to ENGINE and returns the value if its there
134 next if $extra_to_options->($table, 'mysql_table_type', ['ENGINE', 'TYPE']);
135 $table->options( { 'ENGINE' => 'InnoDB' } );
136 }
137 } # foreach constraints
138
139 my %map = ( mysql_collate => 'collate', mysql_charset => 'character set');
140 foreach my $f ( $table->get_fields ) {
141 my $extra = $f->extra;
142 for (keys %map) {
143 $extra->{$map{$_}} = delete $extra->{$_} if exists $extra->{$_};
144 }
145
146 my @size = $f->size;
147 if ( !$size[0] && $f->data_type =~ /char$/ ) {
148 $f->size( (255) );
149 }
150 }
151
152 }
153 }
154
155 method produce {
156 my $translator = $self->translator;
157 my $DEBUG = 0;# = $translator->debug;
158 #local %used_names;
159 my $no_comments = $translator->no_comments;
160 my $add_drop_table = $translator->add_drop_table;
161 my $schema = $translator->schema;
162 my $show_warnings = $translator->show_warnings || 0;
163 my $producer_args = $translator->producer_args;
164 my $mysql_version = $self->parse_mysql_version ($producer_args->{mysql_version}, 'perl') || 0;
165 my $max_id_length = $producer_args->{mysql_max_id_length} || $DEFAULT_MAX_ID_LENGTH;
166
167 my ($qt, $qf, $qc) = ('','', '');
168 $qt = '`' if $translator->quote_table_names;
169 $qf = '`' if $translator->quote_field_names;
170
171 #debug("PKG: Beginning production\n");
172 %used_names = ();
173 my $create = '';
174 $create .= $self->header_comment unless ($no_comments);
175 # \todo Don't set if MySQL 3.x is set on command line
176 my @create = "SET foreign_key_checks=0";
177
178 $self->preprocess_schema($schema);
179
180 #
181 # Generate sql
182 #
183 my @table_defs =();
184
185 for my $table ( $schema->get_tables ) {
186 # print $table->name, "\n";
187 push @table_defs, $self->create_table($table,
188 { add_drop_table => $add_drop_table,
189 show_warnings => $show_warnings,
190 no_comments => $no_comments,
191 quote_table_names => $qt,
192 quote_field_names => $qf,
193 max_id_length => $max_id_length,
194 mysql_version => $mysql_version
195 });
196 }
197
198 if ($mysql_version >= 5.000001) {
199 for my $view ( $schema->get_views ) {
200 push @table_defs, $self->create_view($view,
201 { add_replace_view => $add_drop_table,
202 show_warnings => $show_warnings,
203 no_comments => $no_comments,
204 quote_table_names => $qt,
205 quote_field_names => $qf,
206 max_id_length => $max_id_length,
207 mysql_version => $mysql_version
208 });
209 }
210 }
211
212
213 # print "@table_defs\n";
214 push @table_defs, "SET foreign_key_checks=1";
215
216 return wantarray ? ($create ? $create : (), @create, @table_defs) : ($create . join('', map { $_ ? "$_;\n\n" : () } (@create, @table_defs)));
217 }
218
219 method create_view($view, $options) {
220# my ($view, $options) = @_;
221 my $qt = $options->{quote_table_names} || '';
222 my $qf = $options->{quote_field_names} || '';
223
224 my $view_name = $view->name;
225 #debug("PKG: Looking at view '${view_name}'\n");
226
227 # Header. Should this look like what mysqldump produces?
228 my $create = '';
229 $create .= "--\n-- View: ${qt}${view_name}${qt}\n--\n" unless $options->{no_comments};
230 $create .= 'CREATE';
231 $create .= ' OR REPLACE' if $options->{add_replace_view};
232 $create .= "\n";
233
234 my $extra = $view->extra;
235 # ALGORITHM
236 if( exists($extra->{mysql_algorithm}) && defined(my $algorithm = $extra->{mysql_algorithm}) ){
237 $create .= " ALGORITHM = ${algorithm}\n" if $algorithm =~ /(?:UNDEFINED|MERGE|TEMPTABLE)/i;
238 }
239 # DEFINER
240 if( exists($extra->{mysql_definer}) && defined(my $user = $extra->{mysql_definer}) ){
241 $create .= " DEFINER = ${user}\n";
242 }
243 # SECURITY
244 if( exists($extra->{mysql_security}) && defined(my $security = $extra->{mysql_security}) ){
245 $create .= " SQL SECURITY ${security}\n" if $security =~ /(?:DEFINER|INVOKER)/i;
246 }
247
248 #Header, cont.
249 $create .= " VIEW ${qt}${view_name}${qt}";
250
251 if( my @fields = $view->fields ){
252 my $list = join ', ', map { "${qf}${_}${qf}"} @fields;
253 $create .= " ( ${list} )";
254 }
255 if( my $sql = $view->sql ){
256 $create .= " AS (\n ${sql}\n )";
257 }
258 # $create .= "";
259 return $create;
260 }
261
262 method create_table($table, $options) {
263# my ($table, $options) = @_;
264
265 my $qt = $options->{quote_table_names} || '';
266 my $qf = $options->{quote_field_names} || '';
267
268 my $table_name = $self->quote_table_name($table->name, $qt);
269 #debug("PKG: Looking at table '$table_name'\n");
270
271 #
272 # Header. Should this look like what mysqldump produces?
273 #
274 my $create = '';
275 my $drop;
276 $create .= "--\n-- Table: $table_name\n--\n" unless $options->{no_comments};
277 $drop = qq[DROP TABLE IF EXISTS $table_name] if $options->{add_drop_table};
278 $create .= "CREATE TABLE $table_name (\n";
279
280 #
281 # Fields
282 #
283 my @field_defs;
284 for my $field ( $table->get_fields ) {
285 push @field_defs, $self->create_field($field, $options);
286 }
287
288 #
289 # Indices
290 #
291 my @index_defs;
292 my %indexed_fields;
293 for my $index ( $table->get_indices ) {
294 push @index_defs, $self->create_index($index, $options);
295 $indexed_fields{ $_ } = 1 for $index->fields;
296 }
297
298 #
299 # Constraints -- need to handle more than just FK. -ky
300 #
301 my @constraint_defs;
302 my @constraints = $table->get_constraints;
303 for my $c ( @constraints ) {
304 my $constr = $self->create_constraint($c, $options);
305 push @constraint_defs, $constr if($constr);
306 next unless $c->fields;
307 unless ( $indexed_fields{ ($c->fields())[0] } || $c->type ne FOREIGN_KEY ) {
308 push @index_defs, "INDEX ($qf" . ($c->fields())[0] . "$qf)";
309 $indexed_fields{ ($c->fields())[0] } = 1;
310 }
311 }
312
313 $create .= join(",\n", map { " $_" }
314 @field_defs, @index_defs, @constraint_defs
315 );
316
317 #
318 # Footer
319 #
320 $create .= "\n)";
321 $create .= $self->generate_table_options($table, $options) || '';
322 # $create .= ";\n\n";
323
324 return $drop ? ($drop,$create) : $create;
325 }
326
327 method quote_table_name(Str $table_name, Str $qt) {
328 $table_name =~ s/\./$qt.$qt/g;
329
330 return "$qt$table_name$qt";
331 }
332
333 method generate_table_options(Table $table, $options?) {
334 my $create;
335
336 my $table_type_defined = 0;
337 my $qf = $options->{quote_field_names} ||= '';
338 my $charset = $table->extra->{'mysql_charset'};
339 my $collate = $table->extra->{'mysql_collate'};
340 my $union = undef;
341 for my $t1_option_ref ( $table->options ) {
342 my($key, $value) = %{$t1_option_ref};
343 $table_type_defined = 1
344 if uc $key eq 'ENGINE' or uc $key eq 'TYPE';
345 if (uc $key eq 'CHARACTER SET') {
346 $charset = $value;
347 next;
348 } elsif (uc $key eq 'COLLATE') {
349 $collate = $value;
350 next;
351 } elsif (uc $key eq 'UNION') {
352 $union = "($qf". join("$qf, $qf", @$value) ."$qf)";
353 next;
354 }
355 $create .= " $key=$value";
356 }
357
358 my $mysql_table_type = $table->extra->{'mysql_table_type'};
359 $create .= " ENGINE=$mysql_table_type"
360 if $mysql_table_type && !$table_type_defined;
361 my $comments = $table->comments;
362
363 $create .= " DEFAULT CHARACTER SET $charset" if $charset;
364 $create .= " COLLATE $collate" if $collate;
365 $create .= " UNION=$union" if $union;
366 $create .= qq[ comment='$comments'] if $comments;
367 return $create;
368 }
369
370 method create_field($field, $options?) {
371 my $qf = $options->{quote_field_names} ||= '';
372
373 my $field_name = $field->name;
374 #debug("PKG: Looking at field '$field_name'\n");
375 my $field_def = "$qf$field_name$qf";
376
377 # data type and size
378 my $data_type = $field->data_type;
379 my @size = $field->size;
380 my %extra = $field->extra;
381 my $list = $extra{'list'} || [];
382 # \todo deal with embedded quotes
383 my $commalist = join( ', ', map { qq['$_'] } @$list );
384 my $charset = $extra{'mysql_charset'};
385 my $collate = $extra{'mysql_collate'};
386
387 my $mysql_version = $options->{mysql_version} || 0;
388 #
389 # Oracle "number" type -- figure best MySQL type
390 #
391 if ( lc $data_type eq 'number' ) {
392 # not an integer
393 if ( scalar @size > 1 ) {
394 $data_type = 'double';
395 }
396 elsif ( $size[0] && $size[0] >= 12 ) {
397 $data_type = 'bigint';
398 }
399 elsif ( $size[0] && $size[0] <= 1 ) {
400 $data_type = 'tinyint';
401 }
402 else {
403 $data_type = 'int';
404 }
405 }
406 #
407 # Convert a large Oracle varchar to "text"
408 # (not necessary as of 5.0.3 http://dev.mysql.com/doc/refman/5.0/en/char.html)
409 #
410 elsif ( $data_type =~ /char/i && $size[0] > 255 ) {
411 unless ($size[0] <= 65535 && $mysql_version >= 5.000003 ) {
412 $data_type = 'text';
413 @size = ();
414 }
415 }
416 elsif ( $data_type =~ /boolean/i ) {
417 if ($mysql_version >= 4) {
418 $data_type = 'boolean';
419 } else {
420 $data_type = 'enum';
421 $commalist = "'0','1'";
422 }
423 }
424# elsif ( exists $translate{ lc $data_type } ) {
425# $data_type = $translate{ lc $data_type };
426# }
427
428 @size = () if $data_type =~ /(text|blob)/i;
429
430 if ( $data_type =~ /(double|float)/ && scalar @size == 1 ) {
431 push @size, '0';
432 }
433
434 $field_def .= " $data_type";
435
436 if ( lc($data_type) eq 'enum' || lc($data_type) eq 'set') {
437 $field_def .= '(' . $commalist . ')';
438 }
439 elsif (
440 defined $size[0] && $size[0] > 0
441 &&
442 ! grep lc($data_type) eq $_, @no_length_attr
443 ) {
444 $field_def .= '(' . join( ', ', @size ) . ')';
445 }
446
447 # char sets
448 $field_def .= " CHARACTER SET $charset" if $charset;
449 $field_def .= " COLLATE $collate" if $collate;
450
451 # MySQL qualifiers
452 for my $qual ( qw[ binary unsigned zerofill ] ) {
453 my $val = $extra{ $qual } || $extra{ uc $qual } or next;
454 $field_def .= " $qual";
455 }
456 for my $qual ( 'character set', 'collate', 'on update' ) {
457 my $val = $extra{ $qual } || $extra{ uc $qual } or next;
458 $field_def .= " $qual $val";
459 }
460
461 # Null?
462 $field_def .= ' NOT NULL' unless $field->is_nullable;
463
464 # Default? XXX Need better quoting!
465 my $default = $field->default_value;
466=cut
467 if ( defined $default ) {
468 SQL::Translator::Producer->_apply_default_value(
469 \$field_def,
470 $default,
471 [
472 'NULL' => \'NULL',
473 ],
474 );
475 }
476=cut
477
478 if ( my $comments = $field->comments ) {
479 $field_def .= qq[ comment '$comments'];
480 }
481
482 # auto_increment?
483 $field_def .= " auto_increment" if $field->is_auto_increment;
484
485 return $field_def;
486 }
487
488 method alter_create_index(Index $index, $options?) {
489 my $qt = $options->{quote_table_names} || '';
490 my $qf = $options->{quote_field_names} || '';
491
492 return join( ' ',
493 'ALTER TABLE',
494 $qt.$index->table->name.$qt,
495 'ADD',
496 create_index(@_)
497 );
498 }
499
500 method create_index($index, $options?) {
501# my ( $index, $options ) = @_;
502
503 my $qf = $options->{quote_field_names} || '';
504
505 return join(
506 ' ',
507 map { $_ || () }
508 lc $index->type eq 'normal' ? 'INDEX' : $index->type . ' INDEX',
509 $index->name
510 ? (
511 $self->truncate_id_uniquely(
512 $index->name,
513 $options->{max_id_length} || $DEFAULT_MAX_ID_LENGTH
514 )
515 )
516 : '',
517 '(' . $qf . join( "$qf, $qf", $index->fields ) . $qf . ')'
518 );
519 }
520
521 method alter_drop_index(Index $index, $options?) {
522 my $qt = $options->{quote_table_names} || '';
523 my $qf = $options->{quote_field_names} || '';
524
525 return join( ' ',
526 'ALTER TABLE',
527 $qt.$index->table->name.$qt,
528 'DROP',
529 'INDEX',
530 $index->name || $index->fields
531 );
532
533 }
534
535 method alter_drop_constraint(Constraint $c, $options?) {
536 my $qt = $options->{quote_table_names} || '';
537 my $qc = $options->{quote_field_names} || '';
538
539 my $out = sprintf('ALTER TABLE %s DROP %s %s',
540 $qt . $c->table->name . $qt,
541 $c->type eq FOREIGN_KEY ? $c->type : "INDEX",
542 $qc . $c->name . $qc );
543
544 return $out;
545 }
546
547 method alter_create_constraint($index, $options?) {
548 my $qt = $options->{quote_table_names} || '';
549 return join( ' ',
550 'ALTER TABLE',
551 $qt.$index->table->name.$qt,
552 'ADD',
553 $self->create_constraint(@_) );
554 }
555
556 method create_constraint(Constraint $c, $options?) {
557 my $qf = $options->{quote_field_names} || '';
558 my $qt = $options->{quote_table_names} || '';
559 my $leave_name = $options->{leave_name} || undef;
560
561 my @fields = $c->fields or return;
562
563 if ( $c->type eq PRIMARY_KEY ) {
564 return 'PRIMARY KEY (' . $qf . join("$qf, $qf", @fields). $qf . ')';
565 }
566 elsif ( $c->type eq UNIQUE ) {
567 return
568 'UNIQUE '.
569 (defined $c->name ? $qf.$self->truncate_id_uniquely( $c->name, $options->{max_id_length} || $DEFAULT_MAX_ID_LENGTH ).$qf.' ' : '').
570 '(' . $qf . join("$qf, $qf", @fields). $qf . ')';
571 }
572 elsif ( $c->type eq FOREIGN_KEY ) {
573 #
574 # Make sure FK field is indexed or MySQL complains.
575 #
576
577 my $table = $c->table;
578 my $c_name = $self->truncate_id_uniquely( $c->name, $options->{max_id_length} || $DEFAULT_MAX_ID_LENGTH );
579
580 my $def = join(' ',
581 map { $_ || () }
582 'CONSTRAINT',
583 $qf . $c_name . $qf,
584 'FOREIGN KEY'
585 );
586
587
588 $def .= ' ('.$qf . join( "$qf, $qf", @fields ) . $qf . ')';
589
590 $def .= ' REFERENCES ' . $qt . $c->reference_table . $qt;
591
592 my @rfields = map { $_ || () } $c->reference_fields;
593 unless ( @rfields ) {
594 my $rtable_name = $c->reference_table;
595 if ( my $ref_table = $table->schema->get_table( $rtable_name ) ) {
596 push @rfields, $ref_table->primary_key;
597 }
598 else {
599 warn "Can't find reference table '$rtable_name' " .
600 "in schema\n" if $options->{show_warnings};
601 }
602 }
603
604 if ( @rfields ) {
605 $def .= ' (' . $qf . join( "$qf, $qf", @rfields ) . $qf . ')';
606 }
607 else {
608 warn "FK constraint on " . $table->name . '.' .
609 join('', @fields) . " has no reference fields\n"
610 if $options->{show_warnings};
611 }
612
613 if ( $c->match_type ) {
614 $def .= ' MATCH ' .
615 ( $c->match_type =~ /full/i ) ? 'FULL' : 'PARTIAL';
616 }
617
618 if ( $c->on_delete ) {
619 $def .= ' ON DELETE '.join( ' ', $c->on_delete );
620 }
621
622 if ( $c->on_update ) {
623 $def .= ' ON UPDATE '.join( ' ', $c->on_update );
624 }
625 return $def;
626 }
627
628 return undef;
629 }
630
631 method alter_table(Str $to_table, $options?) {
632 my $qt = $options->{quote_table_names} || '';
633
634 my $table_options = $self->generate_table_options($to_table, $options) || '';
635 my $out = sprintf('ALTER TABLE %s%s',
636 $qt . $to_table->name . $qt,
637 $table_options);
638
639 return $out;
640 }
641
642 method rename_field(@args) { alter_field(@args) }
643 method alter_field(Str $from_field, Str $to_field, $options?) {
644 my $qf = $options->{quote_field_names} || '';
645 my $qt = $options->{quote_table_names} || '';
646
647 my $out = sprintf('ALTER TABLE %s CHANGE COLUMN %s %s',
648 $qt . $to_field->table->name . $qt,
649 $qf . $from_field->name . $qf,
650 $self->create_field($to_field, $options));
651
652 return $out;
653 }
654
655 method add_field(Str $new_field, $options?) {
656 my $qt = $options->{quote_table_names} || '';
657
658 my $out = sprintf('ALTER TABLE %s ADD COLUMN %s',
659 $qt . $new_field->table->name . $qt,
660 create_field($new_field, $options));
661
662 return $out;
663
664 }
665
666 method drop_field(Str $old_field, $options?) {
667 my $qf = $options->{quote_field_names} || '';
668 my $qt = $options->{quote_table_names} || '';
669
670 my $out = sprintf('ALTER TABLE %s DROP COLUMN %s',
671 $qt . $old_field->table->name . $qt,
672 $qf . $old_field->name . $qf);
673
674 return $out;
675
676 }
677
678 method batch_alter_table($table, $diff_hash, $options?) {
679 # InnoDB has an issue with dropping and re-adding a FK constraint under the
680 # name in a single alter statment, see: http://bugs.mysql.com/bug.php?id=13741
681 #
682 # We have to work round this.
683
684 my %fks_to_alter;
685 my %fks_to_drop = map {
686 $_->type eq FOREIGN_KEY
687 ? ( $_->name => $_ )
688 : ( )
689 } @{$diff_hash->{alter_drop_constraint} };
690
691 my %fks_to_create = map {
692 if ( $_->type eq FOREIGN_KEY) {
693 $fks_to_alter{$_->name} = $fks_to_drop{$_->name} if $fks_to_drop{$_->name};
694 ( $_->name => $_ );
695 } else { ( ) }
696 } @{$diff_hash->{alter_create_constraint} };
697
698 my @drop_stmt;
699 if (scalar keys %fks_to_alter) {
700 $diff_hash->{alter_drop_constraint} = [
701 grep { !$fks_to_alter{$_->name} } @{ $diff_hash->{alter_drop_constraint} }
702 ];
703
704 @drop_stmt = batch_alter_table($table, { alter_drop_constraint => [ values %fks_to_alter ] }, $options);
705
706 }
707
708 my @stmts = map {
709 if (@{ $diff_hash->{$_} || [] }) {
710 my $meth = __PACKAGE__->can($_) or die __PACKAGE__ . " cant $_";
711 map { $meth->( (ref $_ eq 'ARRAY' ? @$_ : $_), $options ) } @{ $diff_hash->{$_} }
712 } else { () }
713 } qw/rename_table
714 alter_drop_constraint
715 alter_drop_index
716 drop_field
717 add_field
718 alter_field
719 rename_field
720 alter_create_index
721 alter_create_constraint
722 alter_table/;
723
724 # rename_table makes things a bit more complex
725 my $renamed_from = "";
726 $renamed_from = $diff_hash->{rename_table}[0][0]->name
727 if $diff_hash->{rename_table} && @{$diff_hash->{rename_table}};
728
729 return unless @stmts;
730 # Just zero or one stmts. return now
731 return (@drop_stmt,@stmts) unless @stmts > 1;
732
733 # Now strip off the 'ALTER TABLE xyz' of all but the first one
734
735 my $qt = $options->{quote_table_names} || '';
736 my $table_name = $qt . $table->name . $qt;
737
738
739 my $re = $renamed_from
740 ? qr/^ALTER TABLE (?:\Q$table_name\E|\Q$qt$renamed_from$qt\E) /
741 : qr/^ALTER TABLE \Q$table_name\E /;
742
743 my $first = shift @stmts;
744 my ($alter_table) = $first =~ /($re)/;
745
746 my $padd = " " x length($alter_table);
747
748 return @drop_stmt, join( ",\n", $first, map { s/$re//; $padd . $_ } @stmts);
749
750 }
751
752 method drop_table(Str $table, $options?) {
753 my $qt = $options->{quote_table_names} || '';
754
755 # Drop (foreign key) constraints so table drops cleanly
756 my @sql = batch_alter_table($table, { alter_drop_constraint => [ grep { $_->type eq 'FOREIGN KEY' } $table->get_constraints ] }, $options);
757
758 return (@sql, "DROP TABLE $qt$table$qt");
759 # return join("\n", @sql, "DROP TABLE $qt$table$qt");
760
761 }
762
763 method rename_table(Str $old_table, Str $new_table, $options?) {
764 my $qt = $options->{quote_table_names} || '';
765
766 return "ALTER TABLE $qt$old_table$qt RENAME TO $qt$new_table$qt";
767 }
768
769 method next_unused_name($name?) {
770# my $name = shift || '';
771 if ( !defined($used_names{$name}) ) {
772 $used_names{$name} = $name;
773 return $name;
774 }
775
776 my $i = 1;
777 while ( defined($used_names{$name . '_' . $i}) ) {
778 ++$i;
779 }
780 $name .= '_' . $i;
781 $used_names{$name} = $name;
782 return $name;
783 }
784
785 method header_comment($producer?, $comment_char?) {
786 $producer ||= caller;
787 my $now = scalar localtime;
788 my $DEFAULT_COMMENT = '-- ';
789
790 $comment_char = $DEFAULT_COMMENT
791 unless defined $comment_char;
792
793 my $header_comment =<<"HEADER_COMMENT";
794 ${comment_char}
795 ${comment_char}Created by $producer
796 ${comment_char}Created on $now
797 ${comment_char}
798HEADER_COMMENT
799
800 # Any additional stuff passed in
801 for my $additional_comment (@_) {
802 $header_comment .= "${comment_char}${additional_comment}\n";
803 }
804
805 return $header_comment;
806 }
807
808 method parse_mysql_version($v?, $target?) {
809 return undef unless $v;
810
811 $target ||= 'perl';
812
813 my @vers;
814
815 # X.Y.Z style
816 if ( $v =~ / ^ (\d+) \. (\d{1,3}) (?: \. (\d{1,3}) )? $ /x ) {
817 push @vers, $1, $2, $3;
818 }
819
820 # XYYZZ (mysql) style
821 elsif ( $v =~ / ^ (\d) (\d{2}) (\d{2}) $ /x ) {
822 push @vers, $1, $2, $3;
823 }
824
825 # XX.YYYZZZ (perl) style or simply X
826 elsif ( $v =~ / ^ (\d+) (?: \. (\d{3}) (\d{3}) )? $ /x ) {
827 push @vers, $1, $2, $3;
828 }
829 else {
830 #how do I croak sanely here?
831 die "Unparseable MySQL version '$v'";
832 }
833
834 if ($target eq 'perl') {
835 return sprintf ('%d.%03d%03d', map { $_ || 0 } (@vers) );
836 }
837 elsif ($target eq 'mysql') {
838 return sprintf ('%d%02d%02d', map { $_ || 0 } (@vers) );
839 }
840 else {
841 #how do I croak sanely here?
842 die "Unknown version target '$target'";
843 }
844 }
845
846use constant COLLISION_TAG_LENGTH => 8;
847
848method truncate_id_uniquely(Str $desired_name, Int $max_symbol_length) {
849 return $desired_name
850 unless defined $desired_name && length $desired_name > $max_symbol_length;
851
852 my $truncated_name = substr $desired_name, 0,
853 $max_symbol_length - COLLISION_TAG_LENGTH - 1;
854
855 # Hex isn't the most space-efficient, but it skirts around allowed
856 # charset issues
857 my $digest = sha1_hex($desired_name);
858 my $collision_tag = substr $digest, 0, COLLISION_TAG_LENGTH;
859
860 return $truncated_name
861 . '_'
862 . $collision_tag;
863}
864
865
866}