Commit | Line | Data |
17cae8ab |
1 | package SQL::Translator::Parser::Oracle; |
2 | |
3 | # ------------------------------------------------------------------- |
947dfd86 |
4 | # $Id: Oracle.pm,v 1.2 2003-06-06 22:30:44 kycl4rk Exp $ |
17cae8ab |
5 | # ------------------------------------------------------------------- |
6 | # Copyright (C) 2003 Ken Y. Clark <kclark@cpan.org> |
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 | |
25 | SQL::Translator::Parser::Oracle - parser for Oracle |
26 | |
27 | =head1 SYNOPSIS |
28 | |
29 | use SQL::Translator; |
30 | use SQL::Translator::Parser::Oracle; |
31 | |
32 | my $translator = SQL::Translator->new; |
33 | $translator->parser("SQL::Translator::Parser::Oracle"); |
34 | |
35 | =head1 DESCRIPTION |
36 | |
37 | From http://www.ss64.com/ora/table_c.html: |
38 | |
39 | CREATE [GLOBAL TEMPORARY] TABLE [schema.]table (tbl_defs,...) |
40 | [ON COMMIT {DELETE|PRESERVE} ROWS] |
41 | [storage_options | CLUSTER cluster_name (col1, col2,... ) |
42 | | ORGANIZATION {HEAP [storage_options] |
43 | | INDEX idx_organized_tbl_clause}] |
44 | [LOB_storage_clause][varray_clause][nested_storage_clause] |
45 | partitioning_options |
46 | [[NO]CACHE] [[NO]MONITORING] [PARALLEL parallel_clause] |
47 | [ENABLE enable_clause | DISABLE disable_clause] |
48 | [AS subquery] |
49 | |
50 | tbl_defs: |
51 | column datatype [DEFAULT expr] [column_constraint(s)] |
52 | table_constraint |
53 | table_ref_constraint |
54 | |
55 | storage_options: |
56 | PCTFREE int |
57 | PCTUSED int |
58 | INITTRANS int |
59 | MAXTRANS int |
60 | STORAGE storage_clause |
61 | TABLESPACE tablespace |
62 | [LOGGING|NOLOGGING] |
63 | |
64 | idx_organized_tbl_clause: |
65 | storage_option(s) [PCTTHRESHOLD int] |
66 | [COMPRESS int|NOCOMPRESS] |
67 | [ [INCLUDING column_name] OVERFLOW [storage_option(s)] ] |
68 | |
69 | nested_storage_clause: |
70 | NESTED TABLE nested_item STORE AS storage_table |
71 | [RETURN AS {LOCATOR|VALUE} ] |
72 | |
73 | partitioning_options: |
74 | Partition_clause {ENABLE|DISABLE} ROW MOVEMENT |
75 | |
76 | Column Constraints |
77 | (http://www.ss64.com/ora/clause_constraint_col.html) |
78 | |
79 | CONSTRAINT constrnt_name {UNIQUE|PRIMARY KEY} constrnt_state |
80 | |
81 | CONSTRAINT constrnt_name CHECK(condition) constrnt_state |
82 | |
83 | CONSTRAINT constrnt_name [NOT] NULL constrnt_state |
84 | |
85 | CONSTRAINT constrnt_name REFERENCES [schema.]table[(column)] |
86 | [ON DELETE {CASCADE|SET NULL}] constrnt_state |
87 | |
88 | constrnt_state |
89 | [[NOT] DEFERRABLE] [INITIALLY {IMMEDIATE|DEFERRED}] |
90 | [RELY | NORELY] [USING INDEX using_index_clause] |
91 | [ENABLE|DISABLE] [VALIDATE|NOVALIDATE] |
92 | [EXCEPTIONS INTO [schema.]table] |
93 | |
94 | =cut |
95 | |
96 | use strict; |
97 | use vars qw[ $DEBUG $VERSION $GRAMMAR @EXPORT_OK ]; |
947dfd86 |
98 | $VERSION = sprintf "%d.%02d", q$Revision: 1.2 $ =~ /(\d+)\.(\d+)/; |
17cae8ab |
99 | $DEBUG = 0 unless defined $DEBUG; |
100 | |
101 | use Data::Dumper; |
102 | use Parse::RecDescent; |
103 | use Exporter; |
104 | use base qw(Exporter); |
105 | |
106 | @EXPORT_OK = qw(parse); |
107 | |
108 | # Enable warnings within the Parse::RecDescent module. |
109 | $::RD_ERRORS = 1; # Make sure the parser dies when it encounters an error |
110 | $::RD_WARN = 1; # Enable warnings. This will warn on unused rules &c. |
111 | $::RD_HINT = 1; # Give out hints to help fix problems. |
112 | |
113 | my $parser; |
114 | |
115 | $GRAMMAR = q! |
116 | |
117 | { our ( %tables, $table_order ) } |
118 | |
119 | # |
120 | # The "eofile" rule makes the parser fail if any "statement" rule |
121 | # fails. Otherwise, the first successful match by a "statement" |
122 | # won't cause the failure needed to know that the parse, as a whole, |
123 | # failed. -ky |
124 | # |
125 | startrule : statement(s) eofile { \%tables } |
126 | |
127 | eofile : /^\Z/ |
128 | |
129 | statement : create |
130 | | comment |
131 | | comment_on_table |
132 | | comment_on_column |
133 | | <error> |
134 | |
135 | create : create_table table_name '(' create_definition(s /,/) ')' table_option(s?) ';' |
136 | { |
137 | my $table_name = $item{'table_name'}; |
138 | $tables{ $table_name }{'order'} = ++$table_order; |
139 | $tables{ $table_name }{'table_name'} = $table_name; |
140 | |
141 | my $i = 1; |
142 | my @constraints; |
143 | for my $definition ( @{ $item[4] } ) { |
144 | if ( $definition->{'type'} eq 'field' ) { |
145 | my $field_name = $definition->{'name'}; |
146 | $tables{ $table_name }{'fields'}{ $field_name } = |
147 | { %$definition, order => $i }; |
148 | $i++; |
149 | |
17cae8ab |
150 | for my $constraint ( @{ $definition->{'constraints'} || [] } ) { |
151 | $constraint->{'fields'} = [ $field_name ]; |
152 | push @{ $tables{ $table_name }{'constraints'} }, |
153 | $constraint; |
154 | } |
155 | } |
156 | elsif ( $definition->{'type'} eq 'constraint' ) { |
157 | $definition->{'type'} = $definition->{'constraint_type'}; |
158 | # group FKs at the field level |
947dfd86 |
159 | # if ( $definition->{'type'} eq 'foreign_key' ) { |
160 | # for my $fld ( @{ $definition->{'fields'} || [] } ) { |
161 | # push @{ |
162 | # $tables{$table_name}{'fields'}{$fld}{'constraints'} |
163 | # }, $definition; |
164 | # } |
165 | # } |
166 | # else { |
17cae8ab |
167 | push @{ $tables{ $table_name }{'constraints'} }, |
168 | $definition; |
947dfd86 |
169 | # } |
17cae8ab |
170 | } |
171 | else { |
172 | push @{ $tables{ $table_name }{'indices'} }, $definition; |
173 | } |
174 | } |
175 | |
176 | for my $option ( @{ $item[6] } ) { |
177 | $tables{ $table_name }{'table_options'}{ $option->{'type'} } = |
178 | $option; |
179 | } |
180 | |
181 | 1; |
182 | } |
183 | |
184 | # Create anything else (e.g., domain, function, etc.) |
185 | create : /create/i WORD /[^;]+/ ';' |
186 | |
187 | global_temporary: /global/i /temporary/i |
188 | |
189 | table_name : NAME '.' NAME |
190 | { $item[3] } |
191 | | NAME |
192 | { $item[1] } |
193 | |
194 | create_definition : field |
195 | | table_constraint |
196 | | <error> |
197 | |
198 | comment : /^\s*(?:#|-{2}).*\n/ |
199 | |
947dfd86 |
200 | comment_on_table : /comment/i /on/i /table/i table_name /is/i comment_phrase ';' |
17cae8ab |
201 | { |
947dfd86 |
202 | push @{ $tables{ $item{'table_name'} }{'comments'} }, $item{'comment_phrase'}; |
17cae8ab |
203 | } |
204 | |
947dfd86 |
205 | comment_on_column : /comment/i /on/i /column/i column_name /is/i comment_phrase ';' |
17cae8ab |
206 | { |
207 | my $table_name = $item[4]->{'table'}; |
208 | my $field_name = $item[4]->{'field'}; |
209 | push @{ $tables{ $table_name }{'fields'}{ $field_name }{'comments'} }, |
947dfd86 |
210 | $item{'comment_phrase'}; |
17cae8ab |
211 | } |
212 | |
213 | column_name : NAME '.' NAME |
214 | { $return = { table => $item[1], field => $item[3] } } |
215 | |
947dfd86 |
216 | comment_phrase : /'.*?'/ |
217 | { |
218 | my $val = $item[1]; |
219 | $val =~ s/^'|'$//g; |
220 | $return = $val; |
221 | } |
17cae8ab |
222 | |
223 | field : comment(s?) field_name data_type field_meta(s?) comment(s?) |
224 | { |
947dfd86 |
225 | my ( $is_pk, $default, @constraints ); |
226 | my $null = 1; |
17cae8ab |
227 | for my $meta ( @{ $item[4] } ) { |
947dfd86 |
228 | if ( $meta->{'type'} eq 'default' ) { |
229 | $default = $meta; |
230 | next; |
231 | } |
232 | elsif ( $meta->{'type'} eq 'not_null' ) { |
233 | $null = 0; |
234 | next; |
235 | } |
236 | elsif ( $meta->{'type'} eq 'primary_key' ) { |
237 | $is_pk = 1; |
238 | } |
239 | |
240 | push @constraints, $meta if $meta->{'supertype'} eq 'constraint'; |
17cae8ab |
241 | } |
242 | |
947dfd86 |
243 | my @comments = ( @{ $item[1] }, @{ $item[5] } ); |
17cae8ab |
244 | |
245 | $return = { |
246 | type => 'field', |
247 | name => $item{'field_name'}, |
248 | data_type => $item{'data_type'}{'type'}, |
249 | size => $item{'data_type'}{'size'}, |
17cae8ab |
250 | null => $null, |
251 | default => $default->{'value'}, |
947dfd86 |
252 | is_primary_key => $is_pk, |
17cae8ab |
253 | constraints => [ @constraints ], |
947dfd86 |
254 | comments => [ @comments ], |
17cae8ab |
255 | } |
256 | } |
257 | | <error> |
258 | |
259 | field_name : NAME |
260 | |
261 | data_type : ora_data_type parens_value_list(?) |
262 | { |
263 | $return = { |
264 | type => $item[1], |
265 | size => $item[2][0] || '', |
266 | } |
267 | } |
268 | |
269 | column_constraint : constraint_name(?) column_constraint_type |
270 | #constraint_state(s /,/) |
271 | { |
272 | my $desc = $item{'column_constraint_type'}; |
273 | my $type = $desc->{'type'}; |
274 | my $fields = $desc->{'fields'} || []; |
275 | my $expression = $desc->{'expression'} || ''; |
276 | |
277 | $return = { |
947dfd86 |
278 | supertype => 'constraint', |
279 | name => $item{'constraint_name(?)'}[0] || '', |
17cae8ab |
280 | type => $type, |
281 | expression => $type eq 'check' ? $expression : '', |
282 | deferreable => $item{'deferrable'}, |
283 | deferred => $item{'deferred'}, |
284 | reference_table => $desc->{'reference_table'}, |
285 | reference_fields => $desc->{'reference_fields'}, |
286 | # match_type => $desc->{'match_type'}, |
287 | # on_update_do => $desc->{'on_update_do'}, |
288 | } |
289 | } |
290 | |
291 | constraint_name : /constraint/i NAME { $item[2] } |
292 | |
293 | column_constraint_type : /not null/i { $return = { type => 'not_null' } } |
947dfd86 |
294 | | /null/ |
17cae8ab |
295 | { $return = { type => 'null' } } |
947dfd86 |
296 | | /unique/ |
17cae8ab |
297 | { $return = { type => 'unique' } } |
947dfd86 |
298 | | /primary key/i |
17cae8ab |
299 | { $return = { type => 'primary_key' } } |
947dfd86 |
300 | | /check/i '(' /[^)]+/ ')' |
17cae8ab |
301 | { $return = { type => 'check', expression => $item[2] } } |
947dfd86 |
302 | | /references/i table_name parens_word_list(?) on_delete_do(?) |
17cae8ab |
303 | { |
304 | $return = { |
305 | type => 'foreign_key', |
306 | reference_table => $item[2], |
307 | reference_fields => $item[3][0], |
308 | # match_type => $item[4][0], |
309 | on_delete_do => $item[5][0], |
310 | } |
311 | } |
312 | |
313 | #constraint_state : deferrable { $return = { type => $item[1] } } |
314 | # | deferred { $return = { type => $item[1] } } |
315 | # | /(no)?rely/ { $return = { type => $item[1] } } |
316 | # | /using/i /index/i using_index_clause |
317 | # { $return = { type => 'using_index', index => $item[3] } |
318 | # | (dis)?enable { $return = { type => $item[1] } } |
319 | # | (no)?validate { $return = { type => $item[1] } } |
320 | # | /exceptions/i /into/i table_name |
321 | # { $return = { type => 'exceptions_into', table => $item[3] } } |
322 | |
323 | deferrable : /not/i /deferrable/i |
324 | { $return = 'not_deferrable' } |
325 | | /deferrable/i |
326 | { $return = 'deferrable' } |
327 | |
328 | deferred : /initially/i /(deferred|immediate)/i { $item[2] } |
329 | |
330 | ora_data_type : |
947dfd86 |
331 | /(n?varchar2|varchar)/i { $return = 'varchar2' } |
17cae8ab |
332 | | |
333 | /n?char/i { $return = 'character' } |
334 | | |
335 | /number/i { $return = 'number' } |
336 | | |
337 | /(pls_integer|binary_integer)/i { $return = 'integer' } |
338 | | |
339 | /interval\s+day/i { $return = 'interval_day' } |
340 | | |
341 | /interval\s+year/i { $return = 'interval_year' } |
342 | | |
343 | /long\s+raw/i { $return = 'long_raw' } |
344 | | |
345 | /(long|date|timestamp|raw|rowid|urowid|mlslabel|clob|nclob|blob|bfile)/i { $item[1] } |
346 | |
347 | parens_value_list : '(' VALUE(s /,/) ')' |
348 | { $item[2] } |
349 | |
350 | parens_word_list : '(' WORD(s /,/) ')' |
351 | { $item[2] } |
352 | |
353 | field_meta : default_val |
947dfd86 |
354 | | column_constraint |
17cae8ab |
355 | |
356 | default_val : /default/i /(?:')?[\w\d.-]*(?:')?/ |
357 | { |
358 | my $val = $item[2] || ''; |
359 | $val =~ s/'//g; |
360 | $return = { |
947dfd86 |
361 | supertype => 'constraint', |
362 | type => 'default', |
17cae8ab |
363 | value => $val, |
364 | } |
365 | } |
366 | |
367 | create_table : /create/i global_temporary(?) /table/i |
368 | |
369 | table_option : /[^;]+/ |
370 | |
371 | table_constraint : comment(s?) constraint_name(?) table_constraint_type deferrable(?) deferred(?) comment(s?) |
372 | { |
373 | my $desc = $item{'table_constraint_type'}; |
374 | my $type = $desc->{'type'}; |
375 | my $fields = $desc->{'fields'}; |
376 | my $expression = $desc->{'expression'}; |
377 | my @comments = ( @{ $item[1] }, @{ $item[-1] } ); |
378 | |
379 | $return = { |
947dfd86 |
380 | name => $item{'constraint_name(?)'}[0] || '', |
17cae8ab |
381 | type => 'constraint', |
382 | constraint_type => $type, |
383 | fields => $type ne 'check' ? $fields : [], |
384 | expression => $type eq 'check' ? $expression : '', |
947dfd86 |
385 | deferreable => $item{'deferrable(?)'}, |
386 | deferred => $item{'deferred(?)'}, |
17cae8ab |
387 | reference_table => $desc->{'reference_table'}, |
388 | reference_fields => $desc->{'reference_fields'}, |
389 | # match_type => $desc->{'match_type'}[0], |
390 | on_delete_do => $desc->{'on_delete_do'}, |
391 | on_update_do => $desc->{'on_update_do'}, |
392 | comments => [ @comments ], |
393 | } |
394 | } |
395 | |
396 | table_constraint_type : /primary key/i '(' NAME(s /,/) ')' |
397 | { |
398 | $return = { |
399 | type => 'primary_key', |
400 | fields => $item[3], |
401 | } |
402 | } |
403 | | |
404 | /unique/i '(' NAME(s /,/) ')' |
405 | { |
406 | $return = { |
407 | type => 'unique', |
408 | fields => $item[3], |
409 | } |
410 | } |
411 | | |
412 | /check/ '(' /(.+)/ ')' |
413 | { |
414 | $return = { |
415 | type => 'check', |
416 | expression => $item[3], |
417 | } |
418 | } |
419 | | |
420 | /foreign key/i '(' NAME(s /,/) ')' /references/i table_name parens_word_list(?) on_delete_do(?) |
421 | { |
422 | $return = { |
423 | type => 'foreign_key', |
424 | fields => $item[3], |
425 | reference_table => $item[6], |
426 | reference_fields => $item[7][0], |
427 | match_type => $item[8][0], |
428 | on_delete_do => $item[9][0], |
429 | on_update_do => $item[10][0], |
430 | } |
431 | } |
432 | |
433 | on_delete_do : /on delete/i WORD(s) |
434 | { $item[2] } |
435 | |
436 | WORD : /\w+/ |
437 | |
438 | NAME : /\w+/ { $item[1] } |
439 | |
440 | VALUE : /[-+]?\.?\d+(?:[eE]\d+)?/ |
441 | { $item[1] } |
442 | | /'.*?'/ # XXX doesn't handle embedded quotes |
443 | { $item[1] } |
444 | | /NULL/ |
445 | { 'NULL' } |
446 | |
447 | !; |
448 | |
449 | # ------------------------------------------------------------------- |
450 | sub parse { |
451 | my ( $translator, $data ) = @_; |
452 | $parser ||= Parse::RecDescent->new($GRAMMAR); |
453 | |
454 | local $::RD_TRACE = $translator->trace ? 1 : undef; |
455 | local $DEBUG = $translator->debug; |
456 | |
457 | unless (defined $parser) { |
458 | return $translator->error("Error instantiating Parse::RecDescent ". |
459 | "instance: Bad grammer"); |
460 | } |
461 | |
462 | my $result = $parser->startrule($data); |
463 | die "Parse failed.\n" unless defined $result; |
464 | warn Dumper($result) if $DEBUG; |
947dfd86 |
465 | |
466 | my $schema = $translator->schema; |
467 | my @tables = sort { |
468 | $result->{ $a }->{'order'} <=> $result->{ $b }->{'order'} |
469 | } keys %{ $result }; |
470 | |
471 | for my $table_name ( @tables ) { |
472 | my $tdata = $result->{ $table_name }; |
473 | my $table = $schema->add_table( |
474 | name => $tdata->{'table_name'}, |
475 | comments => @{ $tdata->{'comments'} }, |
476 | ) or die $schema->error; |
477 | |
478 | my @fields = sort { |
479 | $tdata->{'fields'}->{$a}->{'order'} |
480 | <=> |
481 | $tdata->{'fields'}->{$b}->{'order'} |
482 | } keys %{ $tdata->{'fields'} }; |
483 | |
484 | for my $fname ( @fields ) { |
485 | my $fdata = $tdata->{'fields'}{ $fname }; |
486 | my $field = $table->add_field( |
487 | name => $fdata->{'name'}, |
488 | data_type => $fdata->{'data_type'}, |
489 | size => $fdata->{'size'}, |
490 | default_value => $fdata->{'default'}, |
491 | is_auto_increment => $fdata->{'is_auto_inc'}, |
492 | is_nullable => $fdata->{'null'}, |
493 | comments => @{ $fdata->{'comments'} }, |
494 | ) or die $table->error; |
495 | |
496 | for my $cdata ( @{ $fdata->{'constraints'} } ) { |
497 | next unless $cdata->{'type'} eq 'foreign_key'; |
498 | $cdata->{'fields'} ||= [ $field->name ]; |
499 | push @{ $tdata->{'constraints'} }, $cdata; |
500 | } |
501 | } |
502 | |
503 | for my $idata ( @{ $tdata->{'indices'} || [] } ) { |
504 | my $index = $table->add_index( |
505 | name => $idata->{'name'}, |
506 | type => uc $idata->{'type'}, |
507 | fields => $idata->{'fields'}, |
508 | ) or die $table->error; |
509 | } |
510 | |
511 | for my $cdata ( @{ $tdata->{'constraints'} || [] } ) { |
512 | my $constraint = $table->add_constraint( |
513 | name => $cdata->{'name'}, |
514 | type => $cdata->{'type'}, |
515 | fields => $cdata->{'fields'}, |
516 | reference_table => $cdata->{'reference_table'}, |
517 | reference_fields => $cdata->{'reference_fields'}, |
518 | match_type => $cdata->{'match_type'} || '', |
519 | on_delete => $cdata->{'on_delete_do'}, |
520 | on_update => $cdata->{'on_update_do'}, |
521 | ) or die $table->error; |
522 | } |
523 | } |
524 | |
17cae8ab |
525 | return $result; |
526 | } |
527 | |
528 | 1; |
529 | |
947dfd86 |
530 | # ------------------------------------------------------------------- |
531 | # Something there is that doesn't love a wall. |
532 | # Robert Frost |
533 | # ------------------------------------------------------------------- |
534 | |
17cae8ab |
535 | =pod |
536 | |
537 | =head1 AUTHOR |
538 | |
539 | Ken Y. Clark E<lt>kclark@cpan.orgE<gt>. |
540 | |
541 | =head1 SEE ALSO |
542 | |
543 | perl(1), Parse::RecDescent. |
544 | |
545 | =cut |