1package SQL::Translator::Producer::SQLite; 2 3=head1 NAME 4 5SQL::Translator::Producer::SQLite - SQLite producer for SQL::Translator 6 7=head1 SYNOPSIS 8 9 use SQL::Translator; 10 11 my $t = SQL::Translator->new( parser => '...', producer => 'SQLite' ); 12 $t->translate; 13 14=head1 DESCRIPTION 15 16This module will produce text output of the schema suitable for SQLite. 17 18=cut 19 20use strict; 21use warnings; 22use Data::Dumper; 23use SQL::Translator::Schema::Constants; 24use SQL::Translator::Utils qw(debug header_comment parse_dbms_version batch_alter_table_statements); 25use SQL::Translator::Generator::DDL::SQLite; 26 27our ( $DEBUG, $WARN ); 28our $VERSION = '1.62'; 29$DEBUG = 0 unless defined $DEBUG; 30$WARN = 0 unless defined $WARN; 31 32our $max_id_length = 30; 33my %global_names; 34 35# HIDEOUS TEMPORARY DEFAULT WITHOUT QUOTING! 36our $NO_QUOTES = 1; 37{ 38 39 my ($quoting_generator, $nonquoting_generator); 40 sub _generator { 41 $NO_QUOTES 42 ? $nonquoting_generator ||= SQL::Translator::Generator::DDL::SQLite->new(quote_chars => []) 43 : $quoting_generator ||= SQL::Translator::Generator::DDL::SQLite->new 44 } 45} 46 47sub produce { 48 my $translator = shift; 49 local $DEBUG = $translator->debug; 50 local $WARN = $translator->show_warnings; 51 my $no_comments = $translator->no_comments; 52 my $add_drop_table = $translator->add_drop_table; 53 my $schema = $translator->schema; 54 my $producer_args = $translator->producer_args; 55 my $sqlite_version = parse_dbms_version( 56 $producer_args->{sqlite_version}, 'perl' 57 ); 58 my $no_txn = $producer_args->{no_transaction}; 59 60 debug("PKG: Beginning production\n"); 61 62 %global_names = (); #reset 63 64 # only quote if quotes were requested for real 65 # 0E0 indicates "the default of true" was assumed 66 local $NO_QUOTES = 0 67 if $translator->quote_identifiers and $translator->quote_identifiers ne '0E0'; 68 69 my $head; 70 $head = (header_comment() . "\n") unless $no_comments; 71 72 my @create = (); 73 74 push @create, "BEGIN TRANSACTION" unless $no_txn; 75 76 for my $table ( $schema->get_tables ) { 77 push @create, create_table($table, { no_comments => $no_comments, 78 sqlite_version => $sqlite_version, 79 add_drop_table => $add_drop_table,}); 80 } 81 82 for my $view ( $schema->get_views ) { 83 push @create, create_view($view, { 84 add_drop_view => $add_drop_table, 85 no_comments => $no_comments, 86 }); 87 } 88 89 for my $trigger ( $schema->get_triggers ) { 90 push @create, create_trigger($trigger, { 91 add_drop_trigger => $add_drop_table, 92 no_comments => $no_comments, 93 }); 94 } 95 96 push @create, "COMMIT" unless $no_txn; 97 98 if (wantarray) { 99 return ($head||(), @create); 100 } else { 101 return join ('', 102 $head||(), 103 join(";\n\n", @create ), 104 ";\n", 105 ); 106 } 107} 108 109sub mk_name { 110 my ($name, $scope, $critical) = @_; 111 112 $scope ||= \%global_names; 113 if ( my $prev = $scope->{ $name } ) { 114 my $name_orig = $name; 115 $name .= sprintf( "%02d", ++$prev ); 116 substr($name, $max_id_length - 3) = "00" 117 if length( $name ) > $max_id_length; 118 119 warn "The name '$name_orig' has been changed to ", 120 "'$name' to make it unique.\n" if $WARN; 121 122 $scope->{ $name_orig }++; 123 } 124 125 $scope->{ $name }++; 126 return _generator()->quote($name); 127} 128 129sub create_view { 130 my ($view, $options) = @_; 131 my $add_drop_view = $options->{add_drop_view}; 132 133 my $view_name = _generator()->quote($view->name); 134 $global_names{$view->name} = 1; 135 136 debug("PKG: Looking at view '${view_name}'\n"); 137 138 # Header. Should this look like what mysqldump produces? 139 my $extra = $view->extra; 140 my @create; 141 push @create, "DROP VIEW IF EXISTS $view_name" if $add_drop_view; 142 143 my $create_view = 'CREATE'; 144 $create_view .= " TEMPORARY" if exists($extra->{temporary}) && $extra->{temporary}; 145 $create_view .= ' VIEW'; 146 $create_view .= " IF NOT EXISTS" if exists($extra->{if_not_exists}) && $extra->{if_not_exists}; 147 $create_view .= " ${view_name}"; 148 149 if( my $sql = $view->sql ){ 150 $create_view .= " AS\n ${sql}"; 151 } 152 push @create, $create_view; 153 154 # Tack the comment onto the first statement. 155 unless ($options->{no_comments}) { 156 $create[0] = "--\n-- View: ${view_name}\n--\n" . $create[0]; 157 } 158 159 return @create; 160} 161 162 163sub create_table 164{ 165 my ($table, $options) = @_; 166 167 my $table_name = _generator()->quote($table->name); 168 $global_names{$table->name} = 1; 169 170 my $no_comments = $options->{no_comments}; 171 my $add_drop_table = $options->{add_drop_table}; 172 my $sqlite_version = $options->{sqlite_version} || 0; 173 174 debug("PKG: Looking at table '$table_name'\n"); 175 176 my ( @index_defs, @constraint_defs ); 177 my @fields = $table->get_fields or die "No fields in $table_name"; 178 179 my $temp = $options->{temporary_table} ? 'TEMPORARY ' : ''; 180 # 181 # Header. 182 # 183 my $exists = ($sqlite_version >= 3.003) ? ' IF EXISTS' : ''; 184 my @create; 185 my ($comment, $create_table) = ""; 186 $comment = "--\n-- Table: $table_name\n--\n" unless $no_comments; 187 if ($add_drop_table) { 188 push @create, $comment . qq[DROP TABLE$exists $table_name]; 189 } else { 190 $create_table = $comment; 191 } 192 193 $create_table .= "CREATE ${temp}TABLE $table_name (\n"; 194 195 # 196 # Comments 197 # 198 if ( $table->comments and !$no_comments ){ 199 $create_table .= "-- Comments: \n-- "; 200 $create_table .= join "\n-- ", $table->comments; 201 $create_table .= "\n--\n\n"; 202 } 203 204 # 205 # How many fields in PK? 206 # 207 my $pk = $table->primary_key; 208 my @pk_fields = $pk ? $pk->fields : (); 209 210 # 211 # Fields 212 # 213 my ( @field_defs, $pk_set ); 214 for my $field ( @fields ) { 215 push @field_defs, create_field($field); 216 } 217 218 if ( 219 scalar @pk_fields > 1 220 || 221 ( @pk_fields && !grep /INTEGER PRIMARY KEY/, @field_defs ) 222 ) { 223 push @field_defs, 'PRIMARY KEY (' . join(', ', map _generator()->quote($_), @pk_fields ) . ')'; 224 } 225 226 # 227 # Indices 228 # 229 for my $index ( $table->get_indices ) { 230 push @index_defs, create_index($index); 231 } 232 233 # 234 # Constraints 235 # 236 for my $c ( $table->get_constraints ) { 237 if ($c->type eq "FOREIGN KEY") { 238 push @field_defs, create_foreignkey($c); 239 } 240 elsif ($c->type eq "CHECK") { 241 push @field_defs, create_check_constraint($c); 242 } 243 next unless $c->type eq UNIQUE; 244 push @constraint_defs, create_constraint($c); 245 } 246 247 $create_table .= join(",\n", map { " $_" } @field_defs ) . "\n)"; 248 249 return (@create, $create_table, @index_defs, @constraint_defs ); 250} 251 252sub create_check_constraint { 253 my $c = shift; 254 my $check = ''; 255 $check .= 'CONSTRAINT ' . _generator->quote( $c->name ) . ' ' if $c->name; 256 $check .= 'CHECK(' . $c->expression . ')'; 257 return $check; 258} 259 260sub create_foreignkey { 261 my $c = shift; 262 263 my @fields = $c->fields; 264 my @rfields = map { $_ || () } $c->reference_fields; 265 unless ( @rfields ) { 266 my $rtable_name = $c->reference_table; 267 if ( my $ref_table = $c->schema->get_table( $rtable_name ) ) { 268 push @rfields, $ref_table->primary_key; 269 270 die "FK constraint on " . $rtable_name . '.' . join('', @fields) . " has no reference fields\n" 271 unless @rfields; 272 } 273 else { 274 die "Can't find reference table '$rtable_name' in schema\n"; 275 } 276 } 277 278 my $fk_sql = sprintf 'FOREIGN KEY (%s) REFERENCES %s(%s)', 279 join (', ', map { _generator()->quote($_) } @fields ), 280 _generator()->quote($c->reference_table), 281 join (', ', map { _generator()->quote($_) } @rfields ) 282 ; 283 284 $fk_sql .= " ON DELETE " . $c->{on_delete} if $c->{on_delete}; 285 $fk_sql .= " ON UPDATE " . $c->{on_update} if $c->{on_update}; 286 287 return $fk_sql; 288} 289 290sub create_field { return _generator()->field($_[0]) } 291 292sub create_index 293{ 294 my ($index, $options) = @_; 295 296 (my $index_table_name = $index->table->name) =~ s/^.+?\.//; # table name may not specify schema 297 my $name = mk_name($index->name || "${index_table_name}_idx"); 298 299 my $type = $index->type eq 'UNIQUE' ? "UNIQUE " : ''; 300 301 # strip any field size qualifiers as SQLite doesn't like these 302 my @fields = map { s/\(\d+\)$//; _generator()->quote($_) } $index->fields; 303 $index_table_name = _generator()->quote($index_table_name); 304 warn "removing schema name from '" . $index->table->name . "' to make '$index_table_name'\n" if $WARN; 305 my $index_def = 306 "CREATE ${type}INDEX $name ON " . $index_table_name . 307 ' (' . join( ', ', @fields ) . ')'; 308 309 return $index_def; 310} 311 312sub create_constraint 313{ 314 my ($c, $options) = @_; 315 316 (my $index_table_name = $c->table->name) =~ s/^.+?\.//; # table name may not specify schema 317 my $name = mk_name($c->name || "${index_table_name}_idx"); 318 my @fields = map _generator()->quote($_), $c->fields; 319 $index_table_name = _generator()->quote($index_table_name); 320 warn "removing schema name from '" . $c->table->name . "' to make '$index_table_name'\n" if $WARN; 321 322 my $c_def = 323 "CREATE UNIQUE INDEX $name ON " . $index_table_name . 324 ' (' . join( ', ', @fields ) . ')'; 325 326 return $c_def; 327} 328 329sub create_trigger { 330 my ($trigger, $options) = @_; 331 my $add_drop = $options->{add_drop_trigger}; 332 333 my @statements; 334 335 my $trigger_name = $trigger->name; 336 $global_names{$trigger_name} = 1; 337 338 my $events = $trigger->database_events; 339 for my $evt ( @$events ) { 340 341 my $trig_name = $trigger_name; 342 if (@$events > 1) { 343 $trig_name .= "_$evt"; 344 345 warn "Multiple database events supplied for trigger '$trigger_name', ", 346 "creating trigger '$trig_name' for the '$evt' event.\n" if $WARN; 347 } 348 349 $trig_name = _generator()->quote($trig_name); 350 push @statements, "DROP TRIGGER IF EXISTS $trig_name" if $add_drop; 351 352 353 $DB::single = 1; 354 my $action = ""; 355 if (not ref $trigger->action) { 356 $action = $trigger->action; 357 $action = "BEGIN " . $action . " END" 358 unless $action =~ /^ \s* BEGIN [\s\;] .*? [\s\;] END [\s\;]* $/six; 359 } 360 else { 361 $action = $trigger->action->{for_each} . " " 362 if $trigger->action->{for_each}; 363 364 $action = $trigger->action->{when} . " " 365 if $trigger->action->{when}; 366 367 my $steps = $trigger->action->{steps} || []; 368 369 $action .= "BEGIN "; 370 $action .= $_ . "; " for (@$steps); 371 $action .= "END"; 372 } 373 374 push @statements, sprintf ( 375 'CREATE TRIGGER %s %s %s on %s %s', 376 $trig_name, 377 $trigger->perform_action_when, 378 $evt, 379 _generator()->quote($trigger->on_table), 380 $action 381 ); 382 } 383 384 return @statements; 385} 386 387sub alter_table { () } # Noop 388 389sub add_field { 390 my ($field) = @_; 391 392 return sprintf("ALTER TABLE %s ADD COLUMN %s", 393 _generator()->quote($field->table->name), create_field($field)) 394} 395 396sub alter_create_index { 397 my ($index) = @_; 398 399 # This might cause name collisions 400 return create_index($index); 401} 402 403sub alter_create_constraint { 404 my ($constraint) = @_; 405 406 return create_constraint($constraint) if $constraint->type eq 'UNIQUE'; 407} 408 409sub alter_drop_constraint { alter_drop_index(@_) } 410 411sub alter_drop_index { 412 my ($constraint) = @_; 413 414 return sprintf("DROP INDEX %s", 415 _generator()->quote($constraint->name)); 416} 417 418sub batch_alter_table { 419 my ($table, $diffs, $options) = @_; 420 421 # If we have any of the following 422 # 423 # rename_field 424 # alter_field 425 # drop_field 426 # 427 # we need to do the following <http://www.sqlite.org/faq.html#q11> 428 # 429 # BEGIN TRANSACTION; 430 # CREATE TEMPORARY TABLE t1_backup(a,b); 431 # INSERT INTO t1_backup SELECT a,b FROM t1; 432 # DROP TABLE t1; 433 # CREATE TABLE t1(a,b); 434 # INSERT INTO t1 SELECT a,b FROM t1_backup; 435 # DROP TABLE t1_backup; 436 # COMMIT; 437 # 438 # Fun, eh? 439 # 440 # If we have rename_field we do similarly. 441 # 442 # We create the temporary table as a copy of the new table, copy all data 443 # to temp table, create new table and then copy as appropriate taking note 444 # of renamed fields. 445 446 my $table_name = $table->name; 447 448 if ( @{$diffs->{rename_field}} == 0 && 449 @{$diffs->{alter_field}} == 0 && 450 @{$diffs->{drop_field}} == 0 451 ) { 452 return batch_alter_table_statements($diffs, $options); 453 } 454 455 my @sql; 456 457 # $table is the new table but we may need an old one 458 # TODO: this is NOT very well tested at the moment so add more tests 459 460 my $old_table = $table; 461 462 if ( $diffs->{rename_table} && @{$diffs->{rename_table}} ) { 463 $old_table = $diffs->{rename_table}[0][0]; 464 } 465 466 my $temp_table_name = $table_name . '_temp_alter'; 467 468 # CREATE TEMPORARY TABLE t1_backup(a,b); 469 470 my %temp_table_fields; 471 do { 472 local $table->{name} = $temp_table_name; 473 # We only want the table - don't care about indexes on tmp table 474 my ($table_sql) = create_table($table, {no_comments => 1, temporary_table => 1}); 475 push @sql,$table_sql; 476 477 %temp_table_fields = map { $_ => 1} $table->get_fields; 478 }; 479 480 # record renamed fields for later 481 my %rename_field = map { $_->[1]->name => $_->[0]->name } @{$diffs->{rename_field}}; 482 483 # drop added fields from %temp_table_fields 484 delete @temp_table_fields{@{$diffs->{add_field}}}; 485 486 # INSERT INTO t1_backup SELECT a,b FROM t1; 487 488 push @sql, sprintf( 'INSERT INTO %s( %s) SELECT %s FROM %s', 489 490 _generator()->quote( $temp_table_name ), 491 492 join( ', ', 493 map _generator()->quote($_), 494 grep { $temp_table_fields{$_} } $table->get_fields ), 495 496 join( ', ', 497 map _generator()->quote($_), 498 map { $rename_field{$_} ? $rename_field{$_} : $_ } 499 grep { $temp_table_fields{$_} } $table->get_fields ), 500 501 _generator()->quote( $old_table->name ) 502 ); 503 504 # DROP TABLE t1; 505 506 push @sql, sprintf('DROP TABLE %s', _generator()->quote($old_table->name)); 507 508 # CREATE TABLE t1(a,b); 509 510 push @sql, create_table($table, { no_comments => 1 }); 511 512 # INSERT INTO t1 SELECT a,b FROM t1_backup; 513 514 push @sql, sprintf('INSERT INTO %s SELECT %s FROM %s', 515 _generator()->quote($table_name), 516 join(', ', map _generator()->quote($_), $table->get_fields), 517 _generator()->quote($temp_table_name) 518 ); 519 520 # DROP TABLE t1_backup; 521 522 push @sql, sprintf('DROP TABLE %s', _generator()->quote($temp_table_name)); 523 524 return wantarray ? @sql : join(";\n", @sql); 525} 526 527sub drop_table { 528 my ($table) = @_; 529 $table = _generator()->quote($table); 530 return "DROP TABLE $table"; 531} 532 533sub rename_table { 534 my ($old_table, $new_table, $options) = @_; 535 536 $old_table = _generator()->quote($old_table); 537 $new_table = _generator()->quote($new_table); 538 539 return "ALTER TABLE $old_table RENAME TO $new_table"; 540 541} 542 543# No-op. Just here to signify that we are a new style parser. 544sub preproces_schema { } 545 5461; 547 548=pod 549 550=head1 SEE ALSO 551 552SQL::Translator, http://www.sqlite.org/. 553 554=head1 AUTHOR 555 556Ken Youens-Clark C<< <kclark@cpan.orgE> >>. 557 558Diff code added by Ash Berlin C<< <ash@cpan.org> >>. 559 560=cut 561