Pg views and sqlite views, patch from wreis
[dbsrgits/SQL-Translator.git] / lib / SQL / Translator / Producer / SQLite.pm
CommitLineData
758ab1cd 1package SQL::Translator::Producer::SQLite;
2
3# -------------------------------------------------------------------
8619aed2 4# $Id: SQLite.pm,v 1.15 2006-08-26 11:35:31 schiffbruechige Exp $
758ab1cd 5# -------------------------------------------------------------------
977651a5 6# Copyright (C) 2002-4 SQLFairy Authors
758ab1cd 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
20770e44 23=head1 NAME
24
25SQL::Translator::Producer::SQLite - SQLite producer for SQL::Translator
26
27=head1 SYNOPSIS
28
29 use SQL::Translator;
30
31 my $t = SQL::Translator->new( parser => '...', producer => 'SQLite' );
32 $t->translate;
33
34=head1 DESCRIPTION
35
36This module will produce text output of the schema suitable for SQLite.
37
38=cut
39
758ab1cd 40use strict;
41use Data::Dumper;
b21bf652 42use SQL::Translator::Schema::Constants;
5ee19df8 43use SQL::Translator::Utils qw(debug header_comment);
758ab1cd 44
45use vars qw[ $VERSION $DEBUG $WARN ];
5ee19df8 46
8619aed2 47$VERSION = sprintf "%d.%02d", q$Revision: 1.15 $ =~ /(\d+)\.(\d+)/;
5ee19df8 48$DEBUG = 0 unless defined $DEBUG;
49$WARN = 0 unless defined $WARN;
758ab1cd 50
51my %used_identifiers = ();
52my $max_id_length = 30;
53my %global_names;
54my %truncated;
55
758ab1cd 56sub produce {
a1d94525 57 my $translator = shift;
58 local $DEBUG = $translator->debug;
59 local $WARN = $translator->show_warnings;
60 my $no_comments = $translator->no_comments;
61 my $add_drop_table = $translator->add_drop_table;
62 my $schema = $translator->schema;
758ab1cd 63
1a24938d 64 debug("PKG: Beginning production\n");
758ab1cd 65
a5a882f0 66 my $create = '';
5ee19df8 67 $create .= header_comment unless ($no_comments);
a5a882f0 68 $create .= "BEGIN TRANSACTION;\n\n";
758ab1cd 69
bfb5a568 70 my @table_defs = ();
b21bf652 71 for my $table ( $schema->get_tables ) {
4d438549 72 my @defs = create_table($table, { no_comments => $no_comments,
73 add_drop_table => $add_drop_table,});
74 my $create = shift @defs;
75 $create .= ";\n";
76 push @table_defs, $create, map( { "$_;" } @defs), "";
a5a882f0 77 }
78
ec59a597 79 for my $view ( $schema->get_views ) {
a25ac5d2 80 push @table_defs, create_view($view, {
81 add_drop_view => $add_drop_table,
82 no_comments => $no_comments,
83 });
ec59a597 84 }
85
bfb5a568 86# $create .= "COMMIT;\n";
a5a882f0 87
bfb5a568 88 return wantarray ? ($create, @table_defs, "COMMIT;\n") : join("\n", ($create, @table_defs, "COMMIT;\n"));
758ab1cd 89}
90
758ab1cd 91# -------------------------------------------------------------------
92sub mk_name {
93 my ($basename, $type, $scope, $critical) = @_;
94 my $basename_orig = $basename;
95 my $max_name = $type
96 ? $max_id_length - (length($type) + 1)
97 : $max_id_length;
98 $basename = substr( $basename, 0, $max_name )
99 if length( $basename ) > $max_name;
cc74bccc 100 $basename =~ s/\./_/g;
758ab1cd 101 my $name = $type ? "${type}_$basename" : $basename;
102
103 if ( $basename ne $basename_orig and $critical ) {
104 my $show_type = $type ? "+'$type'" : "";
105 warn "Truncating '$basename_orig'$show_type to $max_id_length ",
106 "character limit to make '$name'\n" if $WARN;
107 $truncated{ $basename_orig } = $name;
108 }
109
110 $scope ||= \%global_names;
111 if ( my $prev = $scope->{ $name } ) {
112 my $name_orig = $name;
113 $name .= sprintf( "%02d", ++$prev );
114 substr($name, $max_id_length - 3) = "00"
115 if length( $name ) > $max_id_length;
116
117 warn "The name '$name_orig' has been changed to ",
118 "'$name' to make it unique.\n" if $WARN;
119
120 $scope->{ $name_orig }++;
121 }
122
123 $scope->{ $name }++;
124 return $name;
125}
126
ec59a597 127sub create_view {
128 my ($view, $options) = @_;
a25ac5d2 129 my $add_drop_view = $options->{add_drop_view};
ec59a597 130
131 my $view_name = $view->name;
132 debug("PKG: Looking at view '${view_name}'\n");
133
134 # Header. Should this look like what mysqldump produces?
135 my $extra = $view->extra;
136 my $create = '';
137 $create .= "--\n-- View: ${view_name}\n--\n" unless $options->{no_comments};
a25ac5d2 138 $create .= "DROP VIEW IF EXISTS $view_name;\n" if $add_drop_view;
ec59a597 139 $create .= 'CREATE';
140 $create .= " TEMPORARY" if exists($extra->{temporary}) && $extra->{temporary};
141 $create .= ' VIEW';
142 $create .= " IF NOT EXISTS" if exists($extra->{if_not_exists}) && $extra->{if_not_exists};
143 $create .= " ${view_name}";
144
145 if( my $sql = $view->sql ){
a25ac5d2 146 $create .= " AS\n ${sql}";
ec59a597 147 }
148 $create .= ";\n\n";
149 return $create;
150}
151
152
bfb5a568 153sub create_table
154{
155 my ($table, $options) = @_;
758ab1cd 156
bfb5a568 157 my $table_name = $table->name;
158 my $no_comments = $options->{no_comments};
159 my $add_drop_table = $options->{add_drop_table};
160
161 debug("PKG: Looking at table '$table_name'\n");
162
163 my ( @index_defs, @constraint_defs, @trigger_defs );
164 my @fields = $table->get_fields or die "No fields in $table_name";
165
4d438549 166 my $temp = $options->{temporary_table} ? 'TEMPORARY ' : '';
bfb5a568 167 #
168 # Header.
169 #
170 my $create = '';
171 $create .= "--\n-- Table: $table_name\n--\n" unless $no_comments;
172 $create .= qq[DROP TABLE $table_name;\n] if $add_drop_table;
4d438549 173 $create .= "CREATE ${temp}TABLE $table_name (\n";
bfb5a568 174
175 #
176 # Comments
177 #
178 if ( $table->comments and !$no_comments ){
179 $create .= "-- Comments: \n-- ";
180 $create .= join "\n-- ", $table->comments;
181 $create .= "\n--\n\n";
182 }
183
184 #
185 # How many fields in PK?
186 #
187 my $pk = $table->primary_key;
188 my @pk_fields = $pk ? $pk->fields : ();
189
190 #
191 # Fields
192 #
193 my ( @field_defs, $pk_set );
194 for my $field ( @fields ) {
195 push @field_defs, create_field($field);
196 }
197
198 if (
199 scalar @pk_fields > 1
200 ||
201 ( @pk_fields && !grep /INTEGER PRIMARY KEY/, @field_defs )
202 ) {
203 push @field_defs, 'PRIMARY KEY (' . join(', ', @pk_fields ) . ')';
204 }
205
206 #
207 # Indices
208 #
209 my $idx_name_default = 'A';
210 for my $index ( $table->get_indices ) {
211 push @index_defs, create_index($index);
212 }
213
214 #
215 # Constraints
216 #
217 my $c_name_default = 'A';
218 for my $c ( $table->get_constraints ) {
219 next unless $c->type eq UNIQUE;
220 push @constraint_defs, create_constraint($c);
221 }
222
4d438549 223 $create .= join(",\n", map { " $_" } @field_defs ) . "\n)";
bfb5a568 224
4d438549 225 return ($create, @index_defs, @constraint_defs, @trigger_defs );
bfb5a568 226}
227
228sub create_field
229{
230 my ($field, $options) = @_;
231
232 my $field_name = $field->name;
233 debug("PKG: Looking at field '$field_name'\n");
234 my $field_comments = $field->comments
235 ? "-- " . $field->comments . "\n "
236 : '';
237
238 my $field_def = $field_comments.$field_name;
239
240 # data type and size
241 my $size = $field->size;
242 my $data_type = $field->data_type;
243 $data_type = 'varchar' if lc $data_type eq 'set';
244 $data_type = 'blob' if lc $data_type eq 'bytea';
245
246 if ( lc $data_type =~ /(text|blob)/i ) {
247 $size = undef;
248 }
249
250# if ( $data_type =~ /timestamp/i ) {
251# push @trigger_defs,
252# "CREATE TRIGGER ts_${table_name} ".
253# "after insert on $table_name\n".
254# "begin\n".
255# " update $table_name set $field_name=timestamp() ".
256# "where id=new.id;\n".
257# "end;\n"
258# ;
259#
260# }
261
262 #
263 # SQLite is generally typeless, but newer versions will
264 # make a field autoincrement if it is declared as (and
265 # *only* as) INTEGER PRIMARY KEY
266 #
267 my $pk = $field->table->primary_key;
268 my @pk_fields = $pk ? $pk->fields : ();
269
270 if (
271 $field->is_primary_key &&
272 scalar @pk_fields == 1 &&
273 (
274 $data_type =~ /int(eger)?$/i
275 ||
276 ( $data_type =~ /^number?$/i && $size !~ /,/ )
277 )
278 ) {
279 $data_type = 'INTEGER PRIMARY KEY';
280 $size = undef;
281# $pk_set = 1;
282 }
283
284 $field_def .= sprintf " %s%s", $data_type,
285 ( !$field->is_auto_increment && $size ) ? "($size)" : '';
286
287 # Null?
288 $field_def .= ' NOT NULL' unless $field->is_nullable;
289
290 # Default? XXX Need better quoting!
291 my $default = $field->default_value;
292 if ( defined $default ) {
293 if ( uc $default eq 'NULL') {
294 $field_def .= ' DEFAULT NULL';
295 } elsif ( $default eq 'now()' ||
296 $default eq 'CURRENT_TIMESTAMP' ) {
297 $field_def .= ' DEFAULT CURRENT_TIMESTAMP';
298 } elsif ( $default =~ /val\(/ ) {
299 next;
300 } else {
301 $field_def .= " DEFAULT '$default'";
302 }
303 }
304
305 return $field_def;
306
307}
308
309sub create_index
310{
311 my ($index, $options) = @_;
312
313 my $name = $index->name;
4d438549 314 $name = mk_name($index->table->name, $name);
315
316 my $type = $index->type eq 'UNIQUE' ? "UNIQUE " : '';
bfb5a568 317
318 # strip any field size qualifiers as SQLite doesn't like these
319 my @fields = map { s/\(\d+\)$//; $_ } $index->fields;
cc74bccc 320 (my $index_table_name = $index->table->name) =~ s/^.+?\.//; # table name may not specify schema
321 warn "removing schema name from '" . $index->table->name . "' to make '$index_table_name'\n" if $WARN;
bfb5a568 322 my $index_def =
907f8cea 323 "CREATE ${type}INDEX $name ON " . $index_table_name .
324 ' (' . join( ', ', @fields ) . ')';
bfb5a568 325
326 return $index_def;
327}
328
329sub create_constraint
330{
331 my ($c, $options) = @_;
332
333 my $name = $c->name;
4d438549 334 $name = mk_name($c->table->name, $name);
bfb5a568 335 my @fields = $c->fields;
cc74bccc 336 (my $index_table_name = $c->table->name) =~ s/^.+?\.//; # table name may not specify schema
337 warn "removing schema name from '" . $c->table->name . "' to make '$index_table_name'\n" if $WARN;
bfb5a568 338
339 my $c_def =
907f8cea 340 "CREATE UNIQUE INDEX $name ON " . $index_table_name .
341 ' (' . join( ', ', @fields ) . ')';
bfb5a568 342
343 return $c_def;
344}
345
4d438549 346sub alter_table { } # Noop
347
348sub add_field {
349 my ($field) = @_;
350
351 return sprintf("ALTER TABLE %s ADD COLUMN %s",
352 $field->table->name, create_field($field))
353}
354
355sub alter_create_index {
356 my ($index) = @_;
357
358 # This might cause name collisions
359 return create_index($index);
360}
361
362sub alter_create_constraint {
363 my ($constraint) = @_;
364
365 return create_constraint($constraint) if $constraint->type eq 'UNIQUE';
366}
367
368sub alter_drop_constraint { alter_drop_index(@_) }
369
370sub alter_drop_index {
371 my ($constraint) = @_;
372
ecf7f25d 373 return sprintf("DROP INDEX %s",
374 $constraint->name);
4d438549 375}
376
377sub batch_alter_table {
378 my ($table, $diffs) = @_;
379
4d438549 380 # If we have any of the following
381 #
382 # rename_field
383 # alter_field
384 # drop_field
385 #
386 # we need to do the following <http://www.sqlite.org/faq.html#q11>
387 #
388 # BEGIN TRANSACTION;
389 # CREATE TEMPORARY TABLE t1_backup(a,b);
390 # INSERT INTO t1_backup SELECT a,b FROM t1;
391 # DROP TABLE t1;
392 # CREATE TABLE t1(a,b);
393 # INSERT INTO t1 SELECT a,b FROM t1_backup;
394 # DROP TABLE t1_backup;
395 # COMMIT;
396 #
397 # Fun, eh?
46bf5655 398 #
399 # If we have rename_field we do similarly.
400
401 my $table_name = $table->name;
402 my $renaming = $diffs->{rename_table} && @{$diffs->{rename_table}};
4d438549 403
404 if ( @{$diffs->{rename_field}} == 0 &&
405 @{$diffs->{alter_field}} == 0 &&
46bf5655 406 @{$diffs->{drop_field}} == 0
407 ) {
4d438549 408 return join("\n", map {
409 my $meth = __PACKAGE__->can($_) or die __PACKAGE__ . " cant $_";
410 map { my $sql = $meth->(ref $_ eq 'ARRAY' ? @$_ : $_); $sql ? ("$sql;") : () } @{ $diffs->{$_} }
411
46bf5655 412 } grep { @{$diffs->{$_}} }
413 qw/rename_table
414 alter_drop_constraint
415 alter_drop_index
416 drop_field
417 add_field
418 alter_field
419 rename_field
420 alter_create_index
421 alter_create_constraint
422 alter_table/);
4d438549 423 }
424
425
426 my @sql;
46bf5655 427 my $old_table = $renaming ? $diffs->{rename_table}[0][0] : $table;
4d438549 428
429 do {
46bf5655 430 local $table->{name} = $table_name . '_temp_alter';
4d438549 431 # We only want the table - dont care about indexes on tmp table
432 my ($table_sql) = create_table($table, {no_comments => 1, temporary_table => 1});
433 push @sql,$table_sql;
434 };
435
46bf5655 436 push @sql, "INSERT INTO @{[$table_name]}_temp_alter SELECT @{[ join(', ', $old_table->get_fields)]} FROM @{[$old_table]}",
437 "DROP TABLE @{[$old_table]}",
4d438549 438 create_table($table, { no_comments => 1 }),
46bf5655 439 "INSERT INTO @{[$table_name]} SELECT @{[ join(', ', $old_table->get_fields)]} FROM @{[$table_name]}_temp_alter",
440 "DROP TABLE @{[$table_name]}_temp_alter";
4d438549 441
442 return join(";\n", @sql, "");
443}
444
445sub drop_table {
446 my ($table) = @_;
447 return "DROP TABLE $table;";
448}
449
46bf5655 450sub rename_table {
451 my ($old_table, $new_table, $options) = @_;
452
453 my $qt = $options->{quote_table_names} || '';
454
455 return "ALTER TABLE $qt$old_table$qt RENAME TO $qt$new_table$qt";
456
457}
458
934e1b39 459# No-op. Just here to signify that we are a new style parser.
460sub preproces_schema { }
461
bfb5a568 4621;
758ab1cd 463
20770e44 464=pod
465
466=head1 SEE ALSO
467
468SQL::Translator, http://www.sqlite.org/.
758ab1cd 469
470=head1 AUTHOR
471
4d438549 472Ken Y. Clark C<< <kclark@cpan.orgE> >>.
473
474Diff code added by Ash Berlin C<< <ash@cpan.org> >>.
20770e44 475
476=cut