'Log::Log4perl' => 0,
'Parse::RecDescent' => 1.94,
'Pod::Usage' => 0,
+ 'Class::Accessor::Fast' => 0,
},
recommends => {
'Template' => 2.10,
'File::Basename' => 0,
'File::Spec' => 0,
'Test::More' => 0.6,
+ 'Test::Differences' => 0,
'Test::Exception' => 0,
'Test::Differences' => 0,
'YAML' => 0.39,
t/29html.t
t/30sqlt-diff.t
t/30sqlt-new-diff.t
+t/30sqlt-new-diff-mysql.t
+t/30sqlt-new-diff-sqlite.t
t/31dumper.t
t/32schema-lookups.t
t/33tt-table-producer.t
t/data/sybase/create.sql
t/data/template/basic.tt
t/data/template/table.tt
+t/data/diff/create1.yml
+t/data/diff/create2.yml
t/data/xml/schema.xml
t/data/xml/samefield.xml
t/lib/Producer/BaseTest.pm
resources:
license: http://www.opensource.org/licenses/gpl-license.php
requires:
+ Class::Accessor::Fast: 0
Class::Base: 0
Class::Data::Inheritable: 0.02
Class::MakeMethods: 0
YAML: 0.39
recommends:
GD: 0
+ Graph::Directed: 0
GraphViz: 0
IO::File: 0
IO::Scalar: 0
version: 1.29
SQL::Translator::Parser::PostgreSQL:
file: lib/SQL/Translator/Parser/PostgreSQL.pm
- version: 1.48
+ version: 1.50
SQL::Translator::Parser::SQLServer:
file: lib/SQL/Translator/Parser/SQLServer.pm
version: 1.06
version: 1.01
SQL::Translator::Producer::MySQL:
file: lib/SQL/Translator/Producer/MySQL.pm
- version: 1.52
+ version: 1.54
SQL::Translator::Producer::Oracle:
file: lib/SQL/Translator/Producer/Oracle.pm
version: 1.34
version: 1.12
SQL::Translator::Schema:
file: lib/SQL/Translator/Schema.pm
- version: 1.26
+ version: 1.27
SQL::Translator::Schema::Constants:
file: lib/SQL/Translator/Schema/Constants.pm
version: 1.43
version: 1.21
SQL::Translator::Schema::Field:
file: lib/SQL/Translator/Schema/Field.pm
- version: 1.26
+ version: 1.27
SQL::Translator::Schema::Graph:
file: lib/SQL/Translator/Schema/Graph.pm
SQL::Translator::Schema::Graph::CompoundEdge:
file: lib/SQL/Translator/Schema/Graph/Port.pm
SQL::Translator::Schema::Index:
file: lib/SQL/Translator/Schema/Index.pm
- version: 1.17
+ version: 1.18
SQL::Translator::Schema::Object:
file: lib/SQL/Translator/Schema/Object.pm
version: 1.08
version: 1.08
SQL::Translator::Schema::Table:
file: lib/SQL/Translator/Schema/Table.pm
- version: 1.36
+ version: 1.37
SQL::Translator::Schema::Trigger:
file: lib/SQL/Translator/Schema/Trigger.pm
version: 1.09
Test::SQL::Translator:
file: lib/Test/SQL/Translator.pm
version: 1.08
-generated_by: Module::Build version 0.28
+generated_by: Module::Build version 0.2806
meta-spec:
url: http://module-build.sourceforge.net/META-spec-v1.2.html
version: 1.2
package SQL::Translator::Diff;
+
+
## SQLT schema diffing code
use strict;
use warnings;
+
use Data::Dumper;
use SQL::Translator::Schema::Constants;
-sub schema_diff
- {
+use base 'Class::Accessor::Fast';
+
+# Input/option accessors
+__PACKAGE__->mk_accessors(qw/
+ ignore_index_names ignore_constraint_names ignore_view_sql
+ ignore_proc_sql output_db source_schema source_db target_schema target_db
+ case_insensitive no_batch_alters ignore_missing_methods
+/);
+
+my @diff_arrays = qw/
+ tables_to_drop
+ tables_to_create
+/;
+
+my @diff_hash_keys = qw/
+ constraints_to_create
+ constraints_to_drop
+ indexes_to_create
+ indexes_to_drop
+ fields_to_create
+ fields_to_alter
+ fields_to_rename
+ fields_to_drop
+ table_options
+/;
+
+__PACKAGE__->mk_accessors(@diff_arrays, 'table_diff_hash');
+
+sub schema_diff {
# use Data::Dumper;
## we are getting instructions on how to turn the source into the target
## source == original, target == new (hmm, if I need to comment this, should I rename the vars again ??)
## results are formatted to the source preferences
my ($source_schema, $source_db, $target_schema, $target_db, $options) = @_;
- # print Data::Dumper::Dumper($target_schema);
+ $options ||= {};
- my $producer_class = "SQL::Translator::Producer::$source_db";
- eval "require $producer_class";
+ my $obj = SQL::Translator::Diff->new( {
+ %$options,
+ source_schema => $source_schema,
+ source_db => $source_db,
+ target_schema => $target_schema,
+ target_db => $target_db
+ } );
- my $case_insensitive = $options->{caseopt} || 0;
- my $debug = $options->{debug} || 0;
- my $trace = $options->{trace} || 0;
- my $ignore_index_names = $options->{ignore_index_names} || 0;
- my $ignore_constraint_names = $options->{ignore_constraint_names} || 0;
- my $ignore_view_sql = $options->{ignore_view_sql} || 0;
- my $ignore_proc_sql = $options->{ignore_proc_sql} || 0;
- my $output_db = $options->{output_db} || $source_db;
+ $obj->compute_differences->produce_diff_sql;
+}
- my $tar_name = $target_schema->name;
- my $src_name = $source_schema->name;
+sub new {
+ my ($class, $values) = @_;
+ $values->{$_} ||= [] foreach @diff_arrays;
+ $values->{table_diff_hash} = {};
+
+ $values->{output_db} ||= $values->{source_db};
+ return $class->SUPER::new($values);
+}
+
+sub compute_differences {
+ my ($self) = @_;
- my ( @diffs_new_tables, @diffs_at_end, @new_tables, @diffs_index_drops, @diffs_constraint_drops, @diffs_table_drops, @diffs_table_adds, @diffs_index_creates, @diffs_constraint_creates, @diffs_table_options );
+ my $target_schema = $self->target_schema;
+ my $source_schema = $self->source_schema;
+
+ my @tar_tables = sort { $a->name cmp $b->name } $target_schema->get_tables;
## do original/source tables exist in target?
- for my $tar_table ( $target_schema->get_tables ) {
+ for my $tar_table ( @tar_tables ) {
my $tar_table_name = $tar_table->name;
- my $src_table = $source_schema->get_table( $tar_table_name, $case_insensitive );
+ my $src_table = $source_schema->get_table( $tar_table_name, $self->case_insensitive );
- warn "TABLE '$tar_name.$tar_table_name'\n" if $debug;
unless ( $src_table ) {
- warn "Couldn't find table '$tar_name.$tar_table_name' in '$src_name'\n"
- if $debug;
## table is new
## add table(s) later.
- my $cr_table = $producer_class->can('create_table') || die "$producer_class does not support create_table";
- my $new_table_sql = $cr_table->($tar_table, { leave_name => 1 });
- push (@diffs_new_tables, $new_table_sql);
- push (@new_tables, $tar_table);
+ push @{$self->tables_to_create}, $tar_table;
next;
}
- # Go through our options
- my $options_different = 0;
- my %checkedOptions;
- OPTION:
- for my $tar_table_option_ref ( $tar_table->options ) {
- my($key_tar, $value_tar) = %{$tar_table_option_ref};
- for my $src_table_option_ref ( $src_table->options ) {
- my($key_src, $value_src) = %{$src_table_option_ref};
- if ( $key_tar eq $key_src ) {
- if ( defined $value_tar != defined $value_src ) {
- $options_different = 1;
- last OPTION;
- }
- if ( defined $value_tar && $value_tar ne $value_src ) {
- $options_different = 1;
- last OPTION;
- }
- $checkedOptions{$key_tar} = 1;
- next OPTION;
- }
- }
- $options_different = 1;
- last OPTION;
- }
- # Go through the other table's options
- unless ( $options_different ) {
- for my $src_table_option_ref ( $src_table->options ) {
- my($key, $value) = %{$src_table_option_ref};
- next if $checkedOptions{$key};
- $options_different = 1;
- last;
- }
- }
- # If there's a difference, just re-set all the options
- if ( $options_different ) {
- my $al_table = $producer_class->can('alter_table') || die "$producer_class does not support alter_table";
- my $alter_sql = $al_table->( $tar_table ) . ';';
- @diffs_table_options = ("$alter_sql");
- }
+ $self->table_diff_hash->{$tar_table_name} = {
+ map {$_ => [] } @diff_hash_keys
+ };
+
+ $self->diff_table_options($src_table, $tar_table);
- my $src_table_name = $src_table->name;
## Compare fields, their types, defaults, sizes etc etc
- for my $tar_table_field ( $tar_table->get_fields ) {
- my $f_tar_type = $tar_table_field->data_type;
- my $f_tar_size = $tar_table_field->size;
- my $f_tar_name = $tar_table_field->name;
- my $f_tar_nullable = $tar_table_field->is_nullable;
- my $f_tar_default = $tar_table_field->default_value;
- my $f_tar_auto_inc = $tar_table_field->is_auto_increment;
- my $src_table_field = $src_table->get_field( $f_tar_name, $case_insensitive );
- my $f_tar_full_name = "$tar_name.$tar_table_name.$f_tar_name";
- warn "FIELD '$f_tar_full_name'\n" if $debug;
-
- my $f_src_full_name = "$src_name.$src_table_name.$f_tar_name";
-
- unless ( $src_table_field ) {
- warn "Couldn't find field '$f_src_full_name' in '$src_table_name'\n"
- if $debug;
-
- my $add_field = $producer_class->can('add_field') || die "$producer_class does not support add_field";
- my $alter_add_sql = $add_field->( $tar_table_field ) . ';';
- push (@diffs_table_adds, $alter_add_sql);
- next;
- }
+ $self->diff_table_fields($src_table, $tar_table);
- ## field exists, so what changed?
- ## (do we care? just call equals to see IF)
- if ( !$tar_table_field->equals($src_table_field, $case_insensitive) ) {
- ## throw all this junk away and call producer->alter_field
- ## check output same, etc etc
+ $self->diff_table_indexes($src_table, $tar_table);
+ $self->diff_table_constraints($src_table, $tar_table);
- my $al_field = $producer_class->can('alter_field') || die "$producer_class does not support alter_field";
- my $alter_field_sql = $al_field->( $src_table_field, $tar_table_field ) . ';';
- push (@diffs_table_adds, $alter_field_sql);
- next;
- }
- }
+ } # end of target_schema->get_tables loop
- for my $src_table_field ( $src_table->get_fields ) {
- my $f_src_name = $src_table_field->name;
- my $tar_table_field = $tar_table->get_field( $f_src_name, $case_insensitive );
- my $f_src_full_name = "$tar_name.$tar_table_name.$f_src_name";
+ for my $src_table ( $source_schema->get_tables ) {
+ my $src_table_name = $src_table->name;
+ my $tar_table = $target_schema->get_table( $src_table_name, $self->case_insensitive );
- unless ( $tar_table_field ) {
- warn "Couldn't find field '$f_src_full_name' in '$src_table_name'\n"
- if $debug;
+ unless ( $tar_table ) {
+ $self->table_diff_hash->{$src_table_name} = {
+ map {$_ => [] } @diff_hash_keys
+ };
- my $dr_field = $producer_class->can('drop_field') || die "$producer_class does not support drop_field";
- my $alter_drop_sql = $dr_field->( $src_table_field ) . ';';
- push (@diffs_table_drops, $alter_drop_sql);
- next;
- }
+ push @{ $self->tables_to_drop}, $src_table;
+ next;
}
+ }
+
+ return $self;
+}
+
+sub produce_diff_sql {
+ my ($self) = @_;
+
+ my $target_schema = $self->target_schema;
+ my $source_schema = $self->source_schema;
+ my $tar_name = $target_schema->name;
+ my $src_name = $source_schema->name;
+
+ my $producer_class = "SQL::Translator::Producer::@{[$self->output_db]}";
+ eval "require $producer_class";
+ die $@ if $@;
+
+ # Map of name we store under => producer method name
+ my %func_map = (
+ constraints_to_create => 'alter_create_constraint',
+ constraints_to_drop => 'alter_drop_constraint',
+ indexes_to_create => 'alter_create_index',
+ indexes_to_drop => 'alter_drop_index',
+ fields_to_create => 'add_field',
+ fields_to_alter => 'alter_field',
+ fields_to_rename => 'rename_field',
+ fields_to_drop => 'drop_field',
+ table_options => 'alter_table'
+ );
+ my @diffs;
+
+ if (!$self->no_batch_alters &&
+ (my $batch_alter = $producer_class->can('batch_alter_table')) )
+ {
+ # Good - Producer supports batch altering of tables.
+ foreach my $table ( sort keys %{$self->table_diff_hash} ) {
+ my $tar_table = $target_schema->get_table($table)
+ || $source_schema->get_table($table);
- my (%checked_indices);
- INDEX_CREATE:
- for my $i_tar ( $tar_table->get_indices ) {
- for my $i_src ( $src_table->get_indices ) {
- if ( $i_tar->equals($i_src, $case_insensitive, $ignore_index_names) ) {
- $checked_indices{$i_src} = 1;
- next INDEX_CREATE;
+ $DB::single = 1 if $table eq 'deleted';
+ push @diffs, $batch_alter->($tar_table,
+ { map {
+ $func_map{$_} => $self->table_diff_hash->{$table}{$_}
+ } keys %func_map
}
- }
- my $al_cr_index = $producer_class->can('alter_create_index') || die "$producer_class does not support alter_create_index";
- my $create_index_sql = $al_cr_index->( $i_tar ) . ';';
- push ( @diffs_index_creates, $create_index_sql );
- }
- INDEX_DROP:
- for my $i_src ( $src_table->get_indices ) {
- next if !$ignore_index_names && $checked_indices{$i_src};
- for my $i_tar ( $tar_table->get_indices ) {
- next INDEX_DROP if $i_src->equals($i_tar, $case_insensitive, $ignore_index_names);
- }
- my $al_dr_index = $producer_class->can('alter_drop_index') || die "$producer_class does not support alter_drop_index";
- my $drop_index_sql = $al_dr_index->( $i_src ) . ';';
- push ( @diffs_index_drops, $drop_index_sql );
+ );
}
+ } else {
- my(%checked_constraints);
- CONSTRAINT_CREATE:
- for my $c_tar ( $tar_table->get_constraints ) {
- for my $c_src ( $src_table->get_constraints ) {
- if ( $c_tar->equals($c_src, $case_insensitive, $ignore_constraint_names) ) {
- $checked_constraints{$c_src} = 1;
- next CONSTRAINT_CREATE;
- }
- }
- my $al_cr_const = $producer_class->can('alter_create_constraint') || die "$producer_class does not support alter_create_constraint";
- my $create_constraint_sql = $al_cr_const->( $c_tar, { leave_name => 1 }) . ';';
- push ( @diffs_constraint_creates, $create_constraint_sql );
+ my %flattened_diffs;
+ foreach my $table ( sort keys %{$self->table_diff_hash} ) {
+ my $table_diff = $self->table_diff_hash->{$table};
+ for (@diff_hash_keys) {
+ push( @{ $flattened_diffs{ $func_map{$_} } ||= [] }, @{ $table_diff->{$_} } );
}
+ }
- CONSTRAINT_DROP:
- for my $c_src ( $src_table->get_constraints ) {
- next if !$ignore_constraint_names && $checked_constraints{$c_src};
- for my $c_tar ( $tar_table->get_constraints ) {
- next CONSTRAINT_DROP if $c_src->equals($c_tar, $case_insensitive, $ignore_constraint_names);
- }
+ push @diffs, map( {
+ if (@{$flattened_diffs{$_}}) {
+ my $meth = $producer_class->can($_);
+
+ $meth ? map { my $sql = $meth->(ref $_ eq 'ARRAY' ? @$_ : $_); $sql ? ("$sql;") : () } @{ $flattened_diffs{$_} }
+ : $self->ignore_missing_methods
+ ? "-- $producer_class cant $_"
+ : die "$producer_class cant $_";
+ } else { () }
- my $al_dr_const = $producer_class->can('alter_drop_constraint') || die "$producer_class does not support alter_drop_constraint";
- my $drop_constraint_sql = $al_dr_const->( $c_src ) . ';';
- push ( @diffs_constraint_drops, $drop_constraint_sql );
- }
+ } qw/alter_drop_constraint
+ alter_drop_index
+ drop_field
+ add_field
+ alter_field
+ rename_field
+ alter_create_index
+ alter_create_constraint
+ alter_table/),
}
- my @diffs_dropped_tables;
- for my $src_table ( $source_schema->get_tables ) {
- my $src_table_name = $src_table->name;
- my $tar_table = $target_schema->get_table( $src_table_name, $case_insensitive );
+ if (my @tables = @{ $self->tables_to_create } ) {
+ my $translator = new SQL::Translator(
+ producer_type => $self->output_db,
+ add_drop_table => 0,
+ no_comments => 1,
+ # TODO: sort out options
+ quote_table_names => 0,
+ quote_field_names => 0,
+ );
+ my $schema = $translator->schema;
- unless ( $tar_table ) {
- for my $c_src ( $src_table->get_constraints ) {
- my $al_dr_const = $producer_class->can('alter_drop_constraint') || die "$producer_class does not support alter_drop_constraint";
- my $drop_constraint_sql = $al_dr_const->( $c_src ) . ';';
- push ( @diffs_constraint_drops, $drop_constraint_sql );
- }
+ $schema->add_table($_) for @tables;
- push @diffs_dropped_tables, "DROP TABLE $src_table_name;";
- next;
- }
+ unshift @diffs,
+ # Remove begin/commit here, since we wrap everything in one.
+ grep { $_ !~ /^(?:COMMIT|BEGIN(?: TRANSACTION)?);/ } $producer_class->can('produce')->($translator);
}
- my @diffs;
- push ( @diffs, @diffs_constraint_drops, @diffs_index_drops, @diffs_table_drops, @diffs_table_adds, @diffs_index_creates, @diffs_constraint_creates, @diffs_table_options );
- unshift (@diffs, "SET foreign_key_checks=0;\n\n", @diffs_new_tables, "SET foreign_key_checks=1;\n\n" );
- push (@diffs, @diffs_dropped_tables);
+ if (my @tables_to_drop = @{ $self->{tables_to_drop} || []} ) {
+ my $meth = $producer_class->can('drop_table');
+
+ push @diffs, $meth ? map( { $meth->($_) } @tables_to_drop )
+ : $self->ignore_missing_methods
+ ? "-- $producer_class cant drop_table"
+ : die "$producer_class cant drop_table";
+ }
- if(@diffs_constraint_drops+@diffs_index_drops+@diffs_table_drops+@diffs_table_adds+@diffs_index_creates+@diffs_constraint_creates+@diffs_table_options+@diffs_new_tables+@diffs_dropped_tables == 0 )
- {
- @diffs = ('No differences found');
+ if (@diffs) {
+ unshift @diffs, "BEGIN TRANSACTION;\n";
+ push @diffs, "\nCOMMIT;\n";
+ } else {
+ @diffs = ("-- No differences found\n\n");
}
if ( @diffs ) {
-# if ( $target_db !~ /^(MySQL|SQLServer|Oracle)$/ ) {
- if ( $target_db !~ /^(MySQL)$/ ) {
- unshift(@diffs, "-- Target database $target_db is untested/unsupported!!!");
+ if ( $self->target_db !~ /^(?:MySQL|SQLite)$/ ) {
+ unshift(@diffs, "-- Target database @{[$self->target_db]} is untested/unsupported!!!");
}
- return join( "\n",
- "-- Convert schema '$src_name' to '$tar_name':\n", @diffs, "\n"
- );
+ return join( "\n", "-- Convert schema '$src_name' to '$tar_name':\n", @diffs);
}
return undef;
+
+}
+
+sub diff_table_indexes {
+ my ($self, $src_table, $tar_table) = @_;
+
+ my (%checked_indices);
+ INDEX_CREATE:
+ for my $i_tar ( $tar_table->get_indices ) {
+ for my $i_src ( $src_table->get_indices ) {
+ if ( $i_tar->equals($i_src, $self->case_insensitive, $self->ignore_index_names) ) {
+ $checked_indices{$i_src} = 1;
+ next INDEX_CREATE;
+ }
+ }
+ push @{$self->table_diff_hash->{$tar_table}{indexes_to_create}}, $i_tar;
+ }
+
+ INDEX_DROP:
+ for my $i_src ( $src_table->get_indices ) {
+ next if !$self->ignore_index_names && $checked_indices{$i_src};
+ for my $i_tar ( $tar_table->get_indices ) {
+ next INDEX_DROP if $i_src->equals($i_tar, $self->case_insensitive, $self->ignore_index_names);
+ }
+ push @{$self->table_diff_hash->{$tar_table}{indexes_to_drop}}, $i_src;
+ }
+}
+
+
+sub diff_table_constraints {
+ my ($self, $src_table, $tar_table) = @_;
+
+ my(%checked_constraints);
+ CONSTRAINT_CREATE:
+ for my $c_tar ( $tar_table->get_constraints ) {
+ for my $c_src ( $src_table->get_constraints ) {
+ if ( $c_tar->equals($c_src, $self->case_insensitive, $self->ignore_constraint_names) ) {
+ $checked_constraints{$c_src} = 1;
+ next CONSTRAINT_CREATE;
+ }
+ }
+ push @{ $self->table_diff_hash->{$tar_table}{constraints_to_create} }, $c_tar;
+ }
+
+
+ CONSTRAINT_DROP:
+ for my $c_src ( $src_table->get_constraints ) {
+ next if !$self->ignore_constraint_names && $checked_constraints{$c_src};
+ for my $c_tar ( $tar_table->get_constraints ) {
+ next CONSTRAINT_DROP if $c_src->equals($c_tar, $self->case_insensitive, $self->ignore_constraint_names);
+ }
+
+ push @{ $self->table_diff_hash->{$tar_table}{constraints_to_drop} }, $c_src;
}
+}
+
+sub diff_table_fields {
+ my ($self, $src_table, $tar_table) = @_;
+
+ # List of ones ew've renamed from so we dont drop them
+ my %renamed_source_fields;
+
+ for my $tar_table_field ( $tar_table->get_fields ) {
+ my $f_tar_name = $tar_table_field->name;
+
+ if (my $old_name = $tar_table_field->extra->{renamed_from}) {
+ my $src_table_field = $src_table->get_field( $old_name, $self->case_insensitive );
+ die qq#Renamed cant find "@{[$src_table->name]}.$old_name" for renamed column\n# unless $src_table_field;
+ push @{$self->table_diff_hash->{$tar_table}{fields_to_rename} }, [ $src_table_field, $tar_table_field ];
+ $renamed_source_fields{$old_name} = 1;
+ next;
+ }
+
+ my $src_table_field = $src_table->get_field( $f_tar_name, $self->case_insensitive );
+
+ unless ( $src_table_field ) {
+ push @{$self->table_diff_hash->{$tar_table}{fields_to_create}}, $tar_table_field;
+ next;
+ }
+
+ ## field exists, something changed.
+ if ( !$tar_table_field->equals($src_table_field, $self->case_insensitive) ) {
+
+ # Some producers might need src field to diff against
+ push @{$self->table_diff_hash->{$tar_table}{fields_to_alter}}, [ $src_table_field, $tar_table_field ];
+ next;
+ }
+ }
+
+
+ # Now check to see if any fields from src_table need to be dropped
+ for my $src_table_field ( $src_table->get_fields ) {
+ my $f_src_name = $src_table_field->name;
+ next if $renamed_source_fields{$f_src_name};
+
+ my $tar_table_field = $tar_table->get_field( $f_src_name, $self->case_insensitive );
+
+ unless ( $tar_table_field ) {
+ push @{$self->table_diff_hash->{$tar_table}{fields_to_drop}}, $src_table_field;
+ next;
+ }
+ }
+}
+
+sub diff_table_options {
+ my ($self, $src_table, $tar_table) = @_;
+
+
+ # Go through our options
+ my $options_different = 0;
+ my %checkedOptions;
+
+ OPTION:
+ for my $tar_table_option_ref ( $tar_table->options ) {
+ my($key_tar, $value_tar) = %{$tar_table_option_ref};
+ for my $src_table_option_ref ( $src_table->options ) {
+ my($key_src, $value_src) = %{$src_table_option_ref};
+ if ( $key_tar eq $key_src ) {
+ if ( defined $value_tar != defined $value_src ) {
+ $options_different = 1;
+ last OPTION;
+ }
+ if ( defined $value_tar && $value_tar ne $value_src ) {
+ $options_different = 1;
+ last OPTION;
+ }
+ $checkedOptions{$key_tar} = 1;
+ next OPTION;
+ }
+ }
+ $options_different = 1;
+ last OPTION;
+ }
+
+ # Go through the other table's options
+ unless ( $options_different ) {
+ for my $src_table_option_ref ( $src_table->options ) {
+ my($key, $value) = %{$src_table_option_ref};
+ next if $checkedOptions{$key};
+ $options_different = 1;
+ last;
+ }
+ }
+
+ # If there's a difference, just re-set all the options
+ push @{ $self->table_diff_hash->{$tar_table}{table_options} }, $tar_table
+ if ( $options_different );
+}
+
1;
+
+__END__
+
+=head1 NAME
+
+SQL::Translator::Diff
+
+=head1 DESCRIPTION
+
+Takes two input SQL::Translator::Schemas (or SQL files) and produces ALTER
+statments to make them the same
+
+=head1 SNYOPSIS
+
+Simplest usage:
+
+ use SQL::Translator::Diff;
+ my $sql = SQL::Translator::Diff::schema_diff($source_schema, 'MySQL', $target_schema, 'MySQL', $options_hash)
+
+OO usage:
+
+ use SQL::Translator::Diff;
+ my $diff = SQL::Translator::Diff->new({
+ output_db => 'MySQL',
+ source_schema => $source_schema,
+ target_schema => $target_schema,
+ %$options_hash,
+ })->compute_differences->produce_diff_sql;
+
+=head1 OPTIONS
+
+=over
+
+=item B<ignore_index_names>
+
+Match indexes based on types and fields, ignoring name.
+
+=item B<ignore_constraint_names>
+
+Match constrains based on types, fields and tables, ignoring name.
+
+=item B<output_db>
+
+Which producer to use to produce the output.
+
+=item B<case_insensitive>
+
+Ignore case of table, field, index and constraint names when comparing
+
+=item B<no_batch_alters>
+
+Produce each alter as a distinct C<ALTER TABLE> statement even if the producer
+supports the ability to do all alters for a table as one statement.
+
+=item B<ignore_missing_methods>
+
+If the diff would need a method that is missing from the producer, just emit a
+comment showing the method is missing, rather than dieing with an error
+
+=back
+
+=head1 PRODUCER FUNCTIONS
+
+The following producer functions should be implemented for completeness. If
+any of them are needed for a given diff, but not found, an error will be
+thrown.
+
+=over
+
+=item * C<alter_create_constraint($con)>
+
+=item * C<alter_drop_constraint($con)>
+
+=item * C<alter_create_index($idx)>
+
+=item * C<alter_drop_index($idx)>
+
+=item * C<add_field($fld)>
+
+=item * C<alter_field($old_fld, $new_fld)>
+
+=item * C<rename_field($old_fld, $new_fld)>
+
+=item * C<drop_field($fld)>
+
+=item * C<alter_table($table)>
+
+=item * C<drop_table($table)>
+
+=item * C<batch_alter_table($table, $hash)> (optional)
+
+=back
+
+If the producer supports C<batch_alter_table>, it will be called with the
+table to alter and a hash, the keys of which will be the method names listed
+above; values will be arrays of fields or constraints to operate on. In the
+case of the field functions that take two arguments this will appear as a hash.
+
+I.e. the hash might look something like the following:
+
+ {
+ alter_create_constraint => [ $constraint1, $constraint2 ],
+ add_field => [ $field ],
+ alter_field => [ [$old_field, $new_field] ]
+ }
+
+=head1 AUTHOR
+
+Original Author(s) unknown.
+
+Refactor and more comprehensive tests by Ash Berlin C<< ash@cpan.org >>.
+
+Redevelopment sponsored by Takkle Inc.
+
+=cut
$list = [];
}
- unless ( @{ $size || [] } ) {
+ if ( @{ $size || [] } == 0 && !$thisparser->{local}{sqlt_parser_args}{no_default_sizes} ) {
if ( lc $type eq 'tinyint' ) {
$size = 4;
}
return $translator->error("Error instantiating Parse::RecDescent ".
"instance: Bad grammer");
}
+
+ # This is the only way to get args into the productions/actions
+ $parser->{local}{sqlt_parser_args} = $translator->parser_args;
# Preprocess for MySQL-specific and not-before-version comments from mysqldump
my $parser_version = $translator->parser_args->{mysql_parser_version} || DEFAULT_PARSER_VERSION;
;
for my $tdata ( @tables ) {
+
my $table = $schema->add_table(
- name => $tdata->{'name'},
- extra => $tdata->{'extra'},
+ map {
+ $tdata->{$_} ? ($_ => $tdata->{$_}) : ()
+ } (qw/name extra options/)
) or die $schema->error;
my @fields =
Set the MySQL field options of the same name.
+=item field.renamed_from
+
+Used when producing diffs to say this column is the new name fo the specified
+old column.
+
=item table.mysql_table_type
Set the type of the table e.g. 'InnoDB', 'MyISAM'. This will be
automatically set for tables involved in foreign key constraints if it is
not already set explicitly. See L<"Table Types">.
-=item mysql_character_set
-
-MySql-4.1+. Set the tables character set.
-Run SHOW CHARACTER SET to see list.
-
-=item mysql_collate
-
-MySql-4.1+. Set the tables colation order.
-
=item table.mysql_charset, table.mysql_collate
Set the tables default charater set and collation order.
# Generate sql
#
my @table_defs =();
+
for my $table ( $schema->get_tables ) {
# print $table->name, "\n";
push @table_defs, create_table($table,
$create .= " $key=$value";
}
my $mysql_table_type = $table->extra('mysql_table_type');
- #my $charset = $table->extra('mysql_character_set');
- #my $collate = $table->extra('mysql_collate');
- #$create .= " Type=$mysql_table_type" if $mysql_table_type;
- #$create .= " DEFAULT CHARACTER SET $charset" if $charset;
- #$create .= " COLLATE $collate" if $collate;
$create .= " Type=$mysql_table_type"
if $mysql_table_type && !$table_type_defined;
my $charset = $table->extra('mysql_charset');
return $out;
}
+sub rename_field { alter_field(@_) }
sub alter_field
{
my ($from_field, $to_field, $options) = @_;
my $out = sprintf('ALTER TABLE %s CHANGE COLUMN %s %s',
$qt . $to_field->table->name . $qt,
- $qf . $to_field->name . $qf,
+ $qf . $from_field->name . $qf,
create_field($to_field, $options));
return $out;
}
+sub batch_alter_table {
+ my ($table, $diff_hash, $options) = @_;
+
+ my @stmts = map {
+ if (@{ $diff_hash->{$_} || [] }) {
+ my $meth = __PACKAGE__->can($_) or die __PACKAGE__ . " cant $_";
+ map { $meth->(ref $_ eq 'ARRAY' ? @$_ : $_) } @{ $diff_hash->{$_} }
+ } else { () }
+ } qw/alter_drop_constraint
+ alter_drop_index
+ drop_field
+ add_field
+ alter_field
+ rename_field
+ alter_create_index
+ alter_create_constraint
+ alter_table/;
+
+ return unless @stmts;
+ # Just zero or one stmts. return now
+ return "@stmts;" unless @stmts > 1;
+
+ # Now strip off the 'ALTER TABLE xyz' of all but the first one
+
+ my $qt = $options->{quote_table_name} || '';
+ my $table_name = $qt . $table->name . $qt;
+
+ my $first = shift @stmts;
+ my ($alter_table) = $first =~ /^(ALTER TABLE \Q$table_name\E )/;
+ my $re = qr/^$alter_table/;
+ my $padd = " " x length($alter_table);
+
+ return join( ",\n", $first, map { s/$re//; $padd . $_ } @stmts) . ';';
+}
+
+sub drop_table {
+ my ($table) = @_;
+
+ # Drop (foreign key) constraints so table drops cleanly
+ $DB::single = 1;
+ my @sql = batch_alter_table($table, { alter_drop_constraint => [ grep { $_->type eq 'FOREIGN KEY' } $table->get_constraints ] });
+
+ return join("\n", @sql, "DROP TABLE $table;");
+
+}
+
sub next_unused_name {
my $name = shift || '';
if ( !defined($used_names{$name}) ) {
my @table_defs = ();
for my $table ( $schema->get_tables ) {
- push @table_defs, create_table($table, { no_comments => $no_comments,
- add_drop_table => $add_drop_table,});
+ my @defs = create_table($table, { no_comments => $no_comments,
+ add_drop_table => $add_drop_table,});
+ my $create = shift @defs;
+ $create .= ";\n";
+ push @table_defs, $create, map( { "$_;" } @defs), "";
}
# $create .= "COMMIT;\n";
my ( @index_defs, @constraint_defs, @trigger_defs );
my @fields = $table->get_fields or die "No fields in $table_name";
+ my $temp = $options->{temporary_table} ? 'TEMPORARY ' : '';
#
# Header.
#
my $create = '';
$create .= "--\n-- Table: $table_name\n--\n" unless $no_comments;
$create .= qq[DROP TABLE $table_name;\n] if $add_drop_table;
- $create .= "CREATE TABLE $table_name (\n";
+ $create .= "CREATE ${temp}TABLE $table_name (\n";
#
# Comments
push @constraint_defs, create_constraint($c);
}
- $create .= join(",\n", map { " $_" } @field_defs ) . "\n);\n";
+ $create .= join(",\n", map { " $_" } @field_defs ) . "\n)";
- $create .= "\n";
-
- for my $def ( @index_defs, @constraint_defs, @trigger_defs ) {
- $create .= "$def\n";
- }
- return $create;
+ return ($create, @index_defs, @constraint_defs, @trigger_defs );
}
sub create_field
my ($index, $options) = @_;
my $name = $index->name;
- $name = mk_name($index->table->name, $name); # || ++$idx_name_default);
+ $name = mk_name($index->table->name, $name);
+
+ my $type = $index->type eq 'UNIQUE' ? "UNIQUE " : '';
# strip any field size qualifiers as SQLite doesn't like these
my @fields = map { s/\(\d+\)$//; $_ } $index->fields;
my $index_def =
- "CREATE INDEX $name on " . $index->table->name .
- ' (' . join( ', ', @fields ) . ');';
+ "CREATE ${type}INDEX $name ON " . $index->table->name .
+ ' (' . join( ', ', @fields ) . ')';
return $index_def;
}
my ($c, $options) = @_;
my $name = $c->name;
- $name = mk_name($c->table->name, $name); # || ++$idx_name_default);
+ $name = mk_name($c->table->name, $name);
my @fields = $c->fields;
my $c_def =
- "CREATE UNIQUE INDEX $name on " . $c->table->name .
- ' (' . join( ', ', @fields ) . ');';
+ "CREATE UNIQUE INDEX $name ON " . $c->table->name .
+ ' (' . join( ', ', @fields ) . ')';
return $c_def;
}
+sub alter_table { } # Noop
+
+sub add_field {
+ my ($field) = @_;
+
+ return sprintf("ALTER TABLE %s ADD COLUMN %s",
+ $field->table->name, create_field($field))
+}
+
+sub alter_create_index {
+ my ($index) = @_;
+
+ # This might cause name collisions
+ return create_index($index);
+}
+
+sub alter_create_constraint {
+ my ($constraint) = @_;
+
+ return create_constraint($constraint) if $constraint->type eq 'UNIQUE';
+}
+
+sub alter_drop_constraint { alter_drop_index(@_) }
+
+sub alter_drop_index {
+ my ($constraint) = @_;
+
+ return sprintf("DROP INDEX %s ON %s",
+ $constraint->name, $constraint->table->name);
+}
+
+sub batch_alter_table {
+ my ($table, $diffs) = @_;
+
+ $DB::single = 1 if $table->name eq 'deleted';
+
+ # If we have any of the following
+ #
+ # rename_field
+ # alter_field
+ # drop_field
+ #
+ # we need to do the following <http://www.sqlite.org/faq.html#q11>
+ #
+ # BEGIN TRANSACTION;
+ # CREATE TEMPORARY TABLE t1_backup(a,b);
+ # INSERT INTO t1_backup SELECT a,b FROM t1;
+ # DROP TABLE t1;
+ # CREATE TABLE t1(a,b);
+ # INSERT INTO t1 SELECT a,b FROM t1_backup;
+ # DROP TABLE t1_backup;
+ # COMMIT;
+ #
+ # Fun, eh?
+
+ if ( @{$diffs->{rename_field}} == 0 &&
+ @{$diffs->{alter_field}} == 0 &&
+ @{$diffs->{drop_field}} == 0) {
+ return join("\n", map {
+ my $meth = __PACKAGE__->can($_) or die __PACKAGE__ . " cant $_";
+ map { my $sql = $meth->(ref $_ eq 'ARRAY' ? @$_ : $_); $sql ? ("$sql;") : () } @{ $diffs->{$_} }
+
+ } grep { @{$diffs->{$_}} } keys %$diffs);
+ }
+
+
+ my @sql;
+
+ do {
+ local $table->{name} = $table->name . '_temp_alter';
+ # We only want the table - dont care about indexes on tmp table
+ my ($table_sql) = create_table($table, {no_comments => 1, temporary_table => 1});
+ push @sql,$table_sql;
+ };
+
+ push @sql, "INSERT INTO @{[$table]}_temp_alter SELECT @{[ join(', ', $table->get_fields)]} FROM @{[$table]}",
+ "DROP TABLE @{[$table]}",
+ create_table($table, { no_comments => 1 }),
+ "INSERT INTO @{[$table]} SELECT @{[ join(', ', $table->get_fields)]} FROM @{[$table]}_temp_alter",
+ "DROP TABLE @{[$table]}_temp_alter";
+
+ return join(";\n", @sql, "");
+}
+
+sub drop_table {
+ my ($table) = @_;
+ return "DROP TABLE $table;";
+}
+
1;
=pod
=head1 AUTHOR
-Ken Y. Clark E<lt>kclark@cpan.orgE<gt>.
+Ken Y. Clark C<< <kclark@cpan.orgE> >>.
+
+Diff code added by Ash Berlin C<< <ash@cpan.org> >>.
=cut
'name' => $table->name,
'order' => $table->order,
'options' => $table->options || [],
- 'comments' => $table->comments || '',
+ $table->comments ? ('comments' => $table->comments ) : (),
'constraints' => [
map { view_constraint($_) } $table->get_constraints
],
return {
'deferrable' => scalar $constraint->deferrable,
'expression' => scalar $constraint->expression,
- 'fields' => scalar $constraint->field_names,
+ 'fields' => [ map { ref $_ ? $_->name : $_ } $constraint->field_names ],
'match_type' => scalar $constraint->match_type,
'name' => scalar $constraint->name,
'options' => scalar $constraint->options,
my $field = shift;
return {
- 'order' => scalar $field->order,
- 'name' => scalar $field->name,
- 'data_type' => scalar $field->data_type,
- 'size' => [ $field->size ],
- 'default_value' => scalar $field->default_value,
- 'is_nullable' => scalar $field->is_nullable,
- 'is_primary_key' => scalar $field->is_primary_key,
- 'is_unique' => scalar $field->is_unique,
- 'comments' => $field->comments || '',
- 'extra' => { $field->extra },
+ 'order' => scalar $field->order,
+ 'name' => scalar $field->name,
+ 'data_type' => scalar $field->data_type,
+ 'size' => [ $field->size ],
+ 'default_value' => scalar $field->default_value,
+ 'is_nullable' => scalar $field->is_nullable,
+ 'is_primary_key' => scalar $field->is_primary_key,
+ 'is_unique' => scalar $field->is_unique,
+ $field->is_auto_increment ? ('is_auto_increment' => 1) : (),
+ $field->comments ? ('comments' => $field->comments) : (),
+ 'extra' => { $field->extra },
};
}
use Test::SQL::Translator qw(maybe_plan);
BEGIN {
- maybe_plan(228, "SQL::Translator::Parser::MySQL");
+ maybe_plan(235, "SQL::Translator::Parser::MySQL");
SQL::Translator::Parser::MySQL->import('parse');
}
like($proc2->sql, qr/CREATE PROCEDURE sp_update_security_acl/, "Detected procedure sp_update_security_acl");
}
+{
+ my $tr = SQL::Translator->new({parser_args => { no_default_sizes => 1 } });
+ my $data = q|create table sessions (
+ age int
+ );|;
+
+ my $val = parse($tr, $data);
+ my $schema = $tr->schema;
+ is( $schema->is_valid, 1, 'Schema is valid' );
+ my @tables = $schema->get_tables;
+ is( scalar @tables, 1, 'Right number of tables (1)' );
+ my $table = shift @tables;
+ is( $table->name, 'sessions', 'Found "sessions" table' );
+
+ my @fields = $table->get_fields;
+ is( scalar @fields, 1, 'Right number of fields (1)' );
+ my $f1 = shift @fields;
+ is( $f1->name, 'age', 'First field name is "id"' );
+ is( $f1->data_type, 'int', 'Type is "int"' );
+ is( $f1->size, 0, 'No default size' );
+
+}
+
procedures: {}
tables:
person:
- comments: ''
constraints:
- deferrable: 1
expression: ''
type: UNIQUE
fields:
age:
- comments: ''
data_type: integer
default_value: ~
extra: {}
size:
- 0
description:
- comments: ''
data_type: text
default_value: ~
extra: {}
size:
- 0
iq:
- comments: ''
data_type: tinyint
default_value: 0
extra: {}
size:
- 0
name:
- comments: ''
data_type: varchar
default_value: ~
extra: {}
size:
- 20
person_id:
- comments: ''
data_type: INTEGER
default_value: ~
extra: {}
size:
- 0
weight:
- comments: ''
data_type: double
default_value: ~
extra: {}
options: []
order: 1
pet:
- comments: ''
constraints:
- deferrable: 1
expression: ''
- fields: ''
+ fields: []
match_type: ''
name: ''
on_delete: ''
type: PRIMARY KEY
fields:
age:
- comments: ''
data_type: int
default_value: ~
extra: {}
size:
- 0
name:
- comments: ''
data_type: varchar
default_value: ~
extra: {}
size:
- 30
person_id:
- comments: ''
data_type: int
default_value: ~
extra: {}
size:
- 0
pet_id:
- comments: ''
data_type: int
default_value: ~
extra: {}
--- /dev/null
+#!/usr/bin/perl
+# vim: set ft=perl:
+
+use strict;
+use warnings;
+use SQL::Translator;
+
+use File::Spec::Functions qw(catfile updir tmpdir);
+use FindBin qw($Bin);
+use Test::More;
+use Test::Differences;
+use Test::SQL::Translator qw(maybe_plan);
+
+plan tests => 4;
+
+use_ok('SQL::Translator::Diff') or die "Cannot continue\n";
+
+my $tr = SQL::Translator->new;
+
+my ( $source_schema, $target_schema ) = map {
+ my $t = SQL::Translator->new;
+ $t->parser( 'YAML' )
+ or die $tr->error;
+ my $out = $t->translate( catfile($Bin, qw/data diff/, $_ ) )
+ or die $tr->error;
+
+ my $schema = $t->schema;
+ unless ( $schema->name ) {
+ $schema->name( $_ );
+ }
+ ($schema);
+} (qw/create1.yml create2.yml/);
+
+# Test for differences
+my $out = SQL::Translator::Diff::schema_diff( $source_schema, 'MySQL', $target_schema, 'MySQL', { no_batch_alters => 1} );
+eq_or_diff($out, <<'## END OF DIFF', "Diff as expected");
+-- Convert schema 'create1.yml' to 'create2.yml':
+
+BEGIN TRANSACTION;
+
+SET foreign_key_checks=0;
+
+
+CREATE TABLE added (
+ id integer(11)
+);
+
+
+SET foreign_key_checks=1;
+
+
+ALTER TABLE employee DROP FOREIGN KEY FK5302D47D93FE702E;
+ALTER TABLE person DROP UNIQUE UC_age_name;
+ALTER TABLE person DROP INDEX u_name;
+ALTER TABLE employee DROP COLUMN job_title;
+ALTER TABLE person ADD COLUMN is_rock_star tinyint(4) DEFAULT '1';
+ALTER TABLE person CHANGE COLUMN person_id person_id integer(11) NOT NULL auto_increment;
+ALTER TABLE person CHANGE COLUMN name name varchar(20) NOT NULL;
+ALTER TABLE person CHANGE COLUMN age age integer(11) DEFAULT '18';
+ALTER TABLE person CHANGE COLUMN iq iq integer(11) DEFAULT '0';
+ALTER TABLE person CHANGE COLUMN description physical_description text;
+ALTER TABLE person ADD UNIQUE INDEX unique_name (name);
+ALTER TABLE employee ADD CONSTRAINT FK5302D47D93FE702E_diff FOREIGN KEY (employee_id) REFERENCES person (person_id);
+ALTER TABLE person ADD UNIQUE UC_person_id (person_id);
+ALTER TABLE person ADD UNIQUE UC_age_name (age, name);
+ALTER TABLE person ENGINE=InnoDB;
+ALTER TABLE deleted DROP FOREIGN KEY fk_fake;
+DROP TABLE deleted;
+
+COMMIT;
+## END OF DIFF
+
+#die $out;
+
+$out = SQL::Translator::Diff::schema_diff($source_schema, 'MySQL', $target_schema, 'MySQL',
+ { ignore_index_names => 1,
+ ignore_constraint_names => 1
+ });
+
+eq_or_diff($out, <<'## END OF DIFF', "Diff as expected");
+-- Convert schema 'create1.yml' to 'create2.yml':
+
+BEGIN TRANSACTION;
+
+SET foreign_key_checks=0;
+
+
+CREATE TABLE added (
+ id integer(11)
+);
+
+
+SET foreign_key_checks=1;
+
+
+ALTER TABLE employee DROP COLUMN job_title;
+ALTER TABLE person DROP UNIQUE UC_age_name,
+ ADD COLUMN is_rock_star tinyint(4) DEFAULT '1',
+ CHANGE COLUMN person_id person_id integer(11) NOT NULL auto_increment,
+ CHANGE COLUMN name name varchar(20) NOT NULL,
+ CHANGE COLUMN age age integer(11) DEFAULT '18',
+ CHANGE COLUMN iq iq integer(11) DEFAULT '0',
+ CHANGE COLUMN description physical_description text,
+ ADD UNIQUE UC_person_id (person_id),
+ ADD UNIQUE UC_age_name (age, name),
+ ENGINE=InnoDB;
+ALTER TABLE deleted DROP FOREIGN KEY fk_fake;
+DROP TABLE deleted;
+
+COMMIT;
+## END OF DIFF
+
+
+# Test for sameness
+$out = SQL::Translator::Diff::schema_diff($source_schema, 'MySQL', $source_schema, 'MySQL' );
+
+eq_or_diff($out, <<'## END OF DIFF', "No differences found");
+-- Convert schema 'create1.yml' to 'create1.yml':
+
+-- No differences found
+
+## END OF DIFF
+
+=cut
--- /dev/null
+#!/usr/bin/perl
+# vim: set ft=perl:
+
+use strict;
+use warnings;
+use SQL::Translator;
+
+use File::Spec::Functions qw(catfile updir tmpdir);
+use FindBin qw($Bin);
+use Test::More;
+use Test::Differences;
+use Test::SQL::Translator qw(maybe_plan);
+
+plan tests => 4;
+
+use_ok('SQL::Translator::Diff') or die "Cannot continue\n";
+
+my $tr = SQL::Translator->new;
+
+my ( $source_schema, $target_schema ) = map {
+ my $t = SQL::Translator->new;
+ $t->parser( 'YAML' )
+ or die $tr->error;
+ my $out = $t->translate( catfile($Bin, qw/data diff/, $_ ) )
+ or die $tr->error;
+
+ my $schema = $t->schema;
+ unless ( $schema->name ) {
+ $schema->name( $_ );
+ }
+ ($schema);
+} (qw/create1.yml create2.yml/);
+
+# Test for differences
+my $out = SQL::Translator::Diff::schema_diff( $source_schema, 'SQLite', $target_schema, 'SQLite',
+ { no_batch_alters => 1,
+ ignore_missing_methods => 1,
+ output_db => 'SQLite',
+ }
+);
+eq_or_diff($out, <<'## END OF DIFF', "Diff as expected");
+-- Convert schema 'create1.yml' to 'create2.yml':
+
+BEGIN TRANSACTION;
+
+CREATE TABLE added (
+ id int(11)
+);
+
+
+DROP INDEX FK5302D47D93FE702E ON employee;
+DROP INDEX UC_age_name ON person;
+DROP INDEX u_name ON person;
+-- SQL::Translator::Producer::SQLite cant drop_field
+ALTER TABLE person ADD COLUMN is_rock_star tinyint(4) DEFAULT '1';
+-- SQL::Translator::Producer::SQLite cant alter_field
+-- SQL::Translator::Producer::SQLite cant rename_field
+CREATE UNIQUE INDEX unique_name_person ON person (name);
+CREATE UNIQUE INDEX UC_person_id_person ON person (person_id);
+CREATE UNIQUE INDEX UC_age_name_person ON person (age, name);
+DROP TABLE deleted;
+
+COMMIT;
+## END OF DIFF
+
+
+$out = SQL::Translator::Diff::schema_diff($source_schema, 'SQLite', $target_schema, 'SQLite',
+ { ignore_index_names => 1,
+ ignore_constraint_names => 1,
+ output_db => 'SQLite',
+ });
+
+eq_or_diff($out, <<'## END OF DIFF', "Diff as expected");
+-- Convert schema 'create1.yml' to 'create2.yml':
+
+BEGIN TRANSACTION;
+
+CREATE TABLE added (
+ id int(11)
+);
+
+
+
+CREATE TEMPORARY TABLE employee_temp_alter (
+ position varchar(50) NOT NULL,
+ employee_id int(11) NOT NULL,
+ PRIMARY KEY (position, employee_id)
+);
+INSERT INTO employee_temp_alter SELECT position, employee_id FROM employee;
+DROP TABLE employee;
+CREATE TABLE employee (
+ position varchar(50) NOT NULL,
+ employee_id int(11) NOT NULL,
+ PRIMARY KEY (position, employee_id)
+);
+INSERT INTO employee SELECT position, employee_id FROM employee_temp_alter;
+DROP TABLE employee_temp_alter;
+
+CREATE TEMPORARY TABLE person_temp_alter (
+ person_id INTEGER PRIMARY KEY NOT NULL,
+ name varchar(20) NOT NULL,
+ age int(11) DEFAULT '18',
+ weight double(11,2),
+ iq int(11) DEFAULT '0',
+ is_rock_star tinyint(4) DEFAULT '1',
+ physical_description text
+);
+INSERT INTO person_temp_alter SELECT person_id, name, age, weight, iq, is_rock_star, physical_description FROM person;
+DROP TABLE person;
+CREATE TABLE person (
+ person_id INTEGER PRIMARY KEY NOT NULL,
+ name varchar(20) NOT NULL,
+ age int(11) DEFAULT '18',
+ weight double(11,2),
+ iq int(11) DEFAULT '0',
+ is_rock_star tinyint(4) DEFAULT '1',
+ physical_description text
+);
+CREATE UNIQUE INDEX unique_name_person02 ON person (name);
+CREATE UNIQUE INDEX UC_person_id_person02 ON person (person_id);
+CREATE UNIQUE INDEX UC_age_name_person02 ON person (age, name);
+INSERT INTO person SELECT person_id, name, age, weight, iq, is_rock_star, physical_description FROM person_temp_alter;
+DROP TABLE person_temp_alter;
+
+DROP TABLE deleted;
+
+COMMIT;
+## END OF DIFF
+
+
+# Test for sameness
+$out = SQL::Translator::Diff::schema_diff($source_schema, 'MySQL', $source_schema, 'MySQL' );
+
+eq_or_diff($out, <<'## END OF DIFF', "No differences found");
+-- Convert schema 'create1.yml' to 'create1.yml':
+
+-- No differences found
+
+## END OF DIFF
+
# vim: set ft=perl:
use strict;
+use warnings;
+use SQL::Translator;
use File::Spec::Functions qw(catfile updir tmpdir);
use FindBin qw($Bin);
use Test::More;
-use Test::SQL::Translator qw(maybe_plan);
+use Test::Differences;
-my @script = qw(blib script sqlt-diff);
-my @create1 = qw(data sqlite create.sql);
-my @create2 = qw(data sqlite create2.sql);
+plan tests => 10;
-my $sqlt_diff = (-d "blib")
- ? catfile($Bin, updir, @script)
- : catfile($Bin, @script);
+use_ok('SQL::Translator::Diff') or die "Cannot continue\n";
-my $create1 = (-d "t")
- ? catfile($Bin, @create1)
- : catfile($Bin, "t", @create1);
+my $tr = SQL::Translator->new;
-my $create2 = (-d "t")
- ? catfile($Bin, @create2)
- : catfile($Bin, "t", @create2);
-
-BEGIN {
- maybe_plan(16, 'SQL::Translator::Parser::MySQL',
- );
-}
-
-ok(-e $sqlt_diff, 'Found sqlt-diff script');
-
-my @mysql_create1 = qw(data mysql create.sql);
-my @mysql_create2 = qw(data mysql create2.sql);
-
-my $mysql_create1 = (-d "t")
- ? catfile($Bin, @mysql_create1)
- : catfile($Bin, "t", @mysql_create1);
-
-my $mysql_create2 = (-d "t")
- ? catfile($Bin, @mysql_create2)
- : catfile($Bin, "t", @mysql_create2);
+my ( $source_schema, $target_schema ) = map {
+ my $t = SQL::Translator->new;
+ $t->parser( 'YAML' )
+ or die $tr->error;
+ my $out = $t->translate( catfile($Bin, qw/data diff /, $_ ) )
+ or die $tr->error;
+
+ my $schema = $t->schema;
+ unless ( $schema->name ) {
+ $schema->name( $_ );
+ }
+ ($schema);
+} (qw/create1.yml create2.yml/);
# Test for differences
-my @cmd = ($sqlt_diff, "$mysql_create1=MySQL", "$mysql_create2=MySQL");
-my $out = `@cmd`;
-
-unlike($out, qr/-- Target database MySQL is untested/, "Did not detect 'untested' comment");
-like($out, qr/ALTER TABLE person CHANGE COLUMN person_id/, "Detected altered 'person_id' field");
-like($out, qr/ALTER TABLE person CHANGE COLUMN iq/, "Detected altered 'iq' field");
-like($out, qr/ALTER TABLE person CHANGE COLUMN name/, "Detected altered 'name' field");
-like($out, qr/ALTER TABLE person CHANGE COLUMN age/, "Detected altered 'age' field");
-like($out, qr/ALTER TABLE person ADD COLUMN is_rock_star/,
- "Detected missing rock star field");
-like($out, qr/ALTER TABLE person ADD UNIQUE UC_person_id/,
- "Detected missing unique constraint");
-like($out, qr/ALTER TABLE person ADD UNIQUE INDEX unique_name/,
- "Detected unique index with different name");
-like($out, qr/ALTER TABLE person ENGINE=InnoDB;/,
- "Detected altered table option");
-like($out, qr/ALTER TABLE employee DROP FOREIGN KEY FK5302D47D93FE702E/,
- "Detected drop foreign key");
-like($out, qr/ALTER TABLE employee ADD CONSTRAINT FK5302D47D93FE702E_diff/,
- "Detected add constraint");
-unlike($out, qr/ALTER TABLE employee ADD PRIMARY KEY/, "Primary key looks different when it shouldn't");
-
-# Test ignore parameters
-@cmd = ($sqlt_diff, "--ignore-index-names", "--ignore-constraint-names",
- "$mysql_create1=MySQL", "$mysql_create2=MySQL");
-$out = `@cmd`;
-
-unlike($out, qr/CREATE UNIQUE INDEX unique_name/,
- "Detected unique index with different name");
-unlike($out, qr/ALTER TABLE employee ADD CONSTRAINT employee_FK5302D47D93FE702E_diff/,
- "Detected add constraint");
+my $diff = SQL::Translator::Diff->new({
+ source_schema => $source_schema,
+ source_db => 'MySQL',
+ target_schema => $target_schema,
+ target_db => 'MySQL',
+})->compute_differences;
+
+my $diff_hash = make_diff_hash();
+
+eq_or_diff($diff_hash->{employee},
+ {
+ constraints_to_create => [ 'FK5302D47D93FE702E_diff' ],
+ constraints_to_drop => [ 'FK5302D47D93FE702E' ],
+ fields_to_drop => [ 'job_title' ]
+ },
+ "Correct differences correct on employee table");
+
+eq_or_diff($diff_hash->{person},
+ {
+ constraints_to_create => [ 'UC_person_id', 'UC_age_name' ],
+ constraints_to_drop => [ 'UC_age_name' ],
+ fields_to_alter => [
+ 'person_id person_id',
+ 'name name',
+ 'age age',
+ 'iq iq',
+ ],
+ fields_to_create => [ 'is_rock_star' ],
+ fields_to_rename => [ 'description physical_description' ],
+ indexes_to_create => [ 'unique_name' ],
+ indexes_to_drop => [ 'u_name' ],
+ table_options => [ 'person' ],
+ },
+ "Correct differences correct on person table");
+
+eq_or_diff(
+ [ map { $_->name } @{$diff->tables_to_drop} ],
+ [ "deleted" ],
+ "tables_to_drop right"
+);
+
+eq_or_diff(
+ [ map { $_->name } @{$diff->tables_to_create} ],
+ [ "added" ],
+ "tables_to_create right"
+);
+
+
+$diff = SQL::Translator::Diff->new({
+ source_schema => $source_schema,
+ source_db => 'MySQL',
+ target_schema => $target_schema,
+ target_db => 'MySQL',
+ ignore_index_names => 1,
+ ignore_constraint_names => 1,
+})->compute_differences;
+
+$diff_hash = make_diff_hash();
+
+eq_or_diff($diff_hash->{employee},
+ {
+ fields_to_drop => [ 'job_title' ]
+ },
+ "Correct differences correct on employee table");
+
+eq_or_diff($diff_hash->{person},
+ {
+ constraints_to_create => [ 'UC_person_id', 'UC_age_name' ],
+ constraints_to_drop => [ 'UC_age_name' ],
+ fields_to_alter => [
+ 'person_id person_id',
+ 'name name',
+ 'age age',
+ 'iq iq',
+ ],
+ fields_to_create => [ 'is_rock_star' ],
+ fields_to_rename => [ 'description physical_description' ],
+ table_options => [ 'person' ],
+ },
+ "Correct differences correct on person table");
-# Test for sameness
-@cmd = ($sqlt_diff, "$mysql_create1=MySQL", "$mysql_create1=MySQL");
-$out = `@cmd`;
-like($out, qr/No differences found/, "Properly detected no differences");
+# Test for sameness
+$diff = SQL::Translator::Diff->new({
+ source_schema => $source_schema,
+ source_db => 'MySQL',
+ target_schema => $source_schema,
+ target_db => 'MySQL',
+})->compute_differences;
+
+$diff_hash = make_diff_hash();
+
+eq_or_diff($diff_hash, {}, "No differences");
+
+is( @{$diff->tables_to_drop}, 0, "tables_to_drop right");
+is( @{$diff->tables_to_create}, 0, "tables_to_create right");
+
+
+# Turn table_diff_hash into something we can eq_or_diff better
+sub make_diff_hash {
+
+ return {
+ map {
+ my $table = $_;
+ my $table_diff = $diff->table_diff_hash->{$table};
+
+ my %table_diffs = (
+ map {
+
+ my $opt = $table_diff->{$_};
+ @$opt ? ( $_ => [ map {
+ (ref $_||'') eq 'ARRAY' ? "@$_" :
+ (ref $_) ? $_->name
+ : "$_";
+ } @$opt
+ ] )
+ : ()
+ } keys %$table_diff
+ );
+
+ %table_diffs ? ( $table => \%table_diffs ) : ();
+ } keys %{ $diff->table_diff_hash }
+ };
+}
procedures: {}
tables:
GdayWorld:
- comments: ''
constraints: []
fields: {}
indices: []
options: []
order: 3
HelloWorld:
- comments: ''
constraints: []
fields: {}
indices: []
options: []
order: 2
PERSON:
- comments: ''
constraints: []
fields:
first_name:
- comments: ''
data_type: foovar
default_value: ~
extra: {}
procedures: {}
tables:
person:
- comments: ''
constraints: []
fields:
First_name:
- comments: ''
data_type: foovar
default_value: ~
extra: {}
fields:
- name
name: idx_unique_name
+
thing2:
name: thing2
extra:
data_type: int
order: 2
is_not_null: 1
+ indices:
+ - type: NORMAL
+ fields:
+ - id
+ name: index_1
+ - type: NORMAL
+ fields:
+ - id
+ name: index_2
constraints:
- type: PRIMARY_KEY
fields:
`id` integer,
`foo` integer,
`foo2` integer,
+ INDEX index_1 (`id`),
+ INDEX index_2 (`id`),
INDEX (`foo`),
INDEX (`foo2`),
PRIMARY KEY (`id`, `foo`),
@{$sqlt}{qw/quote_table_names quote_field_names/} = (0,0);
$out = $sqlt->translate(\$yaml_in)
- or die "Translat eerror:".$sqlt->error;
+ or die "Translate error:".$sqlt->error;
@out = $sqlt->translate(\$yaml_in)
- or die "Translat eerror:".$sqlt->error;
+ or die "Translate error:".$sqlt->error;
$mysql_out =~ s/`//g;
my @unquoted_stmts = map { s/`//g; $_} @stmts_no_drop;
eq_or_diff $out, $mysql_out, "Output looks right without quoting";
procedures: {}
tables:
Person:
- comments: ''
constraints:
- deferrable: 1
expression: ''
type: UNIQUE
fields:
created:
- comments: ''
data_type: timestamp
default_value: ~
extra: {}
size:
- 0
first_name:
- comments: ''
data_type: foovar
default_value: ~
extra: {}
size:
- 0
modified:
- comments: ''
data_type: timestamp
default_value: ~
extra: {}
use Test::More;
use Test::SQL::Translator;
use Test::Exception;
+use Test::Differences;
use Data::Dumper;
use SQL::Translator;
use SQL::Translator::Schema::Constants;
# print ">>$sql<<\n";
-is($sql, << "SQL");
+eq_or_diff($sql, << "SQL");
BEGIN TRANSACTION;
timest timestamp
);
-CREATE INDEX titleindex_Basic on Basic (title);
-CREATE UNIQUE INDEX emailuniqueindex_Basic on Basic (email);
+CREATE INDEX titleindex_Basic ON Basic (title);
+CREATE UNIQUE INDEX emailuniqueindex_Basic ON Basic (email);
DROP TABLE Another;
CREATE TABLE Another (
--- /dev/null
+---
+schema:
+ procedures: {}
+ tables:
+ deleted:
+ constraints:
+ - fields: id
+ name: 'fk_fake'
+ reference_fields:
+ - fk_id
+ reference_table: fake
+ type: FOREIGN KEY
+ - fields:
+ - id
+ name: pk_id
+ type: UNIQUE
+ fields:
+ id:
+ data_type: int
+ default_value: ~
+ extra: {}
+ is_nullable: 1
+ is_primary_key: 0
+ is_unique: 0
+ name: id
+ order: 10
+ size:
+ - 11
+ indices: []
+ name: deleted
+ options: []
+ order: 3
+ employee:
+ constraints:
+ - deferrable: 1
+ expression: ''
+ fields:
+ - employee_id
+ match_type: ''
+ name: FK5302D47D93FE702E
+ on_delete: ''
+ on_update: ''
+ options: []
+ reference_fields:
+ - person_id
+ reference_table: person
+ type: FOREIGN KEY
+ - deferrable: 1
+ expression: ''
+ fields:
+ - position
+ - employee_id
+ match_type: ''
+ name: ''
+ on_delete: ''
+ on_update: ''
+ options: []
+ reference_fields: []
+ reference_table: ''
+ type: PRIMARY KEY
+ fields:
+ employee_id:
+ data_type: int
+ default_value: ~
+ extra: {}
+ is_nullable: 0
+ is_primary_key: 1
+ is_unique: 0
+ name: employee_id
+ order: 8
+ size:
+ - 11
+ job_title:
+ data_type: varchar
+ default_value: ~
+ extra: {}
+ is_nullable: 1
+ is_primary_key: 0
+ is_unique: 0
+ name: job_title
+ order: 9
+ size:
+ - 255
+ position:
+ data_type: varchar
+ default_value: ~
+ extra: {}
+ is_nullable: 0
+ is_primary_key: 1
+ is_unique: 0
+ name: position
+ order: 7
+ size:
+ - 50
+ indices: []
+ name: employee
+ options:
+ - ENGINE: InnoDB
+ order: 2
+ person:
+ constraints:
+ - deferrable: 1
+ expression: ''
+ fields:
+ - person_id
+ match_type: ''
+ name: ''
+ on_delete: ''
+ on_update: ''
+ options: []
+ reference_fields: []
+ reference_table: ''
+ type: PRIMARY KEY
+ - deferrable: 1
+ expression: ''
+ fields:
+ - age
+ match_type: ''
+ name: UC_age_name
+ on_delete: ''
+ on_update: ''
+ options: []
+ reference_fields: []
+ reference_table: ''
+ type: UNIQUE
+ fields:
+ age:
+ data_type: int
+ default_value: ~
+ extra: {}
+ is_nullable: 1
+ is_primary_key: 0
+ is_unique: 1
+ name: age
+ order: 3
+ size:
+ - 11
+ description:
+ data_type: text
+ default_value: ~
+ extra: {}
+ is_nullable: 1
+ is_primary_key: 0
+ is_unique: 0
+ name: description
+ order: 6
+ size:
+ - 65535
+ iq:
+ data_type: tinyint
+ default_value: 0
+ extra: {}
+ is_nullable: 1
+ is_primary_key: 0
+ is_unique: 0
+ name: iq
+ order: 5
+ size:
+ - 4
+ name:
+ data_type: varchar
+ default_value: ~
+ extra: {}
+ is_nullable: 1
+ is_primary_key: 0
+ is_unique: 0
+ name: name
+ order: 2
+ size:
+ - 20
+ person_id:
+ data_type: int
+ default_value: ~
+ extra: {}
+ is_nullable: 0
+ is_primary_key: 1
+ is_unique: 0
+ name: person_id
+ order: 1
+ size:
+ - 11
+ weight:
+ data_type: double
+ default_value: ~
+ extra: {}
+ is_nullable: 1
+ is_primary_key: 0
+ is_unique: 0
+ name: weight
+ order: 4
+ size:
+ - 11
+ - 2
+ indices:
+ - fields:
+ - name
+ name: u_name
+ options: []
+ type: UNIQUE
+ name: person
+ options:
+ - ENGINE: MyISAM
+ order: 1
+ triggers: {}
+ views: {}
+translator:
+ add_drop_table: 0
+ filename: t/data/mysql/create.sql
+ no_comments: 0
+ parser_args:
+ db_password: ~
+ db_user: ~
+ dsn: ~
+ field_separator: ~
+ mysql_parser_version: ~
+ record_separator: ~
+ scan_fields: 1
+ trim_fields: 1
+ parser_type: SQL::Translator::Parser::MySQL
+ producer_args:
+ add_prefix: ~
+ add_truncate: ~
+ db_password: ~
+ db_user: ~
+ dsn: ~
+ imap_file: ~
+ imap_url: ~
+ indent: ~
+ newlines: ~
+ package_name: ~
+ prefix: ~
+ pretty: ~
+ skip: ~
+ skiplike: ~
+ title: ~
+ tt_conf: {}
+ tt_vars: {}
+ ttfile: ~
+ producer_type: SQL::Translator::Producer::YAML
+ show_warnings: 0
+ trace: 0
+ version: 0.0899_01
--- /dev/null
+---
+schema:
+ procedures: {}
+ tables:
+ added:
+ constraints: []
+ fields:
+ id:
+ data_type: int
+ default_value: ~
+ extra: {}
+ is_nullable: 1
+ is_primary_key: 0
+ is_unique: 0
+ name: id
+ order: 10
+ size:
+ - 11
+ indices: []
+ name: added
+ options: []
+ order: 3
+ employee:
+ constraints:
+ - deferrable: 1
+ expression: ''
+ fields:
+ - employee_id
+ match_type: ''
+ name: FK5302D47D93FE702E_diff
+ on_delete: ''
+ on_update: ''
+ options: []
+ reference_fields:
+ - person_id
+ reference_table: person
+ type: FOREIGN KEY
+ - deferrable: 1
+ expression: ''
+ fields:
+ - employee_id
+ - position
+ match_type: ''
+ name: ''
+ on_delete: ''
+ on_update: ''
+ options: []
+ reference_fields: []
+ reference_table: ''
+ type: PRIMARY KEY
+ fields:
+ employee_id:
+ data_type: int
+ default_value: ~
+ extra: {}
+ is_nullable: 0
+ is_primary_key: 1
+ is_unique: 0
+ name: employee_id
+ order: 9
+ size:
+ - 11
+ position:
+ data_type: varchar
+ default_value: ~
+ extra: {}
+ is_nullable: 0
+ is_primary_key: 1
+ is_unique: 0
+ name: position
+ order: 8
+ size:
+ - 50
+ indices: []
+ name: employee
+ options:
+ - ENGINE: InnoDB
+ order: 2
+ person:
+ constraints:
+ - deferrable: 1
+ expression: ''
+ fields:
+ - person_id
+ match_type: ''
+ name: ''
+ on_delete: ''
+ on_update: ''
+ options: []
+ reference_fields: []
+ reference_table: ''
+ type: PRIMARY KEY
+ - deferrable: 1
+ expression: ''
+ fields:
+ - person_id
+ match_type: ''
+ name: UC_person_id
+ on_delete: ''
+ on_update: ''
+ options: []
+ reference_fields: []
+ reference_table: ''
+ type: UNIQUE
+ - deferrable: 1
+ expression: ''
+ fields:
+ - age
+ - name
+ match_type: ''
+ name: UC_age_name
+ on_delete: ''
+ on_update: ''
+ options: []
+ reference_fields: []
+ reference_table: ''
+ type: UNIQUE
+ fields:
+ age:
+ data_type: int
+ default_value: 18
+ extra: {}
+ is_nullable: 1
+ is_primary_key: 0
+ is_unique: 1
+ name: age
+ order: 3
+ size:
+ - 11
+ iq:
+ data_type: int
+ default_value: 0
+ extra: {}
+ is_nullable: 1
+ is_primary_key: 0
+ is_unique: 0
+ name: iq
+ order: 5
+ size:
+ - 11
+ is_rock_star:
+ data_type: tinyint
+ default_value: 1
+ extra: {}
+ is_nullable: 1
+ is_primary_key: 0
+ is_unique: 0
+ name: is_rock_star
+ order: 6
+ size:
+ - 4
+ name:
+ data_type: varchar
+ default_value: ~
+ extra: {}
+ is_nullable: 0
+ is_primary_key: 0
+ is_unique: 1
+ name: name
+ order: 2
+ size:
+ - 20
+ person_id:
+ data_type: int
+ default_value: ~
+ extra: {}
+ is_auto_increment: 1
+ is_nullable: 0
+ is_primary_key: 1
+ is_unique: 1
+ name: person_id
+ order: 1
+ size:
+ - 11
+ physical_description:
+ data_type: text
+ default_value: ~
+ extra:
+ renamed_from: 'description'
+ is_nullable: 1
+ is_primary_key: 0
+ is_unique: 0
+ name: physical_description
+ order: 7
+ size:
+ - 65535
+ weight:
+ data_type: double
+ default_value: ~
+ extra: {}
+ is_nullable: 1
+ is_primary_key: 0
+ is_unique: 0
+ name: weight
+ order: 4
+ size:
+ - 11
+ - 2
+ indices:
+ - fields:
+ - name
+ name: unique_name
+ options: []
+ type: UNIQUE
+ name: person
+ options:
+ - ENGINE: InnoDB
+ order: 1
+ triggers: {}
+ views: {}
+translator:
+ add_drop_table: 0
+ filename: t/data/mysql/create2.sql
+ no_comments: 0
+ parser_args:
+ db_password: ~
+ db_user: ~
+ dsn: ~
+ field_separator: ~
+ mysql_parser_version: ~
+ record_separator: ~
+ scan_fields: 1
+ trim_fields: 1
+ parser_type: SQL::Translator::Parser::MySQL
+ producer_args:
+ add_prefix: ~
+ add_truncate: ~
+ db_password: ~
+ db_user: ~
+ dsn: ~
+ imap_file: ~
+ imap_url: ~
+ indent: ~
+ newlines: ~
+ package_name: ~
+ prefix: ~
+ pretty: ~
+ skip: ~
+ skiplike: ~
+ title: ~
+ tt_conf: {}
+ tt_vars: {}
+ ttfile: ~
+ producer_type: SQL::Translator::Producer::YAML
+ show_warnings: 0
+ trace: 0
+ version: 0.0899_01
age integer,
weight double(11,2),
iq tinyint default '0',
- description text
+ description text,
+ UNIQUE KEY UC_age_name (age)
) ENGINE=MyISAM;
create unique index u_name on person (name);
create table employee (
position varchar(50),
employee_id integer,
+ job_title varchar(255),
CONSTRAINT FK5302D47D93FE702E FOREIGN KEY (employee_id) REFERENCES person (person_id),
PRIMARY KEY (position, employee_id)
) ENGINE=InnoDB;
+create table deleted (
+ id integer
+);
weight double(11,2),
iq int default '0',
is_rock_star tinyint default '1',
- description text,
- UNIQUE KEY UC_person_id (person_id)
+ physical_description text,
+ UNIQUE KEY UC_person_id (person_id),
+ UNIQUE KEY UC_age_name (age, name)
) ENGINE=InnoDB;
create unique index unique_name on person (name);
CONSTRAINT FK5302D47D93FE702E_diff FOREIGN KEY (employee_id) REFERENCES person (person_id),
PRIMARY KEY (employee_id, position)
) ENGINE=InnoDB;
+
+create table added (
+ id integer
+);
+