Use precompiled Parse::RecDescent parsers for moar speed
[dbsrgits/SQL-Translator.git] / lib / SQL / Translator / Parser / SQLServer.pm
CommitLineData
be4469ab 1package SQL::Translator::Parser::SQLServer;
2
be4469ab 3=head1 NAME
4
5SQL::Translator::Parser::SQLServer - parser for SQL Server
6
7=head1 SYNOPSIS
8
9 use SQL::Translator::Parser::SQLServer;
10
11=head1 DESCRIPTION
12
13Adapted from Parser::Sybase and mostly parses the output of
14Producer::SQLServer. The parsing is by no means complete and
15should probably be considered a work in progress.
16
17=cut
18
19use strict;
f27f9229 20use warnings;
be4469ab 21
0c04c5a2 22our $VERSION = '1.59';
bdf60588 23
24our $DEBUG;
be4469ab 25$DEBUG = 0 unless defined $DEBUG;
26
27use Data::Dumper;
bdf60588 28use SQL::Translator::Utils qw/ddl_parser_instance/;
be4469ab 29
bdf60588 30use base qw(Exporter);
31our @EXPORT_OK = qw(parse);
be4469ab 32
bdf60588 33our $GRAMMAR = <<'END_OF_GRAMMAR';
be4469ab 34
e5f65c59 35{
ff3dd529 36 my ( %tables, @table_comments, $table_order, %procedures, $proc_order, %views, $view_order );
28224573 37
38 sub _err {
39 my $max_lines = 5;
40 my @up_to_N_lines = split (/\n/, $_[1], $max_lines + 1);
41 die sprintf ("Unable to parse line %d:\n%s\n",
42 $_[0],
43 join "\n", (map { "'$_'" } @up_to_N_lines[0..$max_lines - 1 ]), @up_to_N_lines > $max_lines ? '...' : ()
44 );
45 }
46
be4469ab 47}
48
ff3dd529 49startrule : statement(s) eofile
e5f65c59 50 {
51 return {
52 tables => \%tables,
53 procedures => \%procedures,
54 views => \%views,
55 }
56 }
be4469ab 57
58eofile : /^\Z/
59
60statement : create_table
61 | create_procedure
ff3dd529 62 | create_view
be4469ab 63 | create_index
64 | create_constraint
65 | comment
028386aa 66 | disable_constraints
e2fb9ad3 67 | drop
be4469ab 68 | use
69 | setuser
70 | if
71 | print
72 | grant
73 | exec
28224573 74 | /^\Z/ | { _err ($thisline, $text) }
be4469ab 75
e5f65c59 76use : /use/i WORD GO
be4469ab 77 { @table_comments = () }
78
79setuser : /setuser/i NAME GO
80
81if : /if/i object_not_null begin if_command end GO
82
83if_command : grant
84 | create_index
85 | create_constraint
86
87object_not_null : /object_id/i '(' ident ')' /is not null/i
88
028386aa 89field_not_null : /where/i field_name /is \s+ not \s+ null/ix
90
be4469ab 91print : /\s*/ /print/i /.*/
92
93else : /else/i /.*/
94
95begin : /begin/i
96
97end : /end/i
98
99grant : /grant/i /[^\n]*/
100
101exec : exec_statement(s) GO
102
103exec_statement : /exec/i /[^\n]+/
104
e5f65c59 105comment : /^\s*(?:#|-{2}).*\n/
106 {
be4469ab 107 my $comment = $item[1];
108 $comment =~ s/^\s*(#|--)\s*//;
109 $comment =~ s/\s*$//;
110 $return = $comment;
111 push @table_comments, $comment;
112 }
113
114comment : comment_start comment_middle comment_end
e5f65c59 115 {
be4469ab 116 my $comment = $item[2];
117 $comment =~ s/^\s*|\s*$//mg;
118 $comment =~ s/^\**\s*//mg;
119 push @table_comments, $comment;
120 }
121
122comment_start : m#^\s*\/\*#
123
124comment_end : m#\s*\*\/#
125
126comment_middle : m{([^*]+|\*(?!/))*}
127
e2fb9ad3 128drop : if_exists(?) /drop/i tbl_drop END_STATEMENT
129
028386aa 130tbl_drop : /table/i ident
e2fb9ad3 131
132if_exists : /if exists/i '(' /select/i 'name' /from/i 'sysobjects' /[^\)]+/ ')'
133
be4469ab 134#
135# Create table.
136#
ff3dd529 137create_table : /create/i /table/i ident '(' create_def(s /,/) ')' lock(?) on_system(?) END_STATEMENT
e5f65c59 138 {
be4469ab 139 my $table_owner = $item[3]{'owner'};
140 my $table_name = $item[3]{'name'};
141
142 if ( @table_comments ) {
143 $tables{ $table_name }{'comments'} = [ @table_comments ];
144 @table_comments = ();
145 }
146
147 $tables{ $table_name }{'order'} = ++$table_order;
148 $tables{ $table_name }{'name'} = $table_name;
149 $tables{ $table_name }{'owner'} = $table_owner;
150 $tables{ $table_name }{'system'} = $item[7];
151
152 my $i = 0;
153 for my $def ( @{ $item[5] } ) {
154 if ( $def->{'supertype'} eq 'field' ) {
155 my $field_name = $def->{'name'};
e5f65c59 156 $tables{ $table_name }{'fields'}{ $field_name } =
be4469ab 157 { %$def, order => $i };
158 $i++;
e5f65c59 159
be4469ab 160 if ( $def->{'is_primary_key'} ) {
161 push @{ $tables{ $table_name }{'constraints'} }, {
162 type => 'primary_key',
163 fields => [ $field_name ],
164 };
165 }
166 }
167 elsif ( $def->{'supertype'} eq 'constraint' ) {
168 push @{ $tables{ $table_name }{'constraints'} }, $def;
169 }
170 else {
171 push @{ $tables{ $table_name }{'indices'} }, $def;
172 }
173 }
174 }
175
028386aa 176disable_constraints : if_exists(?) /alter/i /table/i ident /nocheck/i /constraint/i /all/i END_STATEMENT
177
178# this is for the normal case
179create_constraint : /create/i constraint END_STATEMENT
180 {
181 @table_comments = ();
182 push @{ $tables{ $item[2]{'table'} }{'constraints'} }, $item[2];
183 }
184
185# and this is for the BEGIN/END case
f9a5ee79 186create_constraint : /create/i constraint
be4469ab 187 {
188 @table_comments = ();
189 push @{ $tables{ $item[2]{'table'} }{'constraints'} }, $item[2];
190 }
191
028386aa 192
f9a5ee79 193create_constraint : /alter/i /table/i ident /add/i foreign_key_constraint END_STATEMENT
194 {
195 push @{ $tables{ $item[3]{name} }{constraints} }, $item[5];
196 }
197
028386aa 198
be4469ab 199create_index : /create/i index
200 {
201 @table_comments = ();
202 push @{ $tables{ $item[2]{'table'} }{'indices'} }, $item[2];
203 }
204
ff3dd529 205create_procedure : /create/i PROCEDURE WORD not_go GO
be4469ab 206 {
207 @table_comments = ();
ff3dd529 208 my $proc_name = $item[3];
209 my $owner = '';
210 my $sql = "$item[1] $item[2] $proc_name $item[4]";
e5f65c59 211
ff3dd529 212 $procedures{ $proc_name }{'order'} = ++$proc_order;
213 $procedures{ $proc_name }{'name'} = $proc_name;
214 $procedures{ $proc_name }{'owner'} = $owner;
215 $procedures{ $proc_name }{'sql'} = $sql;
be4469ab 216 }
217
ff3dd529 218create_procedure : /create/i PROCEDURE '[' WORD '].' WORD not_go GO
219 {
220 @table_comments = ();
221 my $proc_name = $item[6];
222 my $owner = $item[4];
223 my $sql = "$item[1] $item[2] [$owner].$proc_name $item[7]";
e5f65c59 224
ff3dd529 225 $procedures{ $proc_name }{'order'} = ++$proc_order;
226 $procedures{ $proc_name }{'name'} = $proc_name;
227 $procedures{ $proc_name }{'owner'} = $owner;
228 $procedures{ $proc_name }{'sql'} = $sql;
229 }
230
231PROCEDURE : /procedure/i
e5f65c59 232 | /function/i
ff3dd529 233
ff3dd529 234create_view : /create/i /view/i WORD not_go GO
235 {
236 @table_comments = ();
237 my $view_name = $item[3];
238 my $sql = "$item[1] $item[2] $item[3] $item[4]";
e5f65c59 239
ff3dd529 240 $views{ $view_name }{'order'} = ++$view_order;
241 $views{ $view_name }{'name'} = $view_name;
242 $views{ $view_name }{'sql'} = $sql;
243 }
244
ff3dd529 245not_go : /((?!\bgo\b).)*/is
be4469ab 246
247create_def : constraint
248 | index
249 | field
250
251blank : /\s*/
252
253field : field_name data_type field_qualifier(s?)
e5f65c59 254 {
be4469ab 255 my %qualifiers = map { %$_ } @{ $item{'field_qualifier(s?)'} || [] };
e5f65c59 256 my $nullable = defined $qualifiers{'nullable'}
be4469ab 257 ? $qualifiers{'nullable'} : 1;
e5f65c59 258 $return = {
be4469ab 259 supertype => 'field',
e5f65c59 260 name => $item{'field_name'},
be4469ab 261 data_type => $item{'data_type'}{'type'},
262 size => $item{'data_type'}{'size'},
e5f65c59 263 nullable => $nullable,
264 default => $qualifiers{'default_val'},
265 is_auto_inc => $qualifiers{'is_auto_inc'},
266# is_primary_key => $item{'primary_key'}[0],
267 }
be4469ab 268 }
269
270field_qualifier : nullable
e5f65c59 271 {
272 $return = {
be4469ab 273 nullable => $item{'nullable'},
e5f65c59 274 }
be4469ab 275 }
276
277field_qualifier : default_val
e5f65c59 278 {
279 $return = {
be4469ab 280 default_val => $item{'default_val'},
e5f65c59 281 }
be4469ab 282 }
283
284field_qualifier : auto_inc
e5f65c59 285 {
286 $return = {
be4469ab 287 is_auto_inc => $item{'auto_inc'},
e5f65c59 288 }
be4469ab 289 }
290
291constraint : primary_key_constraint
292 | foreign_key_constraint
293 | unique_constraint
294
295field_name : WORD
028386aa 296 { $return = $item[1] }
297 | LQUOTE WORD RQUOTE
298 { $return = $item[2] }
be4469ab 299
300index_name : WORD
028386aa 301 { $return = $item[1] }
302 | LQUOTE WORD RQUOTE
303 { $return = $item[2] }
be4469ab 304
305table_name : WORD
028386aa 306 { $return = $item[1] }
307 | LQUOTE WORD RQUOTE
308 { $return = $item[2] }
be4469ab 309
e5f65c59 310data_type : WORD field_size(?)
311 {
312 $return = {
313 type => $item[1],
be4469ab 314 size => $item[2][0]
e5f65c59 315 }
be4469ab 316 }
317
318lock : /lock/i /datarows/i
319
320field_type : WORD
321
322field_size : '(' num_range ')' { $item{'num_range'} }
323
324num_range : DIGITS ',' DIGITS
325 { $return = $item[1].','.$item[3] }
326 | DIGITS
327 { $return = $item[1] }
328
329
330nullable : /not/i /null/i
331 { $return = 0 }
332 | /null/i
333 { $return = 1 }
334
2a8fb466 335default_val : /default/i /null/i
336 { $return = 'null' }
e5f65c59 337 | /default/i /'[^']*'/
be4469ab 338 { $item[2]=~ s/'//g; $return = $item[2] }
e5f65c59 339 | /default/i WORD
06baeb21 340 { $return = $item[2] }
be4469ab 341
342auto_inc : /identity/i { 1 }
343
344primary_key_constraint : /constraint/i index_name(?) /primary/i /key/i parens_field_list
e5f65c59 345 {
346 $return = {
be4469ab 347 supertype => 'constraint',
348 name => $item[2][0],
349 type => 'primary_key',
350 fields => $item[5],
e5f65c59 351 }
be4469ab 352 }
353
100684f3 354foreign_key_constraint : /constraint/i index_name(?) /foreign/i /key/i parens_field_list /references/i table_name parens_field_list(?) on_delete(?) on_update(?)
be4469ab 355 {
e5f65c59 356 $return = {
be4469ab 357 supertype => 'constraint',
358 name => $item[2][0],
359 type => 'foreign_key',
360 fields => $item[5],
361 reference_table => $item[7],
e5f65c59 362 reference_fields => $item[8][0],
100684f3 363 on_delete => $item[9][0],
364 on_update => $item[10][0],
e5f65c59 365 }
be4469ab 366 }
367
e2fb9ad3 368unique_constraint : /constraint/i index_name(?) /unique/i parens_field_list
369 {
e5f65c59 370 $return = {
e2fb9ad3 371 supertype => 'constraint',
372 type => 'unique',
373 name => $item[2][0],
374 fields => $item[4],
375 }
376 }
377
028386aa 378unique_constraint : /unique/i clustered(?) INDEX(?) index_name(?) on_table(?) parens_field_list field_not_null(?)
e5f65c59 379 {
380 $return = {
be4469ab 381 supertype => 'constraint',
382 type => 'unique',
383 clustered => $item[2][0],
384 name => $item[4][0],
385 table => $item[5][0],
386 fields => $item[6],
e5f65c59 387 }
be4469ab 388 }
389
100684f3 390on_delete : /on delete/i reference_option
be4469ab 391 { $item[2] }
392
100684f3 393on_update : /on update/i reference_option
be4469ab 394 { $item[2] }
395
ff3dd529 396reference_option: /cascade/i
397 { $item[1] }
398 | /no action/i
399 { $item[1] }
be4469ab 400
401clustered : /clustered/i
402 { $return = 1 }
403 | /nonclustered/i
404 { $return = 0 }
405
406INDEX : /index/i
407
408on_table : /on/i table_name
409 { $return = $item[2] }
410
411on_system : /on/i /system/i
412 { $return = 1 }
413
e2fb9ad3 414index : clustered(?) INDEX index_name(?) on_table(?) parens_field_list END_STATEMENT
e5f65c59 415 {
416 $return = {
be4469ab 417 supertype => 'index',
418 type => 'normal',
419 clustered => $item[1][0],
420 name => $item[3][0],
421 table => $item[4][0],
422 fields => $item[5],
e5f65c59 423 }
be4469ab 424 }
425
426parens_field_list : '(' field_name(s /,/) ')'
427 { $item[2] }
428
028386aa 429ident : QUOTE WORD '.' WORD QUOTE | LQUOTE WORD '.' WORD RQUOTE
be4469ab 430 { $return = { owner => $item[2], name => $item[4] } }
028386aa 431 | LQUOTE WORD RQUOTE '.' LQUOTE WORD RQUOTE
432 { $return = { owner => $item[2], name => $item[6] } }
433 | LQUOTE WORD RQUOTE
434 { $return = { name => $item[2] } }
435 | WORD '.' WORD
436 { $return = { owner => $item[1], name => $item[3] } }
be4469ab 437 | WORD
438 { $return = { name => $item[1] } }
439
ff3dd529 440END_STATEMENT : ';'
e5f65c59 441 | GO
ff3dd529 442
be4469ab 443GO : /^go/i
444
445NAME : QUOTE(?) /\w+/ QUOTE(?)
446 { $item[2] }
447
448WORD : /[\w#]+/
449
450DIGITS : /\d+/
451
452COMMA : ','
453
454QUOTE : /'/
455
028386aa 456LQUOTE : '['
457
458RQUOTE : ']'
459
bdf60588 460END_OF_GRAMMAR
be4469ab 461
be4469ab 462sub parse {
463 my ( $translator, $data ) = @_;
bdf60588 464
465 # Enable warnings within the Parse::RecDescent module.
466 local $::RD_ERRORS = 1 unless defined $::RD_ERRORS; # Make sure the parser dies when it encounters an error
467 local $::RD_WARN = 1 unless defined $::RD_WARN; # Enable warnings. This will warn on unused rules &c.
468 local $::RD_HINT = 1 unless defined $::RD_HINT; # Give out hints to help fix problems.
be4469ab 469
470 local $::RD_TRACE = $translator->trace ? 1 : undef;
471 local $DEBUG = $translator->debug;
472
bdf60588 473 my $parser = ddl_parser_instance('SQLServer');
be4469ab 474
475 my $result = $parser->startrule($data);
476 return $translator->error( "Parse failed." ) unless defined $result;
477 warn Dumper( $result ) if $DEBUG;
478
479 my $schema = $translator->schema;
e5f65c59 480 my @tables = sort {
ff3dd529 481 $result->{tables}->{ $a }->{'order'} <=> $result->{tables}->{ $b }->{'order'}
482 } keys %{ $result->{tables} };
be4469ab 483
484 for my $table_name ( @tables ) {
ff3dd529 485 my $tdata = $result->{tables}->{ $table_name };
e5f65c59 486 my $table = $schema->add_table( name => $tdata->{'name'} )
be4469ab 487 or die "Can't create table '$table_name': ", $schema->error;
488
489 $table->comments( $tdata->{'comments'} );
490
e5f65c59 491 my @fields = sort {
492 $tdata->{'fields'}->{$a}->{'order'}
be4469ab 493 <=>
494 $tdata->{'fields'}->{$b}->{'order'}
495 } keys %{ $tdata->{'fields'} };
496
497 for my $fname ( @fields ) {
498 my $fdata = $tdata->{'fields'}{ $fname };
499 my $field = $table->add_field(
500 name => $fdata->{'name'},
501 data_type => $fdata->{'data_type'},
502 size => $fdata->{'size'},
503 default_value => $fdata->{'default'},
504 is_auto_increment => $fdata->{'is_auto_inc'},
505 is_nullable => $fdata->{'nullable'},
506 comments => $fdata->{'comments'},
507 ) or die $table->error;
508
509 $table->primary_key( $field->name ) if $fdata->{'is_primary_key'};
510
511 for my $qual ( qw[ binary unsigned zerofill list ] ) {
512 if ( my $val = $fdata->{ $qual } || $fdata->{ uc $qual } ) {
513 next if ref $val eq 'ARRAY' && !@$val;
514 $field->extra( $qual, $val );
515 }
516 }
517
518 if ( $field->data_type =~ /(set|enum)/i && !$field->size ) {
519 my %extra = $field->extra;
520 my $longest = 0;
521 for my $len ( map { length } @{ $extra{'list'} || [] } ) {
522 $longest = $len if $len > $longest;
523 }
524 $field->size( $longest ) if $longest;
525 }
526
527 for my $cdata ( @{ $fdata->{'constraints'} } ) {
528 next unless $cdata->{'type'} eq 'foreign_key';
529 $cdata->{'fields'} ||= [ $field->name ];
530 push @{ $tdata->{'constraints'} }, $cdata;
531 }
532 }
533
534 for my $idata ( @{ $tdata->{'indices'} || [] } ) {
535 my $index = $table->add_index(
536 name => $idata->{'name'},
537 type => uc $idata->{'type'},
538 fields => $idata->{'fields'},
539 ) or die $table->error;
540 }
541
542 for my $cdata ( @{ $tdata->{'constraints'} || [] } ) {
543 my $constraint = $table->add_constraint(
544 name => $cdata->{'name'},
545 type => $cdata->{'type'},
546 fields => $cdata->{'fields'},
547 reference_table => $cdata->{'reference_table'},
548 reference_fields => $cdata->{'reference_fields'},
549 match_type => $cdata->{'match_type'} || '',
100684f3 550 on_delete => $cdata->{'on_delete'} || $cdata->{'on_delete_do'},
551 on_update => $cdata->{'on_update'} || $cdata->{'on_update_do'},
be4469ab 552 ) or die $table->error;
553 }
554 }
e5f65c59 555
556 my @procedures = sort {
ff3dd529 557 $result->{procedures}->{ $a }->{'order'} <=> $result->{procedures}->{ $b }->{'order'}
558 } keys %{ $result->{procedures} };
559 for my $proc_name (@procedures) {
e5f65c59 560 $schema->add_procedure(
561 name => $proc_name,
562 owner => $result->{procedures}->{$proc_name}->{owner},
563 sql => $result->{procedures}->{$proc_name}->{sql},
564 );
ff3dd529 565 }
566
e5f65c59 567 my @views = sort {
ff3dd529 568 $result->{views}->{ $a }->{'order'} <=> $result->{views}->{ $b }->{'order'}
569 } keys %{ $result->{views} };
570 for my $view_name (keys %{ $result->{views} }) {
e5f65c59 571 $schema->add_view(
572 name => $view_name,
573 sql => $result->{views}->{$view_name}->{sql},
574 );
ff3dd529 575 }
be4469ab 576
577 return 1;
578}
579
5801;
581
582# -------------------------------------------------------------------
583# Every hero becomes a bore at last.
584# Ralph Waldo Emerson
585# -------------------------------------------------------------------
586
587=pod
588
589=head1 AUTHOR
590
591Chris Hilton E<lt>chris@dctank.comE<gt> - Bulk of code from
592Sybase parser, I just tweaked it for SQLServer. Thanks.
593
594=head1 SEE ALSO
595
596SQL::Translator, SQL::Translator::Parser::DBI, L<http://www.midsomer.org/>.
597
598=cut