Added an 'alter sequence' line to the parser grammer which will simply skip over...
[dbsrgits/SQL-Translator.git] / lib / SQL / Translator / Parser / PostgreSQL.pm
CommitLineData
84012a55 1package SQL::Translator::Parser::PostgreSQL;
4422e22a 2
3# -------------------------------------------------------------------
a20abbda 4# $Id: PostgreSQL.pm,v 1.50 2007-11-13 19:25:04 mwz444 Exp $
4422e22a 5# -------------------------------------------------------------------
90075866 6# Copyright (C) 2002-4 SQLFairy Authors
4422e22a 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
0efb6e1b 19# Foundation, Inc., 59 Temple Place, Suite 330, Boston, MA
4422e22a 20# 02111-1307 USA
21# -------------------------------------------------------------------
22
23=head1 NAME
24
84012a55 25SQL::Translator::Parser::PostgreSQL - parser for PostgreSQL
4422e22a 26
27=head1 SYNOPSIS
28
29 use SQL::Translator;
84012a55 30 use SQL::Translator::Parser::PostgreSQL;
4422e22a 31
32 my $translator = SQL::Translator->new;
84012a55 33 $translator->parser("SQL::Translator::Parser::PostgreSQL");
4422e22a 34
35=head1 DESCRIPTION
36
0efb6e1b 37The grammar was started from the MySQL parsers. Here is the description
38from PostgreSQL:
39
40Table:
629b76f9 41(http://www.postgresql.org/docs/view.php?version=7.3&idoc=1&file=sql-createtable.html)
42
43 CREATE [ [ LOCAL ] { TEMPORARY | TEMP } ] TABLE table_name (
44 { column_name data_type [ DEFAULT default_expr ]
45 [ column_constraint [, ... ] ]
46 | table_constraint } [, ... ]
47 )
48 [ INHERITS ( parent_table [, ... ] ) ]
49 [ WITH OIDS | WITHOUT OIDS ]
50
51 where column_constraint is:
52
53 [ CONSTRAINT constraint_name ]
54 { NOT NULL | NULL | UNIQUE | PRIMARY KEY |
55 CHECK (expression) |
56 REFERENCES reftable [ ( refcolumn ) ] [ MATCH FULL | MATCH PARTIAL ]
57 [ ON DELETE action ] [ ON UPDATE action ] }
58 [ DEFERRABLE | NOT DEFERRABLE ]
59 [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
60
61 and table_constraint is:
62
63 [ CONSTRAINT constraint_name ]
64 { UNIQUE ( column_name [, ... ] ) |
65 PRIMARY KEY ( column_name [, ... ] ) |
66 CHECK ( expression ) |
67 FOREIGN KEY ( column_name [, ... ] )
68 REFERENCES reftable [ ( refcolumn [, ... ] ) ]
69 [ MATCH FULL | MATCH PARTIAL ]
70 [ ON DELETE action ] [ ON UPDATE action ] }
71 [ DEFERRABLE | NOT DEFERRABLE ]
72 [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
0efb6e1b 73
74Index:
629b76f9 75(http://www.postgresql.org/docs/view.php?version=7.3&idoc=1&file=sql-createindex.html)
0efb6e1b 76
629b76f9 77 CREATE [ UNIQUE ] INDEX index_name ON table
78 [ USING acc_method ] ( column [ ops_name ] [, ...] )
79 [ WHERE predicate ]
80 CREATE [ UNIQUE ] INDEX index_name ON table
81 [ USING acc_method ] ( func_name( column [, ... ]) [ ops_name ] )
82 [ WHERE predicate ]
4422e22a 83
0012a163 84Alter table:
85
86 ALTER TABLE [ ONLY ] table [ * ]
87 ADD [ COLUMN ] column type [ column_constraint [ ... ] ]
88 ALTER TABLE [ ONLY ] table [ * ]
89 ALTER [ COLUMN ] column { SET DEFAULT value | DROP DEFAULT }
90 ALTER TABLE [ ONLY ] table [ * ]
91 ALTER [ COLUMN ] column SET STATISTICS integer
92 ALTER TABLE [ ONLY ] table [ * ]
93 RENAME [ COLUMN ] column TO newcolumn
94 ALTER TABLE table
95 RENAME TO new_table
96 ALTER TABLE table
97 ADD table_constraint_definition
98 ALTER TABLE [ ONLY ] table
99 DROP CONSTRAINT constraint { RESTRICT | CASCADE }
100 ALTER TABLE table
101 OWNER TO new_owner
102
3022f45b 103View table:
104
105 CREATE [ OR REPLACE ] VIEW view [ ( column name list ) ] AS SELECT query
106
4422e22a 107=cut
108
109use strict;
110use vars qw[ $DEBUG $VERSION $GRAMMAR @EXPORT_OK ];
a20abbda 111$VERSION = sprintf "%d.%02d", q$Revision: 1.50 $ =~ /(\d+)\.(\d+)/;
4422e22a 112$DEBUG = 0 unless defined $DEBUG;
113
114use Data::Dumper;
115use Parse::RecDescent;
116use Exporter;
117use base qw(Exporter);
118
119@EXPORT_OK = qw(parse);
120
121# Enable warnings within the Parse::RecDescent module.
122$::RD_ERRORS = 1; # Make sure the parser dies when it encounters an error
123$::RD_WARN = 1; # Enable warnings. This will warn on unused rules &c.
124$::RD_HINT = 1; # Give out hints to help fix problems.
125
126my $parser; # should we do this? There's no programmic way to
127 # change the grammar, so I think this is safe.
128
129$GRAMMAR = q!
130
00ef67ea 131{ my ( %tables, $table_order, $field_order, @table_comments) }
4422e22a 132
629b76f9 133#
134# The "eofile" rule makes the parser fail if any "statement" rule
135# fails. Otherwise, the first successful match by a "statement"
136# won't cause the failure needed to know that the parse, as a whole,
137# failed. -ky
138#
0efb6e1b 139startrule : statement(s) eofile { \%tables }
4422e22a 140
0efb6e1b 141eofile : /^\Z/
e4a9818d 142
0efb6e1b 143
144statement : create
ac397a49 145 | comment_on_table
146 | comment_on_column
e4a9818d 147 | comment_on_other
0efb6e1b 148 | comment
0012a163 149 | alter
0efb6e1b 150 | grant
151 | revoke
4422e22a 152 | drop
4d2da1f7 153 | insert
0efb6e1b 154 | connect
4d2da1f7 155 | update
0012a163 156 | set
cc74bccc 157 | select
158 | copy
159 | readin_symbol
4422e22a 160 | <error>
161
0efb6e1b 162connect : /^\s*\\\connect.*\n/
163
f04713db 164set : /set/i /[^;]*/ ';'
0012a163 165
0d51cd9e 166revoke : /revoke/i WORD(s /,/) /on/i TABLE(?) table_name /from/i name_with_opt_quotes(s /,/) ';'
0efb6e1b 167 {
a20abbda 168 my $table_info = $item{'table_name'};
169 my $schema_name = $table_info->{'schema_name'};
170 my $table_name = $table_info->{'table_name'};
0efb6e1b 171 push @{ $tables{ $table_name }{'permissions'} }, {
172 type => 'revoke',
173 actions => $item[2],
91c75eab 174 users => $item[7],
0efb6e1b 175 }
176 }
177
cc74bccc 178revoke : /revoke/i WORD(s /,/) /on/i SCHEMA(?) schema_name /from/i name_with_opt_quotes(s /,/) ';'
179 { 1 }
180
0d51cd9e 181grant : /grant/i WORD(s /,/) /on/i TABLE(?) table_name /to/i name_with_opt_quotes(s /,/) ';'
0efb6e1b 182 {
a20abbda 183 my $table_info = $item{'table_name'};
184 my $schema_name = $table_info->{'schema_name'};
185 my $table_name = $table_info->{'table_name'};
0efb6e1b 186 push @{ $tables{ $table_name }{'permissions'} }, {
187 type => 'grant',
188 actions => $item[2],
91c75eab 189 users => $item[7],
0efb6e1b 190 }
191 }
192
cc74bccc 193grant : /grant/i WORD(s /,/) /on/i SCHEMA(?) schema_name /to/i name_with_opt_quotes(s /,/) ';'
194 { 1 }
195
0efb6e1b 196drop : /drop/i /[^;]*/ ';'
4422e22a 197
9bf756df 198string :
199 /'(\\.|''|[^\\\'])*'/
4d2da1f7 200
9bf756df 201nonstring : /[^;\'"]+/
202
203statement_body : (string | nonstring)(s?)
204
205insert : /insert/i statement_body ';'
206
207update : /update/i statement_body ';'
4d2da1f7 208
0012a163 209#
210# Create table.
211#
c7ea1132 212create : create_table table_name '(' create_definition(s? /,/) ')' table_option(s?) ';'
0efb6e1b 213 {
a20abbda 214 my $table_info = $item{'table_name'};
215 my $schema_name = $table_info->{'schema_name'};
216 my $table_name = $table_info->{'table_name'};
217 $tables{ $table_name }{'order'} = ++$table_order;
218 $tables{ $table_name }{'schema_name'} = $schema_name;
219 $tables{ $table_name }{'table_name'} = $table_name;
0efb6e1b 220
ac397a49 221 if ( @table_comments ) {
222 $tables{ $table_name }{'comments'} = [ @table_comments ];
223 @table_comments = ();
224 }
225
0efb6e1b 226 my @constraints;
227 for my $definition ( @{ $item[4] } ) {
b3384294 228 if ( $definition->{'supertype'} eq 'field' ) {
0efb6e1b 229 my $field_name = $definition->{'name'};
230 $tables{ $table_name }{'fields'}{ $field_name } =
00ef67ea 231 { %$definition, order => $field_order++ };
4422e22a 232
0138f7bb 233 for my $constraint ( @{ $definition->{'constraints'} || [] } ) {
234 $constraint->{'fields'} = [ $field_name ];
7d5bcab8 235 push @{ $tables{ $table_name }{'constraints'} },
0138f7bb 236 $constraint;
0efb6e1b 237 }
238 }
b3384294 239 elsif ( $definition->{'supertype'} eq 'constraint' ) {
240 push @{ $tables{ $table_name }{'constraints'} }, $definition;
0efb6e1b 241 }
b3384294 242 elsif ( $definition->{'supertype'} eq 'index' ) {
0efb6e1b 243 push @{ $tables{ $table_name }{'indices'} }, $definition;
244 }
245 }
246
247 for my $option ( @{ $item[6] } ) {
3022f45b 248 $tables{ $table_name }{'table_options(s?)'}{ $option->{'type'} } =
0efb6e1b 249 $option;
250 }
251
252 1;
253 }
254
211e2e90 255create : CREATE unique(?) /(index|key)/i index_name /on/i table_name using_method(?) '(' field_name(s /,/) ')' where_predicate(?) ';'
4422e22a 256 {
a20abbda 257 my $table_info = $item{'table_name'};
258 my $schema_name = $table_info->{'schema_name'};
259 my $table_name = $table_info->{'table_name'};
260 push @{ $tables{ $table_name }{'indices'} },
4422e22a 261 {
b3384294 262 name => $item{'index_name'},
263 supertype => $item{'unique'}[0] ? 'constraint' : 'index',
264 type => $item{'unique'}[0] ? 'unique' : 'normal',
265 fields => $item[9],
266 method => $item{'using_method'}[0],
4422e22a 267 }
268 ;
ac397a49 269
4422e22a 270 }
271
0012a163 272#
211e2e90 273# Create anything else (e.g., domain, etc.)
0012a163 274#
211e2e90 275create : CREATE WORD /[^;]+/ ';'
ac397a49 276 { @table_comments = (); }
0012a163 277
0efb6e1b 278using_method : /using/i WORD { $item[2] }
279
280where_predicate : /where/i /[^;]+/
281
282create_definition : field
0efb6e1b 283 | table_constraint
4422e22a 284 | <error>
285
a82fa2cb 286comment : /^\s*(?:#|-{2})(.*)\n/
287 {
288 my $comment = $item[1];
289 $comment =~ s/^\s*(#|-*)\s*//;
290 $comment =~ s/\s*$//;
ac397a49 291 $return = $comment;
292 push @table_comments, $comment;
293 }
294
ac397a49 295comment_on_table : /comment/i /on/i /table/i table_name /is/i comment_phrase ';'
296 {
a20abbda 297 my $table_info = $item{'table_name'};
298 my $schema_name = $table_info->{'schema_name'};
299 my $table_name = $table_info->{'table_name'};
300 push @{ $tables{ $table_name }{'comments'} }, $item{'comment_phrase'};
ac397a49 301 }
302
303comment_on_column : /comment/i /on/i /column/i column_name /is/i comment_phrase ';'
304 {
305 my $table_name = $item[4]->{'table'};
306 my $field_name = $item[4]->{'field'};
e1fa2c52 307 if ($tables{ $table_name }{'fields'}{ $field_name } ) {
308 push @{ $tables{ $table_name }{'fields'}{ $field_name }{'comments'} },
309 $item{'comment_phrase'};
310 }
311 else {
312 die "No such column as $table_name.$field_name";
313 }
ac397a49 314 }
315
e4a9818d 316comment_on_other : /comment/i /on/i /\w+/ /\w+/ /is/i comment_phrase ';'
317 {
318 push(@table_comments, $item{'comment_phrase'});
319 }
320
321# [added by cjm 20041019]
322# [TODO: other comment-on types]
323# for now we just have a general mechanism for handling other
324# kinds of comments than table/column; I'm not sure of the best
325# way to incorporate these into the datamodel
326#
327# this is the exhaustive list of types of comment:
328#COMMENT ON DATABASE my_database IS 'Development Database';
329#COMMENT ON INDEX my_index IS 'Enforces uniqueness on employee id';
330#COMMENT ON RULE my_rule IS 'Logs UPDATES of employee records';
331#COMMENT ON SEQUENCE my_sequence IS 'Used to generate primary keys';
332#COMMENT ON TABLE my_table IS 'Employee Information';
333#COMMENT ON TYPE my_type IS 'Complex Number support';
334#COMMENT ON VIEW my_view IS 'View of departmental costs';
335#COMMENT ON COLUMN my_table.my_field IS 'Employee ID number';
336#COMMENT ON TRIGGER my_trigger ON my_table IS 'Used for R.I.';
337#
338# this is tested by test 08
339
ac397a49 340column_name : NAME '.' NAME
341 { $return = { table => $item[1], field => $item[3] } }
342
e4a9818d 343comment_phrase : /null/i
344 { $return = 'NULL' }
345
346comment_phrase : /'/ comment_phrase_unquoted(s) /'/
347 { my $phrase = join(' ', @{ $item[2] });
348 $return = $phrase}
349
350# [cjm TODO: double-single quotes in a comment_phrase]
351comment_phrase_unquoted : /[^\']*/
352 { $return = $item[1] }
353
354
355xxxcomment_phrase : /'.*?'|NULL/
ac397a49 356 {
8e9e79dc 357 my $val = $item[1] || '';
ac397a49 358 $val =~ s/^'|'$//g;
359 $return = $val;
360 }
361
a82fa2cb 362field : field_comment(s?) field_name data_type field_meta(s?) field_comment(s?)
4422e22a 363 {
3022f45b 364 my ( $default, @constraints, $is_pk );
00ef67ea 365 my $is_nullable = 1;
41fc9cb3 366 for my $meta ( @{ $item[4] } ) {
82968eb9 367 if ( $meta->{'type'} eq 'default' ) {
368 $default = $meta;
369 next;
370 }
371 elsif ( $meta->{'type'} eq 'not_null' ) {
00ef67ea 372 $is_nullable = 0;
82968eb9 373 }
374 elsif ( $meta->{'type'} eq 'primary_key' ) {
375 $is_pk = 1;
376 }
4422e22a 377
82968eb9 378 push @constraints, $meta if $meta->{'supertype'} eq 'constraint';
379 }
0efb6e1b 380
f2f71b8e 381 my @comments = ( @{ $item[1] }, @{ $item[5] } );
382
0a7fc605 383 $return = {
b3384294 384 supertype => 'field',
7eac5e12 385 name => $item{'field_name'},
386 data_type => $item{'data_type'}{'type'},
387 size => $item{'data_type'}{'size'},
00ef67ea 388 is_nullable => $is_nullable,
7eac5e12 389 default => $default->{'value'},
390 constraints => [ @constraints ],
391 comments => [ @comments ],
392 is_primary_key => $is_pk || 0,
393 is_auto_increment => $item{'data_type'}{'is_auto_increment'},
4422e22a 394 }
395 }
396 | <error>
397
a82fa2cb 398field_comment : /^\s*(?:#|-{2})(.*)\n/
399 {
400 my $comment = $item[1];
401 $comment =~ s/^\s*(#|-*)\s*//;
402 $comment =~ s/\s*$//;
403 $return = $comment;
404 }
405
0efb6e1b 406field_meta : default_val
82968eb9 407 | column_constraint
4422e22a 408
0efb6e1b 409column_constraint : constraint_name(?) column_constraint_type deferrable(?) deferred(?)
410 {
411 my $desc = $item{'column_constraint_type'};
412 my $type = $desc->{'type'};
413 my $fields = $desc->{'fields'} || [];
414 my $expression = $desc->{'expression'} || '';
415
416 $return = {
82968eb9 417 supertype => 'constraint',
0efb6e1b 418 name => $item{'constraint_name'}[0] || '',
419 type => $type,
420 expression => $type eq 'check' ? $expression : '',
f04713db 421 deferrable => $item{'deferrable'},
0efb6e1b 422 deferred => $item{'deferred'},
423 reference_table => $desc->{'reference_table'},
424 reference_fields => $desc->{'reference_fields'},
425 match_type => $desc->{'match_type'},
100684f3 426 on_delete => $desc->{'on_delete'} || $desc->{'on_delete_do'},
427 on_update => $desc->{'on_update'} || $desc->{'on_update_do'},
4422e22a 428 }
429 }
430
0efb6e1b 431constraint_name : /constraint/i name_with_opt_quotes { $item[2] }
432
433column_constraint_type : /not null/i { $return = { type => 'not_null' } }
434 |
f04713db 435 /null/i
0efb6e1b 436 { $return = { type => 'null' } }
437 |
f04713db 438 /unique/i
0efb6e1b 439 { $return = { type => 'unique' } }
440 |
441 /primary key/i
442 { $return = { type => 'primary_key' } }
443 |
444 /check/i '(' /[^)]+/ ')'
b3384294 445 { $return = { type => 'check', expression => $item[3] } }
0efb6e1b 446 |
3022f45b 447 /references/i table_name parens_word_list(?) match_type(?) key_action(s?)
0efb6e1b 448 {
a20abbda 449 my $table_info = $item{'table_name'};
450 my $schema_name = $table_info->{'schema_name'};
451 my $table_name = $table_info->{'table_name'};
3022f45b 452 my ( $on_delete, $on_update );
453 for my $action ( @{ $item[5] || [] } ) {
454 $on_delete = $action->{'action'} if $action->{'type'} eq 'delete';
455 $on_update = $action->{'action'} if $action->{'type'} eq 'update';
456 }
457
0efb6e1b 458 $return = {
459 type => 'foreign_key',
a20abbda 460 reference_table => $table_name,
0138f7bb 461 reference_fields => $item[3][0],
0efb6e1b 462 match_type => $item[4][0],
100684f3 463 on_delete => $on_delete,
464 on_update => $on_update,
ba1a1626 465 }
4422e22a 466 }
467
a20abbda 468table_name : schema_qualification(?) name_with_opt_quotes {
469 $return = { schema_name => $item[1], table_name => $item[2] }
470}
471
472 schema_qualification : name_with_opt_quotes '.'
4422e22a 473
cc74bccc 474schema_name : name_with_opt_quotes
475
0efb6e1b 476field_name : name_with_opt_quotes
4422e22a 477
0012a163 478name_with_opt_quotes : double_quote(?) NAME double_quote(?) { $item[2] }
4422e22a 479
0efb6e1b 480double_quote: /"/
4422e22a 481
0efb6e1b 482index_name : WORD
4422e22a 483
0efb6e1b 484data_type : pg_data_type parens_value_list(?)
4422e22a 485 {
3022f45b 486 my $data_type = $item[1];
ba1a1626 487
0efb6e1b 488 #
489 # We can deduce some sizes from the data type's name.
490 #
44ffdb73 491 if ( my $size = $item[2][0] ) {
492 $data_type->{'size'} = $size;
493 }
4422e22a 494
3022f45b 495 $return = $data_type;
4422e22a 496 }
497
0efb6e1b 498pg_data_type :
50840472 499 /(bigint|int8)/i
3022f45b 500 {
501 $return = {
50840472 502 type => 'integer',
b8ea6076 503 size => 20,
3022f45b 504 };
505 }
0efb6e1b 506 |
1bbd4a2b 507 /(smallint|int2)/i
3022f45b 508 {
509 $return = {
510 type => 'integer',
b8ea6076 511 size => 5,
3022f45b 512 };
513 }
0efb6e1b 514 |
c4c363bb 515 /interval/i
516 {
517 $return = { type => 'interval' };
518 }
519 |
50840472 520 /(integer|int4?)/i # interval must come before this
3022f45b 521 {
522 $return = {
523 type => 'integer',
b8ea6076 524 size => 10,
3022f45b 525 };
526 }
50840472 527 |
528 /(real|float4)/i
529 {
530 $return = {
531 type => 'real',
b8ea6076 532 size => 10,
50840472 533 };
534 }
0efb6e1b 535 |
1bbd4a2b 536 /(double precision|float8?)/i
3022f45b 537 {
538 $return = {
539 type => 'float',
b8ea6076 540 size => 20,
3022f45b 541 };
542 }
0efb6e1b 543 |
50840472 544 /(bigserial|serial8)/i
3022f45b 545 {
50840472 546 $return = {
7eac5e12 547 type => 'integer',
b8ea6076 548 size => 20,
7eac5e12 549 is_auto_increment => 1,
3022f45b 550 };
551 }
0efb6e1b 552 |
1bbd4a2b 553 /serial4?/i
3022f45b 554 {
555 $return = {
7eac5e12 556 type => 'integer',
b8ea6076 557 size => 11,
7eac5e12 558 is_auto_increment => 1,
3022f45b 559 };
560 }
0efb6e1b 561 |
1bbd4a2b 562 /(bit varying|varbit)/i
3022f45b 563 {
564 $return = { type => 'varbit' };
565 }
0efb6e1b 566 |
1bbd4a2b 567 /character varying/i
3022f45b 568 {
569 $return = { type => 'varchar' };
570 }
0efb6e1b 571 |
1bbd4a2b 572 /char(acter)?/i
3022f45b 573 {
574 $return = { type => 'char' };
575 }
0efb6e1b 576 |
1bbd4a2b 577 /bool(ean)?/i
3022f45b 578 {
579 $return = { type => 'boolean' };
580 }
0efb6e1b 581 |
1bbd4a2b 582 /bytea/i
3022f45b 583 {
82968eb9 584 $return = { type => 'bytea' };
3022f45b 585 }
0efb6e1b 586 |
b0f2faf8 587 /(timestamptz|timestamp)(?:\(\d\))?( with(out)? time zone)?/i
3022f45b 588 {
589 $return = { type => 'timestamp' };
590 }
0efb6e1b 591 |
38a6a4f9 592 /text/i
593 {
594 $return = {
595 type => 'text',
596 size => 64_000,
597 };
598 }
599 |
c4c363bb 600 /(bit|box|cidr|circle|date|inet|line|lseg|macaddr|money|numeric|decimal|path|point|polygon|timetz|time|varchar)/i
3022f45b 601 {
602 $return = { type => $item[1] };
603 }
0efb6e1b 604
4422e22a 605parens_value_list : '(' VALUE(s /,/) ')'
606 { $item[2] }
607
0efb6e1b 608parens_word_list : '(' WORD(s /,/) ')'
609 { $item[2] }
4422e22a 610
0efb6e1b 611field_size : '(' num_range ')' { $item{'num_range'} }
4422e22a 612
0efb6e1b 613num_range : DIGITS ',' DIGITS
4422e22a 614 { $return = $item[1].','.$item[3] }
615 | DIGITS
616 { $return = $item[1] }
617
f2f71b8e 618table_constraint : comment(s?) constraint_name(?) table_constraint_type deferrable(?) deferred(?) comment(s?)
0efb6e1b 619 {
620 my $desc = $item{'table_constraint_type'};
621 my $type = $desc->{'type'};
622 my $fields = $desc->{'fields'};
623 my $expression = $desc->{'expression'};
f2f71b8e 624 my @comments = ( @{ $item[1] }, @{ $item[-1] } );
0efb6e1b 625
626 $return = {
627 name => $item{'constraint_name'}[0] || '',
b3384294 628 supertype => 'constraint',
629 type => $type,
0efb6e1b 630 fields => $type ne 'check' ? $fields : [],
631 expression => $type eq 'check' ? $expression : '',
f04713db 632 deferrable => $item{'deferrable'},
0efb6e1b 633 deferred => $item{'deferred'},
634 reference_table => $desc->{'reference_table'},
635 reference_fields => $desc->{'reference_fields'},
636 match_type => $desc->{'match_type'}[0],
100684f3 637 on_delete => $desc->{'on_delete'} || $desc->{'on_delete_do'},
638 on_update => $desc->{'on_update'} || $desc->{'on_update_do'},
f2f71b8e 639 comments => [ @comments ],
0efb6e1b 640 }
641 }
4422e22a 642
0efb6e1b 643table_constraint_type : /primary key/i '(' name_with_opt_quotes(s /,/) ')'
644 {
645 $return = {
646 type => 'primary_key',
647 fields => $item[3],
648 }
649 }
650 |
651 /unique/i '(' name_with_opt_quotes(s /,/) ')'
652 {
653 $return = {
654 type => 'unique',
655 fields => $item[3],
656 }
657 }
658 |
b3384294 659 /check/i '(' /[^)]+/ ')'
0efb6e1b 660 {
661 $return = {
662 type => 'check',
663 expression => $item[3],
664 }
665 }
666 |
3022f45b 667 /foreign key/i '(' name_with_opt_quotes(s /,/) ')' /references/i table_name parens_word_list(?) match_type(?) key_action(s?)
0efb6e1b 668 {
3022f45b 669 my ( $on_delete, $on_update );
670 for my $action ( @{ $item[9] || [] } ) {
671 $on_delete = $action->{'action'} if $action->{'type'} eq 'delete';
672 $on_update = $action->{'action'} if $action->{'type'} eq 'update';
673 }
674
0efb6e1b 675 $return = {
b3384294 676 supertype => 'constraint',
0efb6e1b 677 type => 'foreign_key',
678 fields => $item[3],
a20abbda 679 reference_table => $item[6]->{'table_name'},
0efb6e1b 680 reference_fields => $item[7][0],
681 match_type => $item[8][0],
100684f3 682 on_delete => $on_delete || '',
683 on_update => $on_update || '',
0efb6e1b 684 }
685 }
686
99f3fab6 687deferrable : not(?) /deferrable/i
0efb6e1b 688 {
689 $return = ( $item[1] =~ /not/i ) ? 0 : 1;
690 }
4422e22a 691
0efb6e1b 692deferred : /initially/i /(deferred|immediate)/i { $item[2] }
4422e22a 693
0efb6e1b 694match_type : /match full/i { 'match_full' }
695 |
696 /match partial/i { 'match_partial' }
697
3022f45b 698key_action : key_delete
699 |
700 key_update
0efb6e1b 701
3022f45b 702key_delete : /on delete/i key_mutation
703 {
8c12c406 704 $return = {
3022f45b 705 type => 'delete',
706 action => $item[2],
707 };
708 }
709
710key_update : /on update/i key_mutation
711 {
8c12c406 712 $return = {
3022f45b 713 type => 'update',
714 action => $item[2],
715 };
716 }
717
718key_mutation : /no action/i { $return = 'no_action' }
719 |
720 /restrict/i { $return = 'restrict' }
721 |
722 /cascade/i { $return = 'cascade' }
723 |
38a6a4f9 724 /set null/i { $return = 'set null' }
3022f45b 725 |
38a6a4f9 726 /set default/i { $return = 'set default' }
0efb6e1b 727
00ef67ea 728alter : alter_table table_name add_column field ';'
729 {
730 my $field_def = $item[4];
a20abbda 731 $tables{ $item[2]->{'table_name'} }{'fields'}{ $field_def->{'name'} } = {
00ef67ea 732 %$field_def, order => $field_order++
733 };
734 1;
735 }
736
737alter : alter_table table_name ADD table_constraint ';'
0012a163 738 {
a20abbda 739 my $table_name = $item[2]->{'table_name'};
0012a163 740 my $constraint = $item[4];
0012a163 741 push @{ $tables{ $table_name }{'constraints'} }, $constraint;
00ef67ea 742 1;
0012a163 743 }
744
00ef67ea 745alter : alter_table table_name drop_column NAME restrict_or_cascade(?) ';'
746 {
a20abbda 747 $tables{ $item[2]->{'table_name'} }{'fields'}{ $item[4] }{'drop'} = 1;
00ef67ea 748 1;
749 }
0012a163 750
00ef67ea 751alter : alter_table table_name alter_column NAME alter_default_val ';'
752 {
a20abbda 753 $tables{ $item[2]->{'table_name'} }{'fields'}{ $item[4] }{'default'} =
00ef67ea 754 $item[5]->{'value'};
755 1;
756 }
757
758#
759# These will just parse for now but won't affect the structure. - ky
760#
761alter : alter_table table_name /rename/i /to/i NAME ';'
762 { 1 }
763
764alter : alter_table table_name alter_column NAME SET /statistics/i INTEGER ';'
765 { 1 }
766
767alter : alter_table table_name alter_column NAME SET /storage/i storage_type ';'
768 { 1 }
769
770alter : alter_table table_name rename_column NAME /to/i NAME ';'
771 { 1 }
772
773alter : alter_table table_name DROP /constraint/i NAME restrict_or_cascade ';'
774 { 1 }
775
776alter : alter_table table_name /owner/i /to/i NAME ';'
777 { 1 }
778
cc74bccc 779alter : alter_sequence NAME /owned/i /by/i column_name ';'
780 { 1 }
781
00ef67ea 782storage_type : /(plain|external|extended|main)/i
783
784alter_default_val : SET default_val
785 {
786 $return = { value => $item[2]->{'value'} }
787 }
788 | DROP DEFAULT
789 {
790 $return = { value => undef }
791 }
792
793#
794# This is a little tricky to get right, at least WRT to making the
795# tests pass. The problem is that the constraints are stored just as
796# a list (no name access), and the tests expect the constraints in a
797# particular order. I'm going to leave the rule but disable the code
798# for now. - ky
799#
800alter : alter_table table_name alter_column NAME alter_nullable ';'
801 {
a20abbda 802# my $table_name = $item[2]->{'table_name'};
00ef67ea 803# my $field_name = $item[4];
804# my $is_nullable = $item[5]->{'is_nullable'};
805#
806# $tables{ $table_name }{'fields'}{ $field_name }{'is_nullable'} =
807# $is_nullable;
808#
809# if ( $is_nullable ) {
810# 1;
811# push @{ $tables{ $table_name }{'constraints'} }, {
812# type => 'not_null',
813# fields => [ $field_name ],
814# };
815# }
816# else {
817# for my $i (
818# 0 .. $#{ $tables{ $table_name }{'constraints'} || [] }
819# ) {
820# my $c = $tables{ $table_name }{'constraints'}[ $i ] or next;
821# my $fields = join( '', @{ $c->{'fields'} || [] } ) or next;
822# if ( $c->{'type'} eq 'not_null' && $fields eq $field_name ) {
823# delete $tables{ $table_name }{'constraints'}[ $i ];
824# last;
825# }
826# }
827# }
828
829 1;
830 }
831
832alter_nullable : SET not_null
833 {
834 $return = { is_nullable => 0 }
835 }
836 | DROP not_null
837 {
838 $return = { is_nullable => 1 }
839 }
840
841not_null : /not/i /null/i
842
99f3fab6 843not : /not/i
844
00ef67ea 845add_column : ADD COLUMN(?)
846
847alter_table : ALTER TABLE ONLY(?)
848
cc74bccc 849alter_sequence : ALTER SEQUENCE
850
00ef67ea 851drop_column : DROP COLUMN(?)
852
853alter_column : ALTER COLUMN(?)
854
855rename_column : /rename/i COLUMN(?)
856
857restrict_or_cascade : /restrict/i |
858 /cascade/i
859
cc74bccc 860# Handle functions that can be called
861select : SELECT select_function ';'
862 { 1 }
863
864# Read the setval function but don't do anything with it because this parser
865# isn't handling sequences
866select_function : schema_qualification(?) /setval/i '(' VALUE /,/ VALUE /,/ /(true|false)/i ')'
867 { 1 }
868
869# Skipping all COPY commands
870copy : COPY WORD /[^;]+/ ';' { 1 }
871 { 1 }
872
873# The "\." allows reading in from STDIN but this isn't needed for schema
874# creation, so it is skipped.
875readin_symbol : '\.'
876 {1}
877
00ef67ea 878#
879# End basically useless stuff. - ky
880#
0012a163 881
211e2e90 882create_table : CREATE TABLE
0efb6e1b 883
211e2e90 884create_index : CREATE /index/i
4422e22a 885
00ef67ea 886default_val : DEFAULT /(\d+|'[^']*'|\w+\(.*?\))|\w+/
4422e22a 887 {
f04713db 888 my $val = defined $item[2] ? $item[2] : '';
889 $val =~ s/^'|'$//g;
0efb6e1b 890 $return = {
82968eb9 891 supertype => 'constraint',
892 type => 'default',
0efb6e1b 893 value => $val,
894 }
4422e22a 895 }
f27085c9 896 | /null/i
897 {
898 $return = {
899 supertype => 'constraint',
900 type => 'default',
901 value => 'NULL',
902 }
903 }
4422e22a 904
4422e22a 905name_with_opt_paren : NAME parens_value_list(s?)
0efb6e1b 906 { $item[2][0] ? "$item[1]($item[2][0][0])" : $item[1] }
4422e22a 907
908unique : /unique/i { 1 }
909
910key : /key/i | /index/i
911
0efb6e1b 912table_option : /inherits/i '(' name_with_opt_quotes(s /,/) ')'
4422e22a 913 {
0efb6e1b 914 $return = { type => 'inherits', table_name => $item[3] }
915 }
916 |
917 /with(out)? oids/i
918 {
919 $return = { type => $item[1] =~ /out/i ? 'without_oids' : 'with_oids' }
4422e22a 920 }
921
00ef67ea 922ADD : /add/i
923
924ALTER : /alter/i
925
211e2e90 926CREATE : /create/i
927
00ef67ea 928ONLY : /only/i
929
930DEFAULT : /default/i
931
932DROP : /drop/i
933
934COLUMN : /column/i
935
0d51cd9e 936TABLE : /table/i
937
cc74bccc 938SCHEMA : /schema/i
939
0efb6e1b 940SEMICOLON : /\s*;\n?/
941
cc74bccc 942SEQUENCE : /sequence/i
943
944SELECT : /select/i
945
946COPY : /copy/i
947
00ef67ea 948INTEGER : /\d+/
949
4422e22a 950WORD : /\w+/
951
952DIGITS : /\d+/
953
954COMMA : ','
955
00ef67ea 956SET : /set/i
957
4422e22a 958NAME : "`" /\w+/ "`"
959 { $item[2] }
960 | /\w+/
961 { $item[1] }
0012a163 962 | /[\$\w]+/
963 { $item[1] }
4422e22a 964
965VALUE : /[-+]?\.?\d+(?:[eE]\d+)?/
966 { $item[1] }
967 | /'.*?'/ # XXX doesn't handle embedded quotes
968 { $item[1] }
f04713db 969 | /null/i
4422e22a 970 { 'NULL' }
971
972!;
973
974# -------------------------------------------------------------------
975sub parse {
976 my ( $translator, $data ) = @_;
977 $parser ||= Parse::RecDescent->new($GRAMMAR);
978
979 $::RD_TRACE = $translator->trace ? 1 : undef;
980 $DEBUG = $translator->debug;
981
982 unless (defined $parser) {
983 return $translator->error("Error instantiating Parse::RecDescent ".
984 "instance: Bad grammer");
985 }
986
987 my $result = $parser->startrule($data);
988 die "Parse failed.\n" unless defined $result;
989 warn Dumper($result) if $DEBUG;
82968eb9 990
991 my $schema = $translator->schema;
992 my @tables = sort {
429f639c 993 ( $result->{ $a }{'order'} || 0 ) <=> ( $result->{ $b }{'order'} || 0 )
82968eb9 994 } keys %{ $result };
995
996 for my $table_name ( @tables ) {
997 my $tdata = $result->{ $table_name };
998 my $table = $schema->add_table(
a20abbda 999 #schema => $tdata->{'schema_name'},
1000 name => $tdata->{'table_name'},
d7fcc1d6 1001 ) or die "Couldn't create table '$table_name': " . $schema->error;
82968eb9 1002
a82fa2cb 1003 $table->comments( $tdata->{'comments'} );
1004
82968eb9 1005 my @fields = sort {
429f639c 1006 $tdata->{'fields'}{ $a }{'order'}
82968eb9 1007 <=>
429f639c 1008 $tdata->{'fields'}{ $b }{'order'}
82968eb9 1009 } keys %{ $tdata->{'fields'} };
1010
1011 for my $fname ( @fields ) {
1012 my $fdata = $tdata->{'fields'}{ $fname };
00ef67ea 1013 next if $fdata->{'drop'};
82968eb9 1014 my $field = $table->add_field(
1015 name => $fdata->{'name'},
1016 data_type => $fdata->{'data_type'},
1017 size => $fdata->{'size'},
1018 default_value => $fdata->{'default'},
7eac5e12 1019 is_auto_increment => $fdata->{'is_auto_increment'},
00ef67ea 1020 is_nullable => $fdata->{'is_nullable'},
a82fa2cb 1021 comments => $fdata->{'comments'},
82968eb9 1022 ) or die $table->error;
1023
1024 $table->primary_key( $field->name ) if $fdata->{'is_primary_key'};
1025
1026 for my $cdata ( @{ $fdata->{'constraints'} } ) {
1027 next unless $cdata->{'type'} eq 'foreign_key';
1028 $cdata->{'fields'} ||= [ $field->name ];
1029 push @{ $tdata->{'constraints'} }, $cdata;
1030 }
1031 }
1032
1033 for my $idata ( @{ $tdata->{'indices'} || [] } ) {
1034 my $index = $table->add_index(
1035 name => $idata->{'name'},
1036 type => uc $idata->{'type'},
1037 fields => $idata->{'fields'},
1038 ) or die $table->error;
1039 }
1040
1041 for my $cdata ( @{ $tdata->{'constraints'} || [] } ) {
1042 my $constraint = $table->add_constraint(
1043 name => $cdata->{'name'},
1044 type => $cdata->{'type'},
1045 fields => $cdata->{'fields'},
1046 reference_table => $cdata->{'reference_table'},
1047 reference_fields => $cdata->{'reference_fields'},
1048 match_type => $cdata->{'match_type'} || '',
100684f3 1049 on_delete => $cdata->{'on_delete'} || $cdata->{'on_delete_do'},
1050 on_update => $cdata->{'on_update'} || $cdata->{'on_update_do'},
b3384294 1051 expression => $cdata->{'expression'},
1052 ) or die "Can't add constraint of type '" .
1053 $cdata->{'type'} . "' to table '" . $table->name .
1054 "': " . $table->error;
82968eb9 1055 }
1056 }
1057
f62bd16c 1058 return 1;
4422e22a 1059}
1060
10611;
1062
82968eb9 1063# -------------------------------------------------------------------
1064# Rescue the drowning and tie your shoestrings.
1065# Henry David Thoreau
1066# -------------------------------------------------------------------
4422e22a 1067
1068=pod
1069
0efb6e1b 1070=head1 AUTHORS
4422e22a 1071
1072Ken Y. Clark E<lt>kclark@cpan.orgE<gt>,
b8ea6076 1073Allen Day E<lt>allenday@ucla.eduE<gt>.
4422e22a 1074
1075=head1 SEE ALSO
1076
1077perl(1), Parse::RecDescent.
1078
1079=cut