A whole lot of changes, but major additions include adding diffs for table options...
[dbsrgits/SQL-Translator.git] / lib / SQL / Translator / Parser / SQLServer.pm
CommitLineData
be4469ab 1package SQL::Translator::Parser::SQLServer;
2
3# -------------------------------------------------------------------
4# $Id: SQLServer.pm,v 1.1 2005-06-27 19:01:31 duality72 Exp $
5# -------------------------------------------------------------------
6# Copyright (C) 2002-4 SQLFairy Authors
7#
8# This program is free software; you can redistribute it and/or
9# modify it under the terms of the GNU General Public License as
10# published by the Free Software Foundation; version 2.
11#
12# This program is distributed in the hope that it will be useful, but
13# WITHOUT ANY WARRANTY; without even the implied warranty of
14# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU
15# General Public License for more details.
16#
17# You should have received a copy of the GNU General Public License
18# along with this program; if not, write to the Free Software
19# Foundation, Inc., 59 Temple Place, Suite 330, Boston, MA
20# 02111-1307 USA
21# -------------------------------------------------------------------
22
23=head1 NAME
24
25SQL::Translator::Parser::SQLServer - parser for SQL Server
26
27=head1 SYNOPSIS
28
29 use SQL::Translator::Parser::SQLServer;
30
31=head1 DESCRIPTION
32
33Adapted from Parser::Sybase and mostly parses the output of
34Producer::SQLServer. The parsing is by no means complete and
35should probably be considered a work in progress.
36
37=cut
38
39use strict;
40
41use vars qw[ $DEBUG $VERSION $GRAMMAR @EXPORT_OK ];
42$VERSION = sprintf "%d.%02d", q$Revision: 1.1 $ =~ /(\d+)\.(\d+)/;
43$DEBUG = 0 unless defined $DEBUG;
44
45use Data::Dumper;
46use Parse::RecDescent;
47use Exporter;
48use base qw(Exporter);
49
50@EXPORT_OK = qw(parse);
51
52$::RD_ERRORS = 1;
53$::RD_WARN = 1;
54$::RD_HINT = 1;
55
56$GRAMMAR = q{
57
58{
59 my ( %tables, @table_comments, $table_order );
60}
61
62startrule : statement(s) eofile { \%tables }
63
64eofile : /^\Z/
65
66statement : create_table
67 | create_procedure
68 | create_index
69 | create_constraint
70 | comment
71 | use
72 | setuser
73 | if
74 | print
75 | grant
76 | exec
77 | <error>
78
79use : /use/i WORD GO
80 { @table_comments = () }
81
82setuser : /setuser/i NAME GO
83
84if : /if/i object_not_null begin if_command end GO
85
86if_command : grant
87 | create_index
88 | create_constraint
89
90object_not_null : /object_id/i '(' ident ')' /is not null/i
91
92print : /\s*/ /print/i /.*/
93
94else : /else/i /.*/
95
96begin : /begin/i
97
98end : /end/i
99
100grant : /grant/i /[^\n]*/
101
102exec : exec_statement(s) GO
103
104exec_statement : /exec/i /[^\n]+/
105
106comment : /^\s*(?:#|-{2}).*\n/
107 {
108 my $comment = $item[1];
109 $comment =~ s/^\s*(#|--)\s*//;
110 $comment =~ s/\s*$//;
111 $return = $comment;
112 push @table_comments, $comment;
113 }
114
115comment : comment_start comment_middle comment_end
116 {
117 my $comment = $item[2];
118 $comment =~ s/^\s*|\s*$//mg;
119 $comment =~ s/^\**\s*//mg;
120 push @table_comments, $comment;
121 }
122
123comment_start : m#^\s*\/\*#
124
125comment_end : m#\s*\*\/#
126
127comment_middle : m{([^*]+|\*(?!/))*}
128
129#
130# Create table.
131#
132create_table : /create/i /table/i ident '(' create_def(s /,/) ')' lock(?) on_system(?) ';' GO(?)
133 {
134 my $table_owner = $item[3]{'owner'};
135 my $table_name = $item[3]{'name'};
136
137 if ( @table_comments ) {
138 $tables{ $table_name }{'comments'} = [ @table_comments ];
139 @table_comments = ();
140 }
141
142 $tables{ $table_name }{'order'} = ++$table_order;
143 $tables{ $table_name }{'name'} = $table_name;
144 $tables{ $table_name }{'owner'} = $table_owner;
145 $tables{ $table_name }{'system'} = $item[7];
146
147 my $i = 0;
148 for my $def ( @{ $item[5] } ) {
149 if ( $def->{'supertype'} eq 'field' ) {
150 my $field_name = $def->{'name'};
151 $tables{ $table_name }{'fields'}{ $field_name } =
152 { %$def, order => $i };
153 $i++;
154
155 if ( $def->{'is_primary_key'} ) {
156 push @{ $tables{ $table_name }{'constraints'} }, {
157 type => 'primary_key',
158 fields => [ $field_name ],
159 };
160 }
161 }
162 elsif ( $def->{'supertype'} eq 'constraint' ) {
163 push @{ $tables{ $table_name }{'constraints'} }, $def;
164 }
165 else {
166 push @{ $tables{ $table_name }{'indices'} }, $def;
167 }
168 }
169 }
170
171create_constraint : /create/i constraint
172 {
173 @table_comments = ();
174 push @{ $tables{ $item[2]{'table'} }{'constraints'} }, $item[2];
175 }
176
177create_index : /create/i index
178 {
179 @table_comments = ();
180 push @{ $tables{ $item[2]{'table'} }{'indices'} }, $item[2];
181 }
182
183create_procedure : /create/i /procedure/i procedure_body GO
184 {
185 @table_comments = ();
186 }
187
188procedure_body : not_go(s)
189
190not_go : /((?!go).)*/
191
192create_def : constraint
193 | index
194 | field
195
196blank : /\s*/
197
198field : field_name data_type field_qualifier(s?)
199 {
200 my %qualifiers = map { %$_ } @{ $item{'field_qualifier(s?)'} || [] };
201 my $nullable = defined $qualifiers{'nullable'}
202 ? $qualifiers{'nullable'} : 1;
203 $return = {
204 supertype => 'field',
205 name => $item{'field_name'},
206 data_type => $item{'data_type'}{'type'},
207 size => $item{'data_type'}{'size'},
208 nullable => $nullable,
209 default => $qualifiers{'default_val'},
210 is_auto_inc => $qualifiers{'auto_inc'},
211# is_primary_key => $item{'primary_key'}[0],
212 }
213 }
214
215field_qualifier : nullable
216 {
217 $return = {
218 nullable => $item{'nullable'},
219 }
220 }
221
222field_qualifier : default_val
223 {
224 $return = {
225 default_val => $item{'default_val'},
226 }
227 }
228
229field_qualifier : auto_inc
230 {
231 $return = {
232 is_auto_inc => $item{'auto_inc'},
233 }
234 }
235
236constraint : primary_key_constraint
237 | foreign_key_constraint
238 | unique_constraint
239
240field_name : WORD
241
242index_name : WORD
243
244table_name : WORD
245
246data_type : WORD field_size(?)
247 {
248 $return = {
249 type => $item[1],
250 size => $item[2][0]
251 }
252 }
253
254lock : /lock/i /datarows/i
255
256field_type : WORD
257
258field_size : '(' num_range ')' { $item{'num_range'} }
259
260num_range : DIGITS ',' DIGITS
261 { $return = $item[1].','.$item[3] }
262 | DIGITS
263 { $return = $item[1] }
264
265
266nullable : /not/i /null/i
267 { $return = 0 }
268 | /null/i
269 { $return = 1 }
270
271default_val : /default/i /(?:')?[^']*(?:')?/
272 { $item[2]=~ s/'//g; $return = $item[2] }
273
274auto_inc : /identity/i { 1 }
275
276primary_key_constraint : /constraint/i index_name(?) /primary/i /key/i parens_field_list
277 {
278 $return = {
279 supertype => 'constraint',
280 name => $item[2][0],
281 type => 'primary_key',
282 fields => $item[5],
283 }
284 }
285
286foreign_key_constraint : /constraint/i index_name(?) /foreign/i /key/i parens_field_list /references/i table_name parens_field_list(?) on_delete_do(?) on_update_do(?)
287 {
288 $return = {
289 supertype => 'constraint',
290 name => $item[2][0],
291 type => 'foreign_key',
292 fields => $item[5],
293 reference_table => $item[7],
294 reference_fields => $item[8][0],
295 on_delete_do => $item[9][0],
296 on_update_do => $item[10][0],
297 }
298 }
299
300unique_constraint : /unique/i clustered(?) INDEX(?) index_name(?) on_table(?) parens_field_list
301 {
302 $return = {
303 supertype => 'constraint',
304 type => 'unique',
305 clustered => $item[2][0],
306 name => $item[4][0],
307 table => $item[5][0],
308 fields => $item[6],
309 }
310 }
311
312on_delete_do : /on delete/i reference_option
313 { $item[2] }
314
315on_update_do : /on update/i reference_option
316 { $item[2] }
317
318reference_option: /cascade/i |
319 /no action/i
320 { $item[1] }
321
322clustered : /clustered/i
323 { $return = 1 }
324 | /nonclustered/i
325 { $return = 0 }
326
327INDEX : /index/i
328
329on_table : /on/i table_name
330 { $return = $item[2] }
331
332on_system : /on/i /system/i
333 { $return = 1 }
334
335index : clustered(?) INDEX index_name(?) on_table(?) parens_field_list ';'
336 {
337 $return = {
338 supertype => 'index',
339 type => 'normal',
340 clustered => $item[1][0],
341 name => $item[3][0],
342 table => $item[4][0],
343 fields => $item[5],
344 }
345 }
346
347parens_field_list : '(' field_name(s /,/) ')'
348 { $item[2] }
349
350ident : QUOTE(?) WORD '.' WORD QUOTE(?)
351 { $return = { owner => $item[2], name => $item[4] } }
352 | WORD
353 { $return = { name => $item[1] } }
354
355GO : /^go/i
356
357NAME : QUOTE(?) /\w+/ QUOTE(?)
358 { $item[2] }
359
360WORD : /[\w#]+/
361
362DIGITS : /\d+/
363
364COMMA : ','
365
366QUOTE : /'/
367
368};
369
370# -------------------------------------------------------------------
371sub parse {
372 my ( $translator, $data ) = @_;
373 my $parser = Parse::RecDescent->new($GRAMMAR);
374
375 local $::RD_TRACE = $translator->trace ? 1 : undef;
376 local $DEBUG = $translator->debug;
377
378 unless (defined $parser) {
379 return $translator->error("Error instantiating Parse::RecDescent ".
380 "instance: Bad grammer");
381 }
382
383 my $result = $parser->startrule($data);
384 return $translator->error( "Parse failed." ) unless defined $result;
385 warn Dumper( $result ) if $DEBUG;
386
387 my $schema = $translator->schema;
388 my @tables = sort {
389 $result->{ $a }->{'order'} <=> $result->{ $b }->{'order'}
390 } keys %{ $result };
391
392 for my $table_name ( @tables ) {
393 my $tdata = $result->{ $table_name };
394 my $table = $schema->add_table( name => $tdata->{'name'} )
395 or die "Can't create table '$table_name': ", $schema->error;
396
397 $table->comments( $tdata->{'comments'} );
398
399 my @fields = sort {
400 $tdata->{'fields'}->{$a}->{'order'}
401 <=>
402 $tdata->{'fields'}->{$b}->{'order'}
403 } keys %{ $tdata->{'fields'} };
404
405 for my $fname ( @fields ) {
406 my $fdata = $tdata->{'fields'}{ $fname };
407 my $field = $table->add_field(
408 name => $fdata->{'name'},
409 data_type => $fdata->{'data_type'},
410 size => $fdata->{'size'},
411 default_value => $fdata->{'default'},
412 is_auto_increment => $fdata->{'is_auto_inc'},
413 is_nullable => $fdata->{'nullable'},
414 comments => $fdata->{'comments'},
415 ) or die $table->error;
416
417 $table->primary_key( $field->name ) if $fdata->{'is_primary_key'};
418
419 for my $qual ( qw[ binary unsigned zerofill list ] ) {
420 if ( my $val = $fdata->{ $qual } || $fdata->{ uc $qual } ) {
421 next if ref $val eq 'ARRAY' && !@$val;
422 $field->extra( $qual, $val );
423 }
424 }
425
426 if ( $field->data_type =~ /(set|enum)/i && !$field->size ) {
427 my %extra = $field->extra;
428 my $longest = 0;
429 for my $len ( map { length } @{ $extra{'list'} || [] } ) {
430 $longest = $len if $len > $longest;
431 }
432 $field->size( $longest ) if $longest;
433 }
434
435 for my $cdata ( @{ $fdata->{'constraints'} } ) {
436 next unless $cdata->{'type'} eq 'foreign_key';
437 $cdata->{'fields'} ||= [ $field->name ];
438 push @{ $tdata->{'constraints'} }, $cdata;
439 }
440 }
441
442 for my $idata ( @{ $tdata->{'indices'} || [] } ) {
443 my $index = $table->add_index(
444 name => $idata->{'name'},
445 type => uc $idata->{'type'},
446 fields => $idata->{'fields'},
447 ) or die $table->error;
448 }
449
450 for my $cdata ( @{ $tdata->{'constraints'} || [] } ) {
451 my $constraint = $table->add_constraint(
452 name => $cdata->{'name'},
453 type => $cdata->{'type'},
454 fields => $cdata->{'fields'},
455 reference_table => $cdata->{'reference_table'},
456 reference_fields => $cdata->{'reference_fields'},
457 match_type => $cdata->{'match_type'} || '',
458 on_delete => $cdata->{'on_delete_do'},
459 on_update => $cdata->{'on_update_do'},
460 ) or die $table->error;
461 }
462 }
463
464 return 1;
465}
466
4671;
468
469# -------------------------------------------------------------------
470# Every hero becomes a bore at last.
471# Ralph Waldo Emerson
472# -------------------------------------------------------------------
473
474=pod
475
476=head1 AUTHOR
477
478Chris Hilton E<lt>chris@dctank.comE<gt> - Bulk of code from
479Sybase parser, I just tweaked it for SQLServer. Thanks.
480
481=head1 SEE ALSO
482
483SQL::Translator, SQL::Translator::Parser::DBI, L<http://www.midsomer.org/>.
484
485=cut