Switch MySQL parser test to done_testing
[dbsrgits/SQL-Translator.git] / lib / SQL / Translator / Parser / MySQL.pm
CommitLineData
16dc9970 1package SQL::Translator::Parser::MySQL;
2
d529894e 3=head1 NAME
4
5SQL::Translator::Parser::MySQL - parser for MySQL
6
7=head1 SYNOPSIS
8
9 use SQL::Translator;
10 use SQL::Translator::Parser::MySQL;
11
12 my $translator = SQL::Translator->new;
13 $translator->parser("SQL::Translator::Parser::MySQL");
14
15=head1 DESCRIPTION
16
17The grammar is influenced heavily by Tim Bunce's "mysql2ora" grammar.
18
629b76f9 19Here's the word from the MySQL site
20(http://www.mysql.com/doc/en/CREATE_TABLE.html):
21
22 CREATE [TEMPORARY] TABLE [IF NOT EXISTS] tbl_name [(create_definition,...)]
23 [table_options] [select_statement]
ea93df61 24
629b76f9 25 or
ea93df61 26
629b76f9 27 CREATE [TEMPORARY] TABLE [IF NOT EXISTS] tbl_name LIKE old_table_name;
ea93df61 28
629b76f9 29 create_definition:
30 col_name type [NOT NULL | NULL] [DEFAULT default_value] [AUTO_INCREMENT]
31 [PRIMARY KEY] [reference_definition]
32 or PRIMARY KEY (index_col_name,...)
33 or KEY [index_name] (index_col_name,...)
34 or INDEX [index_name] (index_col_name,...)
35 or UNIQUE [INDEX] [index_name] (index_col_name,...)
36 or FULLTEXT [INDEX] [index_name] (index_col_name,...)
37 or [CONSTRAINT symbol] FOREIGN KEY [index_name] (index_col_name,...)
38 [reference_definition]
39 or CHECK (expr)
ea93df61 40
629b76f9 41 type:
42 TINYINT[(length)] [UNSIGNED] [ZEROFILL]
43 or SMALLINT[(length)] [UNSIGNED] [ZEROFILL]
44 or MEDIUMINT[(length)] [UNSIGNED] [ZEROFILL]
45 or INT[(length)] [UNSIGNED] [ZEROFILL]
46 or INTEGER[(length)] [UNSIGNED] [ZEROFILL]
47 or BIGINT[(length)] [UNSIGNED] [ZEROFILL]
48 or REAL[(length,decimals)] [UNSIGNED] [ZEROFILL]
49 or DOUBLE[(length,decimals)] [UNSIGNED] [ZEROFILL]
50 or FLOAT[(length,decimals)] [UNSIGNED] [ZEROFILL]
51 or DECIMAL(length,decimals) [UNSIGNED] [ZEROFILL]
52 or NUMERIC(length,decimals) [UNSIGNED] [ZEROFILL]
53 or CHAR(length) [BINARY]
54 or VARCHAR(length) [BINARY]
55 or DATE
56 or TIME
57 or TIMESTAMP
58 or DATETIME
59 or TINYBLOB
60 or BLOB
61 or MEDIUMBLOB
62 or LONGBLOB
63 or TINYTEXT
64 or TEXT
65 or MEDIUMTEXT
66 or LONGTEXT
67 or ENUM(value1,value2,value3,...)
68 or SET(value1,value2,value3,...)
ea93df61 69
629b76f9 70 index_col_name:
71 col_name [(length)]
ea93df61 72
629b76f9 73 reference_definition:
74 REFERENCES tbl_name [(index_col_name,...)]
75 [MATCH FULL | MATCH PARTIAL]
76 [ON DELETE reference_option]
77 [ON UPDATE reference_option]
ea93df61 78
629b76f9 79 reference_option:
80 RESTRICT | CASCADE | SET NULL | NO ACTION | SET DEFAULT
ea93df61 81
629b76f9 82 table_options:
83 TYPE = {BDB | HEAP | ISAM | InnoDB | MERGE | MRG_MYISAM | MYISAM }
a7f49dfb 84 or ENGINE = {BDB | HEAP | ISAM | InnoDB | MERGE | MRG_MYISAM | MYISAM }
629b76f9 85 or AUTO_INCREMENT = #
86 or AVG_ROW_LENGTH = #
a7f49dfb 87 or [ DEFAULT ] CHARACTER SET charset_name
629b76f9 88 or CHECKSUM = {0 | 1}
a7f49dfb 89 or COLLATE collation_name
629b76f9 90 or COMMENT = "string"
91 or MAX_ROWS = #
92 or MIN_ROWS = #
93 or PACK_KEYS = {0 | 1 | DEFAULT}
94 or PASSWORD = "string"
95 or DELAY_KEY_WRITE = {0 | 1}
96 or ROW_FORMAT= { default | dynamic | fixed | compressed }
97 or RAID_TYPE= {1 | STRIPED | RAID0 } RAID_CHUNKS=# RAID_CHUNKSIZE=#
98 or UNION = (table_name,[table_name...])
99 or INSERT_METHOD= {NO | FIRST | LAST }
100 or DATA DIRECTORY="absolute path to directory"
101 or INDEX DIRECTORY="absolute path to directory"
102
a7f49dfb 103
13aec984 104A subset of the ALTER TABLE syntax that allows addition of foreign keys:
105
106 ALTER [IGNORE] TABLE tbl_name alter_specification [, alter_specification] ...
107
108 alter_specification:
109 ADD [CONSTRAINT [symbol]]
110 FOREIGN KEY [index_name] (index_col_name,...)
111 [reference_definition]
112
113A subset of INSERT that we ignore:
114
115 INSERT anything
116
5d666b31 117=head1 ARGUMENTS
118
119This parser takes a single optional parser_arg C<mysql_parser_version>, which
120provides the desired version for the target database. Any statement in the processed
121dump file, that is commented with a version higher than the one supplied, will be stripped.
122
aa4301a7 123The default C<mysql_parser_version> is set to the conservative value of 40000 (MySQL 4.0)
124
5d666b31 125Valid version specifiers for C<mysql_parser_version> are listed L<here|SQL::Translator::Utils/parse_mysql_version>
126
127More information about the MySQL comment-syntax: L<http://dev.mysql.com/doc/refman/5.0/en/comments.html>
128
129
d529894e 130=cut
131
16dc9970 132use strict;
f27f9229 133use warnings;
bdf60588 134
0c04c5a2 135our $VERSION = '1.59';
bdf60588 136
137our $DEBUG;
8d0f3086 138$DEBUG = 0 unless defined $DEBUG;
077ebf34 139
d529894e 140use Data::Dumper;
07d6e5f7 141use Storable qw(dclone);
6b2dbb1a 142use DBI qw(:sql_types);
bdf60588 143use SQL::Translator::Utils qw/parse_mysql_version ddl_parser_instance/;
077ebf34 144
bdf60588 145use base qw(Exporter);
146our @EXPORT_OK = qw(parse);
5d666b31 147
f1fe509d 148our %type_mapping = ();
6b2dbb1a 149
aa4301a7 150use constant DEFAULT_PARSER_VERSION => 40000;
d31c185b 151
bdf60588 152our $GRAMMAR = << 'END_OF_GRAMMAR';
d529894e 153
ea93df61 154{
f1fe509d 155 my ( $database_name, %tables, $table_order, @table_comments, %views,
156 $view_order, %procedures, $proc_order );
86318717 157 my $delimiter = ';';
8ccdeb42 158}
d529894e 159
629b76f9 160#
161# The "eofile" rule makes the parser fail if any "statement" rule
ea93df61 162# fails. Otherwise, the first successful match by a "statement"
629b76f9 163# won't cause the failure needed to know that the parse, as a whole,
164# failed. -ky
165#
ea93df61 166startrule : statement(s) eofile {
167 {
168 database_name => $database_name,
169 tables => \%tables,
170 views => \%views,
f1fe509d 171 procedures => \%procedures,
ea93df61 172 }
13aec984 173}
629b76f9 174
175eofile : /^\Z/
d529894e 176
177statement : comment
dcb4fa06 178 | use
33d0d6d4 179 | set
61745327 180 | drop
d529894e 181 | create
13aec984 182 | alter
183 | insert
86318717 184 | delimiter
185 | empty_statement
d529894e 186 | <error>
187
aaea005b 188use : /use/i NAME "$delimiter"
13aec984 189 {
190 $database_name = $item[2];
191 @table_comments = ();
192 }
dcb4fa06 193
aa4301a7 194set : /set/i not_delimiter "$delimiter"
c5dabd71 195 { @table_comments = () }
734dfc91 196
aa4301a7 197drop : /drop/i TABLE not_delimiter "$delimiter"
33d0d6d4 198
aaea005b 199drop : /drop/i NAME(s) "$delimiter"
c5dabd71 200 { @table_comments = () }
61745327 201
bc9932bf 202bit:
b98bd48d 203 /(b'[01]{1,64}')/ |
204 /(b"[01]{1,64}")/
bc9932bf 205
9bf756df 206string :
ea93df61 207 # MySQL strings, unlike common SQL strings, can be double-quoted or
aaea005b 208 # single-quoted.
9bf756df 209
aaea005b 210 SQSTRING | DQSTRING
9bf756df 211
212nonstring : /[^;\'"]+/
213
9644fab3 214statement_body : string | nonstring
9bf756df 215
9644fab3 216insert : /insert/i statement_body(s?) "$delimiter"
13aec984 217
86318717 218delimiter : /delimiter/i /[\S]+/
07d6e5f7 219 { $delimiter = $item[2] }
86318717 220
221empty_statement : "$delimiter"
222
223alter : ALTER TABLE table_name alter_specification(s /,/) "$delimiter"
13aec984 224 {
225 my $table_name = $item{'table_name'};
226 die "Cannot ALTER table '$table_name'; it does not exist"
227 unless $tables{ $table_name };
ea93df61 228 for my $definition ( @{ $item[4] } ) {
13aec984 229 $definition->{'extra'}->{'alter'} = 1;
230 push @{ $tables{ $table_name }{'constraints'} }, $definition;
231 }
232 }
233
234alter_specification : ADD foreign_key_def
235 { $return = $item[2] }
236
aaea005b 237create : CREATE /database/i NAME "$delimiter"
c5dabd71 238 { @table_comments = () }
dcb4fa06 239
86318717 240create : CREATE TEMPORARY(?) TABLE opt_if_not_exists(?) table_name '(' create_definition(s /,/) /(,\s*)?\)/ table_option(s?) "$delimiter"
ea93df61 241 {
d529894e 242 my $table_name = $item{'table_name'};
22529e36 243 die "There is more than one definition for $table_name"
244 if ($tables{$table_name});
245
d529894e 246 $tables{ $table_name }{'order'} = ++$table_order;
247 $tables{ $table_name }{'table_name'} = $table_name;
248
734dfc91 249 if ( @table_comments ) {
250 $tables{ $table_name }{'comments'} = [ @table_comments ];
251 @table_comments = ();
252 }
253
61745327 254 my $i = 1;
40c1ade1 255 for my $definition ( @{ $item[7] } ) {
f2cf1734 256 if ( $definition->{'supertype'} eq 'field' ) {
d529894e 257 my $field_name = $definition->{'name'};
ea93df61 258 $tables{ $table_name }{'fields'}{ $field_name } =
d529894e 259 { %$definition, order => $i };
260 $i++;
ea93df61 261
d529894e 262 if ( $definition->{'is_primary_key'} ) {
f2cf1734 263 push @{ $tables{ $table_name }{'constraints'} },
d529894e 264 {
265 type => 'primary_key',
266 fields => [ $field_name ],
16dc9970 267 }
d529894e 268 ;
269 }
dd2ef5ae 270 }
f2cf1734 271 elsif ( $definition->{'supertype'} eq 'constraint' ) {
f2cf1734 272 push @{ $tables{ $table_name }{'constraints'} }, $definition;
40c1ade1 273 }
f2cf1734 274 elsif ( $definition->{'supertype'} eq 'index' ) {
734dfc91 275 push @{ $tables{ $table_name }{'indices'} }, $definition;
dd2ef5ae 276 }
d529894e 277 }
dd2ef5ae 278
02a21f1a 279 if ( my @options = @{ $item{'table_option(s?)'} } ) {
35843e6b 280 for my $option ( @options ) {
281 my ( $key, $value ) = each %$option;
282 if ( $key eq 'comment' ) {
283 push @{ $tables{ $table_name }{'comments'} }, $value;
284 }
285 else {
286 push @{ $tables{ $table_name }{'table_options'} }, $option;
287 }
288 }
d529894e 289 }
58a88238 290
291 1;
d529894e 292 }
dd2ef5ae 293
40c1ade1 294opt_if_not_exists : /if not exists/i
295
86318717 296create : CREATE UNIQUE(?) /(index|key)/i index_name /on/i table_name '(' field_name(s /,/) ')' "$delimiter"
d529894e 297 {
734dfc91 298 @table_comments = ();
d529894e 299 push @{ $tables{ $item{'table_name'} }{'indices'} },
300 {
301 name => $item[4],
041e659f 302 type => $item[2][0] ? 'unique' : 'normal',
d529894e 303 fields => $item[8],
dd2ef5ae 304 }
d529894e 305 ;
306 }
dd2ef5ae 307
d31c185b 308create : CREATE /trigger/i NAME not_delimiter "$delimiter"
07d6e5f7 309 {
310 @table_comments = ();
311 }
d31c185b 312
313create : CREATE PROCEDURE NAME not_delimiter "$delimiter"
07d6e5f7 314 {
315 @table_comments = ();
d31c185b 316 my $func_name = $item[3];
317 my $owner = '';
318 my $sql = "$item[1] $item[2] $item[3] $item[4]";
ea93df61 319
d31c185b 320 $procedures{ $func_name }{'order'} = ++$proc_order;
321 $procedures{ $func_name }{'name'} = $func_name;
322 $procedures{ $func_name }{'owner'} = $owner;
323 $procedures{ $func_name }{'sql'} = $sql;
07d6e5f7 324 }
d31c185b 325
326PROCEDURE : /procedure/i
07d6e5f7 327 | /function/i
d31c185b 328
aa4301a7 329create : CREATE or_replace(?) create_view_option(s?) /view/i NAME /as/i view_select_statement "$delimiter"
07d6e5f7 330 {
331 @table_comments = ();
aa4301a7 332 my $view_name = $item{'NAME'};
333 my $select_sql = $item{'view_select_statement'};
334 my $options = $item{'create_view_option(s?)'};
335
336 my $sql = join(q{ },
337 grep { defined and length }
338 map { ref $_ eq 'ARRAY' ? @$_ : $_ }
339 $item{'CREATE'},
340 $item{'or_replace(?)'},
341 $options,
342 $view_name,
343 'as select',
344 join(', ',
345 map {
346 sprintf('%s%s',
347 $_->{'name'},
348 $_->{'alias'} ? ' as ' . $_->{'alias'} : ''
349 )
350 }
351 @{ $select_sql->{'columns'} || [] }
352 ),
353 ' from ',
354 join(', ',
355 map {
356 sprintf('%s%s',
357 $_->{'name'},
358 $_->{'alias'} ? ' as ' . $_->{'alias'} : ''
359 )
360 }
361 @{ $select_sql->{'from'}{'tables'} || [] }
362 ),
363 $select_sql->{'from'}{'where'}
364 ? 'where ' . $select_sql->{'from'}{'where'}
365 : ''
366 ,
367 );
ea93df61 368
d31c185b 369 # Hack to strip database from function calls in SQL
370 $sql =~ s#`\w+`\.(`\w+`\()##g;
ea93df61 371
aa4301a7 372 $views{ $view_name }{'order'} = ++$view_order;
373 $views{ $view_name }{'name'} = $view_name;
374 $views{ $view_name }{'sql'} = $sql;
375 $views{ $view_name }{'options'} = $options;
376 $views{ $view_name }{'select'} = $item{'view_select_statement'};
07d6e5f7 377 }
d31c185b 378
aa4301a7 379create_view_option : view_algorithm | view_sql_security | view_definer
22b9814a 380
aa4301a7 381or_replace : /or replace/i
382
383view_algorithm : /algorithm/i /=/ WORD
07d6e5f7 384 {
385 $return = "$item[1]=$item[3]";
386 }
d31c185b 387
aa4301a7 388view_definer : /definer=\S+/i
389
390view_sql_security : /sql \s+ security \s+ (definer|invoker)/ixs
391
392not_delimiter : /.*?(?=$delimiter)/is
393
394view_select_statement : /[(]?/ /select/i view_column_def /from/i view_table_def /[)]?/
395 {
396 $return = {
397 columns => $item{'view_column_def'},
398 from => $item{'view_table_def'},
399 };
400 }
401
402view_column_def : /(.*?)(?=\bfrom\b)/ixs
403 {
404 # split on commas not in parens,
405 # e.g., "concat_ws(\' \', first, last) as first_last"
406 my @tmp = $1 =~ /((?:[^(,]+|\(.*?\))+)/g;
407 my @cols;
408 for my $col ( @tmp ) {
409 my ( $name, $alias ) = map {
410 s/^\s+|\s+$//g;
411 s/[`]//g;
412 $_
413 } split /\s+as\s+/i, $col;
414
415 push @cols, { name => $name, alias => $alias || '' };
416 }
417
418 $return = \@cols;
419 }
420
d31c185b 421not_delimiter : /.*?(?=$delimiter)/is
422
aa4301a7 423view_table_def : not_delimiter
424 {
425 my $clause = $item[1];
426 my $where = $1 if $clause =~ s/\bwhere \s+ (.*)//ixs;
427 $clause =~ s/[)]\s*$//;
428
429 my @tables;
430 for my $tbl ( split( /\s*,\s*/, $clause ) ) {
431 my ( $name, $alias ) = split /\s+as\s+/i, $tbl;
432 push @tables, { name => $name, alias => $alias || '' };
433 }
434
435 $return = {
436 tables => \@tables,
437 where => $where || '',
438 };
439 }
440
aaea005b 441view_column_alias : /as/i NAME
aa4301a7 442 { $return = $item[2] }
443
ea93df61 444create_definition : constraint
f2cf1734 445 | index
d529894e 446 | field
02a21f1a 447 | comment
d529894e 448 | <error>
449
ea93df61 450comment : /^\s*(?:#|-{2}).*\n/
451 {
734dfc91 452 my $comment = $item[1];
a82fa2cb 453 $comment =~ s/^\s*(#|--)\s*//;
734dfc91 454 $comment =~ s/\s*$//;
455 $return = $comment;
734dfc91 456 }
457
aa4301a7 458comment : m{ / \* (?! \!) .*? \* / }xs
e78d62f2 459 {
460 my $comment = $item[2];
73212389 461 $comment = substr($comment, 0, -2);
e78d62f2 462 $comment =~ s/^\s*|\s*$//g;
463 $return = $comment;
464 }
ea93df61 465
aa4301a7 466comment_like_command : m{/\*!(\d+)?}s
467
468comment_end : m{ \* / }xs
469
ea93df61 470field_comment : /^\s*(?:#|-{2}).*\n/
471 {
734dfc91 472 my $comment = $item[1];
a82fa2cb 473 $comment =~ s/^\s*(#|--)\s*//;
734dfc91 474 $comment =~ s/\s*$//;
475 $return = $comment;
476 }
d529894e 477
35843e6b 478
aaea005b 479field_comment2 : /comment/i SQSTRING
480 { $return = $item[2] }
35843e6b 481
d529894e 482blank : /\s*/
483
100684f3 484field : field_comment(s?) field_name data_type field_qualifier(s?) field_comment2(?) reference_definition(?) on_update(?) field_comment(s?)
ea93df61 485 {
734dfc91 486 my %qualifiers = map { %$_ } @{ $item{'field_qualifier(s?)'} || [] };
d529894e 487 if ( my @type_quals = @{ $item{'data_type'}{'qualifiers'} || [] } ) {
488 $qualifiers{ $_ } = 1 for @type_quals;
489 }
490
ea93df61 491 my $null = defined $qualifiers{'not_null'}
c5dabd71 492 ? $qualifiers{'not_null'} : 1;
493 delete $qualifiers{'not_null'};
494
35843e6b 495 my @comments = ( @{ $item[1] }, @{ $item[5] }, @{ $item[8] } );
88b89793 496
ea93df61 497 $return = {
f2cf1734 498 supertype => 'field',
ea93df61 499 name => $item{'field_name'},
f2cf1734 500 data_type => $item{'data_type'}{'type'},
501 size => $item{'data_type'}{'size'},
502 list => $item{'data_type'}{'list'},
503 null => $null,
504 constraints => $item{'reference_definition(?)'},
88b89793 505 comments => [ @comments ],
d529894e 506 %qualifiers,
ea93df61 507 }
d529894e 508 }
509 | <error>
dd2ef5ae 510
d529894e 511field_qualifier : not_null
ea93df61 512 {
513 $return = {
d529894e 514 null => $item{'not_null'},
ea93df61 515 }
d529894e 516 }
16dc9970 517
d529894e 518field_qualifier : default_val
ea93df61 519 {
520 $return = {
d529894e 521 default => $item{'default_val'},
ea93df61 522 }
d529894e 523 }
16dc9970 524
d529894e 525field_qualifier : auto_inc
ea93df61 526 {
527 $return = {
d529894e 528 is_auto_inc => $item{'auto_inc'},
ea93df61 529 }
d529894e 530 }
16dc9970 531
d529894e 532field_qualifier : primary_key
ea93df61 533 {
534 $return = {
d529894e 535 is_primary_key => $item{'primary_key'},
ea93df61 536 }
d529894e 537 }
16dc9970 538
d529894e 539field_qualifier : unsigned
ea93df61 540 {
541 $return = {
d529894e 542 is_unsigned => $item{'unsigned'},
ea93df61 543 }
d529894e 544 }
16dc9970 545
ea93df61 546field_qualifier : /character set/i WORD
095b4549 547 {
548 $return = {
bd30a9a2 549 'CHARACTER SET' => $item[2],
550 }
551 }
552
553field_qualifier : /collate/i WORD
554 {
555 $return = {
556 COLLATE => $item[2],
557 }
558 }
559
560field_qualifier : /on update/i CURRENT_TIMESTAMP
561 {
562 $return = {
563 'ON UPDATE' => $item[2],
095b4549 564 }
565 }
566
bd356af8 567field_qualifier : /unique/i KEY(?)
568 {
569 $return = {
570 is_unique => 1,
571 }
572 }
573
574field_qualifier : KEY
575 {
576 $return = {
577 has_index => 1,
578 }
579 }
580
100684f3 581reference_definition : /references/i table_name parens_field_list(?) match_type(?) on_delete(?) on_update(?)
658637cd 582 {
40c1ade1 583 $return = {
658637cd 584 type => 'foreign_key',
585 reference_table => $item[2],
586 reference_fields => $item[3][0],
587 match_type => $item[4][0],
100684f3 588 on_delete => $item[5][0],
589 on_update => $item[6][0],
658637cd 590 }
591 }
592
02a21f1a 593match_type : /match full/i { 'full' }
658637cd 594 |
02a21f1a 595 /match partial/i { 'partial' }
658637cd 596
100684f3 597on_delete : /on delete/i reference_option
658637cd 598 { $item[2] }
599
ea93df61 600on_update :
0a2833d8 601 /on update/i CURRENT_TIMESTAMP
6fa97af6 602 { $item[2] }
603 |
604 /on update/i reference_option
658637cd 605 { $item[2] }
606
ea93df61 607reference_option: /restrict/i |
608 /cascade/i |
609 /set null/i |
610 /no action/i |
658637cd 611 /set default/i
ea93df61 612 { $item[1] }
658637cd 613
f2cf1734 614index : normal_index
371f5f88 615 | fulltext_index
531652d6 616 | spatial_index
58a88238 617 | <error>
d529894e 618
0d41bc9b 619table_name : NAME
d529894e 620
0d41bc9b 621field_name : NAME
d529894e 622
02a21f1a 623index_name : NAME
d529894e 624
625data_type : WORD parens_value_list(s?) type_qualifier(s?)
ea93df61 626 {
d529894e 627 my $type = $item[1];
628 my $size; # field size, applicable only to non-set fields
629 my $list; # set list, applicable only to sets (duh)
630
44fcd0b5 631 if ( uc($type) =~ /^(SET|ENUM)$/ ) {
d529894e 632 $size = undef;
633 $list = $item[2][0];
634 }
635 else {
636 $size = $item[2][0];
637 $list = [];
638 }
639
256d534a 640
ea93df61 641 $return = {
d529894e 642 type => $type,
643 size => $size,
644 list => $list,
645 qualifiers => $item[3],
ea93df61 646 }
d529894e 647 }
16dc9970 648
658637cd 649parens_field_list : '(' field_name(s /,/) ')'
650 { $item[2] }
651
d529894e 652parens_value_list : '(' VALUE(s /,/) ')'
653 { $item[2] }
16dc9970 654
d529894e 655type_qualifier : /(BINARY|UNSIGNED|ZEROFILL)/i
656 { lc $item[1] }
16dc9970 657
d529894e 658field_type : WORD
16dc9970 659
d529894e 660create_index : /create/i /index/i
dd2ef5ae 661
ea93df61 662not_null : /not/i /null/i
e78d62f2 663 { $return = 0 }
664 |
665 /null/i
666 { $return = 1 }
16dc9970 667
d529894e 668unsigned : /unsigned/i { $return = 0 }
16dc9970 669
ea93df61 670default_val :
0a2833d8 671 /default/i CURRENT_TIMESTAMP
6fa97af6 672 {
0a2833d8 673 $return = $item[2];
6fa97af6 674 }
675 |
aaea005b 676 /default/i VALUE
bc9932bf 677 {
bc9932bf 678 $return = $item[2];
679 }
680 |
681 /default/i bit
682 {
683 $item[2] =~ s/b['"]([01]+)['"]/$1/g;
684 $return = $item[2];
685 }
686 |
34248db8 687 /default/i /[\w\d:.-]+/
09fa21a6 688 {
d529894e 689 $return = $item[2];
690 }
16dc9970 691
d529894e 692auto_inc : /auto_increment/i { 1 }
16dc9970 693
d529894e 694primary_key : /primary/i /key/i { 1 }
16dc9970 695
f2cf1734 696constraint : primary_key_def
697 | unique_key_def
698 | foreign_key_def
699 | <error>
700
02a21f1a 701foreign_key_def : foreign_key_def_begin parens_field_list reference_definition
40c1ade1 702 {
703 $return = {
f2cf1734 704 supertype => 'constraint',
40c1ade1 705 type => 'foreign_key',
02a21f1a 706 name => $item[1],
09fa21a6 707 fields => $item[2],
40c1ade1 708 %{ $item{'reference_definition'} },
709 }
710 }
711
aaea005b 712foreign_key_def_begin : /constraint/i /foreign key/i NAME
e78d62f2 713 { $return = $item[3] }
714 |
715 /constraint/i NAME /foreign key/i
716 { $return = $item[2] }
717 |
718 /constraint/i /foreign key/i
02a21f1a 719 { $return = '' }
720 |
aaea005b 721 /foreign key/i NAME
02a21f1a 722 { $return = $item[2] }
723 |
724 /foreign key/i
725 { $return = '' }
40c1ade1 726
1687dad4 727primary_key_def : primary_key index_type(?) '(' name_with_opt_paren(s /,/) ')' index_type(?)
ea93df61 728 {
729 $return = {
f2cf1734 730 supertype => 'constraint',
f2cf1734 731 type => 'primary_key',
1687dad4 732 fields => $item[4],
733 options => $item[2][0] || $item[6][0],
734 };
735 }
736 # In theory, and according to the doc, names should not be allowed here, but
737 # MySQL accept (and ignores) them, so we are not going to be less :)
738 | primary_key index_name_not_using(?) '(' name_with_opt_paren(s /,/) ')' index_type(?)
739 {
740 $return = {
741 supertype => 'constraint',
742 type => 'primary_key',
743 fields => $item[4],
744 options => $item[6][0],
58a88238 745 };
d529894e 746 }
16dc9970 747
62a64f6c 748unique_key_def : UNIQUE KEY(?) index_name_not_using(?) index_type(?) '(' name_with_opt_paren(s /,/) ')' index_type(?)
ea93df61 749 {
750 $return = {
f2cf1734 751 supertype => 'constraint',
62a64f6c 752 name => $item[3][0],
f2cf1734 753 type => 'unique',
62a64f6c 754 fields => $item[6],
755 options => $item[4][0] || $item[8][0],
ea93df61 756 }
d529894e 757 }
16dc9970 758
62a64f6c 759normal_index : KEY index_name_not_using(?) index_type(?) '(' name_with_opt_paren(s /,/) ')' index_type(?)
ea93df61 760 {
761 $return = {
f2cf1734 762 supertype => 'index',
763 type => 'normal',
fd11d3c5 764 name => $item[2][0],
765 fields => $item[5],
62a64f6c 766 options => $item[3][0] || $item[7][0],
767 }
d529894e 768 }
16dc9970 769
fd11d3c5 770index_name_not_using : QUOTED_NAME
62a64f6c 771 | /(\b(?!using)\w+\b)/ { $return = ($1 =~ /^using/i) ? undef : $1 }
fd11d3c5 772
773index_type : /using (btree|hash|rtree)/i { $return = uc $1 }
774
f2cf1734 775fulltext_index : /fulltext/i KEY(?) index_name(?) '(' name_with_opt_paren(s /,/) ')'
ea93df61 776 {
777 $return = {
f2cf1734 778 supertype => 'index',
779 type => 'fulltext',
780 name => $item{'index_name(?)'}[0],
781 fields => $item[5],
ea93df61 782 }
371f5f88 783 }
784
531652d6 785spatial_index : /spatial/i KEY(?) index_name(?) '(' name_with_opt_paren(s /,/) ')'
ea93df61 786 {
787 $return = {
531652d6 788 supertype => 'index',
789 type => 'spatial',
790 name => $item{'index_name(?)'}[0],
791 fields => $item[5],
ea93df61 792 }
531652d6 793 }
794
d529894e 795name_with_opt_paren : NAME parens_value_list(s?)
796 { $item[2][0] ? "$item[1]($item[2][0][0])" : $item[1] }
16dc9970 797
041e659f 798UNIQUE : /unique/i
16dc9970 799
f2cf1734 800KEY : /key/i | /index/i
16dc9970 801
aaea005b 802table_option : /comment/i /=/ string
35843e6b 803 {
aaea005b 804 $return = { comment => $item[3] };
35843e6b 805 }
aaea005b 806 | /(default )?(charset|character set)/i /\s*=?\s*/ NAME
ea93df61 807 {
bd30a9a2 808 $return = { 'CHARACTER SET' => $item[3] };
d529894e 809 }
aaea005b 810 | /collate/i NAME
a7f49dfb 811 {
812 $return = { 'COLLATE' => $item[2] }
813 }
9a96648f 814 | /union/i /\s*=\s*/ '(' table_name(s /,/) ')'
ea93df61 815 {
9a96648f 816 $return = { $item[1] => $item[4] };
817 }
aaea005b 818 | WORD /\s*=\s*/ table_option_value
47666977 819 {
19c5bc53 820 $return = { $item[1] => $item[3] };
821 }
47666977 822
aaea005b 823table_option_value : VALUE
824 | NAME
47666977 825
bd30a9a2 826default : /default/i
16dc9970 827
13aec984 828ADD : /add/i
829
830ALTER : /alter/i
831
40c1ade1 832CREATE : /create/i
833
834TEMPORARY : /temporary/i
835
836TABLE : /table/i
837
d529894e 838WORD : /\w+/
16dc9970 839
d529894e 840DIGITS : /\d+/
16dc9970 841
d529894e 842COMMA : ','
16dc9970 843
a7f49dfb 844BACKTICK : '`'
845
f1fe509d 846DOUBLE_QUOTE: '"'
847
46417fe2 848SINGLE_QUOTE: "'"
849
aaea005b 850QUOTED_NAME : BQSTRING
851 | SQSTRING
852 | DQSTRING
853
854# MySQL strings, unlike common SQL strings, can have the delmiters
855# escaped either by doubling or by backslashing.
fd498bb0 856BQSTRING: BACKTICK <skip: ''> /(?:[^\\`]|``|\\.)*/ BACKTICK
857 { ($return = $item[3]) =~ s/(\\[\\`]|``)/substr($1,1)/ge }
aaea005b 858
fd498bb0 859DQSTRING: DOUBLE_QUOTE <skip: ''> /(?:[^\\"]|""|\\.)*/ DOUBLE_QUOTE
860 { ($return = $item[3]) =~ s/(\\[\\"]|"")/substr($1,1)/ge }
aaea005b 861
fd498bb0 862SQSTRING: SINGLE_QUOTE <skip: ''> /(?:[^\\']|''|\\.)*/ SINGLE_QUOTE
863 { ($return = $item[3]) =~ s/(\\[\\']|'')/substr($1,1)/ge }
aaea005b 864
16dc9970 865
fd11d3c5 866NAME: QUOTED_NAME
ea93df61 867 | /\w+/
fd11d3c5 868
aaea005b 869VALUE : /[-+]?\d*\.?\d+(?:[eE]\d+)?/
d529894e 870 { $item[1] }
aaea005b 871 | SQSTRING
872 | DQSTRING
873 | /NULL/i
d529894e 874 { 'NULL' }
16dc9970 875
0a2833d8 876# always a scalar-ref, so that it is treated as a function and not quoted by consumers
877CURRENT_TIMESTAMP :
878 /current_timestamp(\(\))?/i { \'CURRENT_TIMESTAMP' }
879 | /now\(\)/i { \'CURRENT_TIMESTAMP' }
ea93df61 880
9bf756df 881END_OF_GRAMMAR
16dc9970 882
d529894e 883sub parse {
70944bc5 884 my ( $translator, $data ) = @_;
bdf60588 885
886 # Enable warnings within the Parse::RecDescent module.
f9a2a1d9 887 # Make sure the parser dies when it encounters an error
888 local $::RD_ERRORS = 1 unless defined $::RD_ERRORS;
889 # Enable warnings. This will warn on unused rules &c.
890 local $::RD_WARN = 1 unless defined $::RD_WARN;
891 # Give out hints to help fix problems.
892 local $::RD_HINT = 1 unless defined $::RD_HINT;
e099bee9 893 local $::RD_TRACE = $translator->trace ? 1 : undef;
894 local $DEBUG = $translator->debug;
d529894e 895
bdf60588 896 my $parser = ddl_parser_instance('MySQL');
ea93df61 897
f1fe509d 898 # Preprocess for MySQL-specific and not-before-version comments
899 # from mysqldump
900 my $parser_version = parse_mysql_version(
901 $translator->parser_args->{mysql_parser_version}, 'mysql'
902 ) || DEFAULT_PARSER_VERSION;
903
ea93df61 904 while ( $data =~
905 s#/\*!(\d{5})?(.*?)\*/#($1 && $1 > $parser_version ? '' : $2)#es
f1fe509d 906 ) {
907 # do nothing; is there a better way to write this? -- ky
908 }
d529894e 909
910 my $result = $parser->startrule($data);
40c1ade1 911 return $translator->error( "Parse failed." ) unless defined $result;
13aec984 912 warn "Parse result:".Dumper( $result ) if $DEBUG;
8ccdeb42 913
70944bc5 914 my $schema = $translator->schema;
13aec984 915 $schema->name($result->{'database_name'}) if $result->{'database_name'};
916
ea93df61 917 my @tables = sort {
918 $result->{'tables'}{ $a }{'order'}
919 <=>
13aec984 920 $result->{'tables'}{ $b }{'order'}
921 } keys %{ $result->{'tables'} };
034ecdec 922
923 for my $table_name ( @tables ) {
13aec984 924 my $tdata = $result->{tables}{ $table_name };
ea93df61 925 my $table = $schema->add_table(
8ccdeb42 926 name => $tdata->{'table_name'},
40c1ade1 927 ) or die $schema->error;
8ccdeb42 928
734dfc91 929 $table->comments( $tdata->{'comments'} );
f2cf1734 930
ea93df61 931 my @fields = sort {
932 $tdata->{'fields'}->{$a}->{'order'}
8ccdeb42 933 <=>
934 $tdata->{'fields'}->{$b}->{'order'}
935 } keys %{ $tdata->{'fields'} };
936
937 for my $fname ( @fields ) {
938 my $fdata = $tdata->{'fields'}{ $fname };
939 my $field = $table->add_field(
940 name => $fdata->{'name'},
941 data_type => $fdata->{'data_type'},
942 size => $fdata->{'size'},
943 default_value => $fdata->{'default'},
944 is_auto_increment => $fdata->{'is_auto_inc'},
945 is_nullable => $fdata->{'null'},
88b89793 946 comments => $fdata->{'comments'},
40c1ade1 947 ) or die $table->error;
f2cf1734 948
949 $table->primary_key( $field->name ) if $fdata->{'is_primary_key'};
950
bd30a9a2 951 for my $qual ( qw[ binary unsigned zerofill list collate ],
07d6e5f7 952 'character set', 'on update' ) {
f2cf1734 953 if ( my $val = $fdata->{ $qual } || $fdata->{ uc $qual } ) {
954 next if ref $val eq 'ARRAY' && !@$val;
955 $field->extra( $qual, $val );
956 }
957 }
958
bd356af8 959 if ( $fdata->{'has_index'} ) {
960 $table->add_index(
961 name => '',
962 type => 'NORMAL',
963 fields => $fdata->{'name'},
964 ) or die $table->error;
965 }
966
967 if ( $fdata->{'is_unique'} ) {
968 $table->add_constraint(
969 name => '',
970 type => 'UNIQUE',
971 fields => $fdata->{'name'},
972 ) or die $table->error;
973 }
974
f2cf1734 975 for my $cdata ( @{ $fdata->{'constraints'} } ) {
976 next unless $cdata->{'type'} eq 'foreign_key';
977 $cdata->{'fields'} ||= [ $field->name ];
978 push @{ $tdata->{'constraints'} }, $cdata;
979 }
07d6e5f7 980
f2cf1734 981 }
982
983 for my $idata ( @{ $tdata->{'indices'} || [] } ) {
984 my $index = $table->add_index(
985 name => $idata->{'name'},
986 type => uc $idata->{'type'},
987 fields => $idata->{'fields'},
988 ) or die $table->error;
989 }
990
02a21f1a 991 if ( my @options = @{ $tdata->{'table_options'} || [] } ) {
f7f81963 992 my @cleaned_options;
f1fe509d 993 my @ignore_opts = $translator->parser_args->{'ignore_opts'}
994 ? split( /,/, $translator->parser_args->{'ignore_opts'} )
995 : ();
f7f81963 996 if (@ignore_opts) {
997 my $ignores = { map { $_ => 1 } @ignore_opts };
998 foreach my $option (@options) {
999 # make sure the option isn't in ignore list
1000 my ($option_key) = keys %$option;
f1fe509d 1001 if ( !exists $ignores->{$option_key} ) {
1002 push @cleaned_options, $option;
1003 }
f7f81963 1004 }
1005 } else {
1006 @cleaned_options = @options;
1007 }
1008 $table->options( \@cleaned_options ) or die $table->error;
02a21f1a 1009 }
1010
f2cf1734 1011 for my $cdata ( @{ $tdata->{'constraints'} || [] } ) {
1012 my $constraint = $table->add_constraint(
1013 name => $cdata->{'name'},
1014 type => $cdata->{'type'},
1015 fields => $cdata->{'fields'},
1016 reference_table => $cdata->{'reference_table'},
1017 reference_fields => $cdata->{'reference_fields'},
1018 match_type => $cdata->{'match_type'} || '',
ea93df61 1019 on_delete => $cdata->{'on_delete'}
f1fe509d 1020 || $cdata->{'on_delete_do'},
ea93df61 1021 on_update => $cdata->{'on_update'}
f1fe509d 1022 || $cdata->{'on_update_do'},
f2cf1734 1023 ) or die $table->error;
8ccdeb42 1024 }
07d6e5f7 1025
ea93df61 1026 # After the constrains and PK/idxs have been created,
f1fe509d 1027 # we normalize fields
07d6e5f7 1028 normalize_field($_) for $table->get_fields;
8ccdeb42 1029 }
ea93df61 1030
1031 my @procedures = sort {
1032 $result->{procedures}->{ $a }->{'order'}
1033 <=>
f1fe509d 1034 $result->{procedures}->{ $b }->{'order'}
d31c185b 1035 } keys %{ $result->{procedures} };
f1fe509d 1036
1037 for my $proc_name ( @procedures ) {
07d6e5f7 1038 $schema->add_procedure(
1039 name => $proc_name,
1040 owner => $result->{procedures}->{$proc_name}->{owner},
1041 sql => $result->{procedures}->{$proc_name}->{sql},
1042 );
d31c185b 1043 }
aa4301a7 1044
ea93df61 1045 my @views = sort {
1046 $result->{views}->{ $a }->{'order'}
1047 <=>
f1fe509d 1048 $result->{views}->{ $b }->{'order'}
d31c185b 1049 } keys %{ $result->{views} };
f1fe509d 1050
3ebe2ce5 1051 for my $view_name ( @views ) {
aa4301a7 1052 my $view = $result->{'views'}{ $view_name };
1053 my @flds = map { $_->{'alias'} || $_->{'name'} }
1054 @{ $view->{'select'}{'columns'} || [] };
e6c5fb6e 1055 my @from = map { $_->{'alias'} || $_->{'name'} }
1056 @{ $view->{'from'}{'tables'} || [] };
aa4301a7 1057
07d6e5f7 1058 $schema->add_view(
aa4301a7 1059 name => $view_name,
1060 sql => $view->{'sql'},
1061 order => $view->{'order'},
1062 fields => \@flds,
e6c5fb6e 1063 tables => \@from,
1064 options => $view->{'options'}
07d6e5f7 1065 );
d31c185b 1066 }
8ccdeb42 1067
f62bd16c 1068 return 1;
d529894e 1069}
1070
ea93df61 1071# Takes a field, and returns
07d6e5f7 1072sub normalize_field {
1073 my ($field) = @_;
936e626b 1074 my ($size, $type, $list, $unsigned, $changed);
ea93df61 1075
07d6e5f7 1076 $size = $field->size;
1077 $type = $field->data_type;
1078 $list = $field->extra->{list} || [];
936e626b 1079 $unsigned = defined($field->extra->{unsigned});
07d6e5f7 1080
1081 if ( !ref $size && $size eq 0 ) {
1082 if ( lc $type eq 'tinyint' ) {
936e626b 1083 $changed = $size != 4 - $unsigned;
1084 $size = 4 - $unsigned;
07d6e5f7 1085 }
1086 elsif ( lc $type eq 'smallint' ) {
936e626b 1087 $changed = $size != 6 - $unsigned;
1088 $size = 6 - $unsigned;
07d6e5f7 1089 }
1090 elsif ( lc $type eq 'mediumint' ) {
936e626b 1091 $changed = $size != 9 - $unsigned;
1092 $size = 9 - $unsigned;
07d6e5f7 1093 }
1094 elsif ( $type =~ /^int(eger)?$/i ) {
936e626b 1095 $changed = $size != 11 - $unsigned || $type ne 'int';
07d6e5f7 1096 $type = 'int';
936e626b 1097 $size = 11 - $unsigned;
07d6e5f7 1098 }
1099 elsif ( lc $type eq 'bigint' ) {
1100 $changed = $size != 20;
1101 $size = 20;
1102 }
1103 elsif ( lc $type =~ /(float|double|decimal|numeric|real|fixed|dec)/ ) {
1104 my $old_size = (ref $size || '') eq 'ARRAY' ? $size : [];
ea93df61 1105 $changed = @$old_size != 2
1106 || $old_size->[0] != 8
f1fe509d 1107 || $old_size->[1] != 2;
1108 $size = [8,2];
07d6e5f7 1109 }
1110 }
1111
1112 if ( $type =~ /^tiny(text|blob)$/i ) {
1113 $changed = $size != 255;
1114 $size = 255;
1115 }
1116 elsif ( $type =~ /^(blob|text)$/i ) {
1117 $changed = $size != 65_535;
1118 $size = 65_535;
1119 }
1120 elsif ( $type =~ /^medium(blob|text)$/i ) {
1121 $changed = $size != 16_777_215;
1122 $size = 16_777_215;
1123 }
1124 elsif ( $type =~ /^long(blob|text)$/i ) {
1125 $changed = $size != 4_294_967_295;
1126 $size = 4_294_967_295;
1127 }
f1fe509d 1128
9ab59f87 1129 if ( $field->data_type =~ /(set|enum)/i && !$field->size ) {
1130 my %extra = $field->extra;
1131 my $longest = 0;
1132 for my $len ( map { length } @{ $extra{'list'} || [] } ) {
1133 $longest = $len if $len > $longest;
1134 }
1135 $changed = 1;
1136 $size = $longest if $longest;
1137 }
1138
1139
f1fe509d 1140 if ( $changed ) {
1141 # We only want to clone the field, not *everything*
1142 {
1143 local $field->{table} = undef;
1144 $field->parsed_field( dclone( $field ) );
1145 $field->parsed_field->{table} = $field->table;
1146 }
1147 $field->size( $size );
1148 $field->data_type( $type );
1149 $field->sql_data_type( $type_mapping{ lc $type } )
1150 if exists $type_mapping{ lc $type };
1151 $field->extra->{list} = $list if @$list;
07d6e5f7 1152 }
1153}
1154
d529894e 11551;
1156
034ecdec 1157# -------------------------------------------------------------------
d529894e 1158# Where man is not nature is barren.
1159# William Blake
034ecdec 1160# -------------------------------------------------------------------
16dc9970 1161
d529894e 1162=pod
16dc9970 1163
1164=head1 AUTHOR
1165
19c5bc53 1166Ken Youens-Clark E<lt>kclark@cpan.orgE<gt>,
8ccdeb42 1167Chris Mungall E<lt>cjm@fruitfly.orgE<gt>.
16dc9970 1168
1169=head1 SEE ALSO
1170
19c5bc53 1171Parse::RecDescent, SQL::Translator::Schema.
16dc9970 1172
1173=cut