Fix warning messages
[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
bfb5a568 79# $create .= "COMMIT;\n";
a5a882f0 80
bfb5a568 81 return wantarray ? ($create, @table_defs, "COMMIT;\n") : join("\n", ($create, @table_defs, "COMMIT;\n"));
758ab1cd 82}
83
758ab1cd 84# -------------------------------------------------------------------
85sub mk_name {
86 my ($basename, $type, $scope, $critical) = @_;
87 my $basename_orig = $basename;
88 my $max_name = $type
89 ? $max_id_length - (length($type) + 1)
90 : $max_id_length;
91 $basename = substr( $basename, 0, $max_name )
92 if length( $basename ) > $max_name;
cc74bccc 93 $basename =~ s/\./_/g;
758ab1cd 94 my $name = $type ? "${type}_$basename" : $basename;
95
96 if ( $basename ne $basename_orig and $critical ) {
97 my $show_type = $type ? "+'$type'" : "";
98 warn "Truncating '$basename_orig'$show_type to $max_id_length ",
99 "character limit to make '$name'\n" if $WARN;
100 $truncated{ $basename_orig } = $name;
101 }
102
103 $scope ||= \%global_names;
104 if ( my $prev = $scope->{ $name } ) {
105 my $name_orig = $name;
106 $name .= sprintf( "%02d", ++$prev );
107 substr($name, $max_id_length - 3) = "00"
108 if length( $name ) > $max_id_length;
109
110 warn "The name '$name_orig' has been changed to ",
111 "'$name' to make it unique.\n" if $WARN;
112
113 $scope->{ $name_orig }++;
114 }
115
116 $scope->{ $name }++;
117 return $name;
118}
119
bfb5a568 120sub create_table
121{
122 my ($table, $options) = @_;
758ab1cd 123
bfb5a568 124 my $table_name = $table->name;
125 my $no_comments = $options->{no_comments};
126 my $add_drop_table = $options->{add_drop_table};
127
128 debug("PKG: Looking at table '$table_name'\n");
129
130 my ( @index_defs, @constraint_defs, @trigger_defs );
131 my @fields = $table->get_fields or die "No fields in $table_name";
132
4d438549 133 my $temp = $options->{temporary_table} ? 'TEMPORARY ' : '';
bfb5a568 134 #
135 # Header.
136 #
137 my $create = '';
138 $create .= "--\n-- Table: $table_name\n--\n" unless $no_comments;
139 $create .= qq[DROP TABLE $table_name;\n] if $add_drop_table;
4d438549 140 $create .= "CREATE ${temp}TABLE $table_name (\n";
bfb5a568 141
142 #
143 # Comments
144 #
145 if ( $table->comments and !$no_comments ){
146 $create .= "-- Comments: \n-- ";
147 $create .= join "\n-- ", $table->comments;
148 $create .= "\n--\n\n";
149 }
150
151 #
152 # How many fields in PK?
153 #
154 my $pk = $table->primary_key;
155 my @pk_fields = $pk ? $pk->fields : ();
156
157 #
158 # Fields
159 #
160 my ( @field_defs, $pk_set );
161 for my $field ( @fields ) {
162 push @field_defs, create_field($field);
163 }
164
165 if (
166 scalar @pk_fields > 1
167 ||
168 ( @pk_fields && !grep /INTEGER PRIMARY KEY/, @field_defs )
169 ) {
170 push @field_defs, 'PRIMARY KEY (' . join(', ', @pk_fields ) . ')';
171 }
172
173 #
174 # Indices
175 #
176 my $idx_name_default = 'A';
177 for my $index ( $table->get_indices ) {
178 push @index_defs, create_index($index);
179 }
180
181 #
182 # Constraints
183 #
184 my $c_name_default = 'A';
185 for my $c ( $table->get_constraints ) {
186 next unless $c->type eq UNIQUE;
187 push @constraint_defs, create_constraint($c);
188 }
189
4d438549 190 $create .= join(",\n", map { " $_" } @field_defs ) . "\n)";
bfb5a568 191
4d438549 192 return ($create, @index_defs, @constraint_defs, @trigger_defs );
bfb5a568 193}
194
195sub create_field
196{
197 my ($field, $options) = @_;
198
199 my $field_name = $field->name;
200 debug("PKG: Looking at field '$field_name'\n");
201 my $field_comments = $field->comments
202 ? "-- " . $field->comments . "\n "
203 : '';
204
205 my $field_def = $field_comments.$field_name;
206
207 # data type and size
208 my $size = $field->size;
209 my $data_type = $field->data_type;
210 $data_type = 'varchar' if lc $data_type eq 'set';
211 $data_type = 'blob' if lc $data_type eq 'bytea';
212
213 if ( lc $data_type =~ /(text|blob)/i ) {
214 $size = undef;
215 }
216
217# if ( $data_type =~ /timestamp/i ) {
218# push @trigger_defs,
219# "CREATE TRIGGER ts_${table_name} ".
220# "after insert on $table_name\n".
221# "begin\n".
222# " update $table_name set $field_name=timestamp() ".
223# "where id=new.id;\n".
224# "end;\n"
225# ;
226#
227# }
228
229 #
230 # SQLite is generally typeless, but newer versions will
231 # make a field autoincrement if it is declared as (and
232 # *only* as) INTEGER PRIMARY KEY
233 #
234 my $pk = $field->table->primary_key;
235 my @pk_fields = $pk ? $pk->fields : ();
236
237 if (
238 $field->is_primary_key &&
239 scalar @pk_fields == 1 &&
240 (
241 $data_type =~ /int(eger)?$/i
242 ||
243 ( $data_type =~ /^number?$/i && $size !~ /,/ )
244 )
245 ) {
246 $data_type = 'INTEGER PRIMARY KEY';
247 $size = undef;
248# $pk_set = 1;
249 }
250
251 $field_def .= sprintf " %s%s", $data_type,
252 ( !$field->is_auto_increment && $size ) ? "($size)" : '';
253
254 # Null?
255 $field_def .= ' NOT NULL' unless $field->is_nullable;
256
257 # Default? XXX Need better quoting!
258 my $default = $field->default_value;
259 if ( defined $default ) {
260 if ( uc $default eq 'NULL') {
261 $field_def .= ' DEFAULT NULL';
262 } elsif ( $default eq 'now()' ||
263 $default eq 'CURRENT_TIMESTAMP' ) {
264 $field_def .= ' DEFAULT CURRENT_TIMESTAMP';
265 } elsif ( $default =~ /val\(/ ) {
266 next;
267 } else {
268 $field_def .= " DEFAULT '$default'";
269 }
270 }
271
272 return $field_def;
273
274}
275
276sub create_index
277{
278 my ($index, $options) = @_;
279
280 my $name = $index->name;
4d438549 281 $name = mk_name($index->table->name, $name);
282
283 my $type = $index->type eq 'UNIQUE' ? "UNIQUE " : '';
bfb5a568 284
285 # strip any field size qualifiers as SQLite doesn't like these
286 my @fields = map { s/\(\d+\)$//; $_ } $index->fields;
cc74bccc 287 (my $index_table_name = $index->table->name) =~ s/^.+?\.//; # table name may not specify schema
288 warn "removing schema name from '" . $index->table->name . "' to make '$index_table_name'\n" if $WARN;
bfb5a568 289 my $index_def =
907f8cea 290 "CREATE ${type}INDEX $name ON " . $index_table_name .
291 ' (' . join( ', ', @fields ) . ')';
bfb5a568 292
293 return $index_def;
294}
295
296sub create_constraint
297{
298 my ($c, $options) = @_;
299
300 my $name = $c->name;
4d438549 301 $name = mk_name($c->table->name, $name);
bfb5a568 302 my @fields = $c->fields;
cc74bccc 303 (my $index_table_name = $c->table->name) =~ s/^.+?\.//; # table name may not specify schema
304 warn "removing schema name from '" . $c->table->name . "' to make '$index_table_name'\n" if $WARN;
bfb5a568 305
306 my $c_def =
907f8cea 307 "CREATE UNIQUE INDEX $name ON " . $index_table_name .
308 ' (' . join( ', ', @fields ) . ')';
bfb5a568 309
310 return $c_def;
311}
312
4d438549 313sub alter_table { } # Noop
314
315sub add_field {
316 my ($field) = @_;
317
318 return sprintf("ALTER TABLE %s ADD COLUMN %s",
319 $field->table->name, create_field($field))
320}
321
322sub alter_create_index {
323 my ($index) = @_;
324
325 # This might cause name collisions
326 return create_index($index);
327}
328
329sub alter_create_constraint {
330 my ($constraint) = @_;
331
332 return create_constraint($constraint) if $constraint->type eq 'UNIQUE';
333}
334
335sub alter_drop_constraint { alter_drop_index(@_) }
336
337sub alter_drop_index {
338 my ($constraint) = @_;
339
340 return sprintf("DROP INDEX %s ON %s",
341 $constraint->name, $constraint->table->name);
342}
343
344sub batch_alter_table {
345 my ($table, $diffs) = @_;
346
4d438549 347 # If we have any of the following
348 #
349 # rename_field
350 # alter_field
351 # drop_field
352 #
353 # we need to do the following <http://www.sqlite.org/faq.html#q11>
354 #
355 # BEGIN TRANSACTION;
356 # CREATE TEMPORARY TABLE t1_backup(a,b);
357 # INSERT INTO t1_backup SELECT a,b FROM t1;
358 # DROP TABLE t1;
359 # CREATE TABLE t1(a,b);
360 # INSERT INTO t1 SELECT a,b FROM t1_backup;
361 # DROP TABLE t1_backup;
362 # COMMIT;
363 #
364 # Fun, eh?
46bf5655 365 #
366 # If we have rename_field we do similarly.
367
368 my $table_name = $table->name;
369 my $renaming = $diffs->{rename_table} && @{$diffs->{rename_table}};
4d438549 370
371 if ( @{$diffs->{rename_field}} == 0 &&
372 @{$diffs->{alter_field}} == 0 &&
46bf5655 373 @{$diffs->{drop_field}} == 0
374 ) {
4d438549 375 return join("\n", map {
376 my $meth = __PACKAGE__->can($_) or die __PACKAGE__ . " cant $_";
377 map { my $sql = $meth->(ref $_ eq 'ARRAY' ? @$_ : $_); $sql ? ("$sql;") : () } @{ $diffs->{$_} }
378
46bf5655 379 } grep { @{$diffs->{$_}} }
380 qw/rename_table
381 alter_drop_constraint
382 alter_drop_index
383 drop_field
384 add_field
385 alter_field
386 rename_field
387 alter_create_index
388 alter_create_constraint
389 alter_table/);
4d438549 390 }
391
392
393 my @sql;
46bf5655 394 my $old_table = $renaming ? $diffs->{rename_table}[0][0] : $table;
4d438549 395
396 do {
46bf5655 397 local $table->{name} = $table_name . '_temp_alter';
4d438549 398 # We only want the table - dont care about indexes on tmp table
399 my ($table_sql) = create_table($table, {no_comments => 1, temporary_table => 1});
400 push @sql,$table_sql;
401 };
402
46bf5655 403 push @sql, "INSERT INTO @{[$table_name]}_temp_alter SELECT @{[ join(', ', $old_table->get_fields)]} FROM @{[$old_table]}",
404 "DROP TABLE @{[$old_table]}",
4d438549 405 create_table($table, { no_comments => 1 }),
46bf5655 406 "INSERT INTO @{[$table_name]} SELECT @{[ join(', ', $old_table->get_fields)]} FROM @{[$table_name]}_temp_alter",
407 "DROP TABLE @{[$table_name]}_temp_alter";
4d438549 408
409 return join(";\n", @sql, "");
410}
411
412sub drop_table {
413 my ($table) = @_;
414 return "DROP TABLE $table;";
415}
416
46bf5655 417sub rename_table {
418 my ($old_table, $new_table, $options) = @_;
419
420 my $qt = $options->{quote_table_names} || '';
421
422 return "ALTER TABLE $qt$old_table$qt RENAME TO $qt$new_table$qt";
423
424}
425
bfb5a568 4261;
758ab1cd 427
20770e44 428=pod
429
430=head1 SEE ALSO
431
432SQL::Translator, http://www.sqlite.org/.
758ab1cd 433
434=head1 AUTHOR
435
4d438549 436Ken Y. Clark C<< <kclark@cpan.orgE> >>.
437
438Diff code added by Ash Berlin C<< <ash@cpan.org> >>.
20770e44 439
440=cut