Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We鈥檒l occasionally send you account related emails.

Already on GitHub? Sign in to your account

Fixed a terrible diff issue case of PostgreSQL #91

Closed
wants to merge 5 commits into from
Closed
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
25 changes: 21 additions & 4 deletions lib/SQL/Translator/Parser/DBI/PostgreSQL.pm
Original file line number Diff line number Diff line change
Expand Up @@ -37,14 +37,31 @@ sub parse {
my $schema = $tr->schema;

my $column_select = $dbh->prepare(
"SELECT a.attname, format_type(t.oid, a.atttypmod) as typname, a.attnum,
a.atttypmod as length, a.attnotnull, a.atthasdef, ad.adsrc,
"SELECT a.attname, case
when t.oid = any ('{int,int8,int2}'::regtype[])
and ad.adsrc = 'nextval('''
|| (pg_get_serial_sequence (a.attrelid::regclass::text, a.attname))::regclass
|| '''::regclass)'
then case t.oid
when 'int8'::regtype then 'bigserial'
when 'int'::regtype then 'serial'
when 'int2'::regtype then 'smallserial'
end
else format_type(t.oid, a.atttypmod)
end as typname, a.attnum,
case typname
when 'varchar' then a.atttypmod - 4
when 'bpchar' then a.atttypmod - 4
when 'numeric' then (a.atttypmod - 4) / 65536
when 'decimal' then (a.atttypmod - 4) / 65536
else a.atttypmod
end as length, a.attnotnull, a.atthasdef, ad.adsrc,
d.description
FROM pg_type t, pg_attribute a
LEFT JOIN pg_attrdef ad ON (ad.adrelid = a.attrelid AND a.attnum = ad.adnum)
LEFT JOIN pg_description d ON (a.attrelid=d.objoid AND a.attnum=d.objsubid)
WHERE a.attrelid=? AND attnum>0
AND a.atttypid=t.oid
WHERE a.attrelid = ? AND attnum > 0
AND a.atttypid = t.oid
ORDER BY a.attnum"
);

Expand Down
9 changes: 9 additions & 0 deletions lib/SQL/Translator/Parser/PostgreSQL.pm
Original file line number Diff line number Diff line change
Expand Up @@ -589,6 +589,15 @@ pg_data_type :
};
}
|
/(smallserial|serial2)/i
{
$return = {
type => 'integer',
size => 5,
is_auto_increment => 1
};
}
|
/(bit varying|varbit)/i
{
$return = { type => 'varbit' };
Expand Down
85 changes: 58 additions & 27 deletions lib/SQL/Translator/Producer/PostgreSQL.pm
Original file line number Diff line number Diff line change
Expand Up @@ -651,10 +651,11 @@ sub convert_datatype
$data_type = 'character varying';
}
elsif ( $field->is_auto_increment ) {
if ( (defined $size[0] && $size[0] > 11) or $data_type eq 'bigint' ) {
if (11 < $size[0] || $data_type eq 'bigint') {
$data_type = 'bigserial';
}
else {
} elsif (0 < $size[0] && $size[0] < 5 || $data_type eq 'smallint') {
$data_type = 'smallserial';
} else {
$data_type = 'serial';
}
undef @size;
Expand All @@ -672,19 +673,10 @@ sub convert_datatype
}

if ( $data_type eq 'integer' ) {
if ( defined $size[0] && $size[0] > 0) {
if ( $size[0] > 10 ) {
$data_type = 'bigint';
}
elsif ( $size[0] < 5 ) {
$data_type = 'smallint';
}
else {
$data_type = 'integer';
}
}
else {
$data_type = 'integer';
if (10 < $size[0]) {
$data_type = 'bigint';
} elsif (0 < $size[0] && $size[0] <= 5) {
$data_type = 'smallint';
}
}

Expand All @@ -697,10 +689,19 @@ sub convert_datatype
@size = ();
}

if (defined $size[0] && $size[0] > 0 && $data_type =~ /^time/i ) {
$data_type =~ s/^(time.*?)( with.*)?$/$1($size[0])/;
$data_type .= $2 if(defined $2);
if ( $data_type =~ /^(time(?:[a-z]+)?)/i ) {
my $time_type = $1;
if (defined $size[0] && 0 < $size[0]) {
$time_type .= "($size[0])";
}
if ($data_type =~ /((?:with|without)? time zone)$/i) {
$time_type .= " $1";
} else {
$time_type .= ' without time zone';
}
$data_type = $time_type;
} elsif ( defined $size[0] && $size[0] > 0 ) {
$data_type =~ s/\([0-9]+\)$//; # Bug fix for type(size)(size)
$data_type .= '(' . join( ',', @size ) . ')';
}
if($array)
Expand Down Expand Up @@ -768,14 +769,44 @@ sub alter_field

my $from_dt = convert_datatype($from_field);
my $to_dt = convert_datatype($to_field);
push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s TYPE %s',
map($generator->quote($_),
$to_field->table->name,
$to_field->name
),
$to_dt,
)
if($to_dt ne $from_dt);

if ($to_dt ne $from_dt) {
if ($to_dt =~ /(big|small)?serial/) {
my $table_name = $to_field->table->name;
my $field_name = $to_field->name;

push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s TYPE %s',
map($generator->quote($_),
$to_field->table->name,
$to_field->name),
$to_dt eq 'serial' ? 'integer' : "$1int"
);
my $seq_name = "${table_name}_${field_name}_seq";
my $by_name = "${table_name}.${field_name}";
my @args = map(
$generator->quote($_),
$seq_name,
$table_name,
$field_name,
$seq_name,
$by_name
);
push @out, sprintf(<<"__SERIAL__", @args);
CREATE SEQUENCE %s;

ALTER TABLE %s ALTER COLUMN %s SET DEFAULT nextval('${table_name}_${field_name}_seq');

ALTER SEQUENCE %s OWNED BY %s;

__SERIAL__
} else {
push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s TYPE %s',
map($generator->quote($_),
$to_field->table->name,
$to_field->name),
$to_dt);
}
}

my $old_default = $from_field->default_value;
my $new_default = $to_field->default_value;
Expand Down
16 changes: 14 additions & 2 deletions t/30sqlt-new-diff-pgsql.t
Original file line number Diff line number Diff line change
Expand Up @@ -72,7 +72,13 @@ DROP INDEX "u_name";

ALTER TABLE "person" ADD COLUMN "is_rock_star" smallint DEFAULT 1;

ALTER TABLE "person" ALTER COLUMN "person_id" TYPE serial;
ALTER TABLE "person" ALTER COLUMN "person_id" TYPE integer;

CREATE SEQUENCE "person_person_id_seq";

ALTER TABLE "person" ALTER COLUMN "person_id" SET DEFAULT nextval('person_person_id_seq');

ALTER SEQUENCE "person_person_id_seq" OWNED BY "person"."person_id";

ALTER TABLE "person" ALTER COLUMN "name" SET NOT NULL;

Expand Down Expand Up @@ -127,7 +133,13 @@ ALTER TABLE person DROP CONSTRAINT UC_age_name;

ALTER TABLE person ADD COLUMN is_rock_star smallint DEFAULT 1;

ALTER TABLE person ALTER COLUMN person_id TYPE serial;
ALTER TABLE person ALTER COLUMN person_id TYPE integer;

CREATE SEQUENCE person_person_id_seq;

ALTER TABLE person ALTER COLUMN person_id SET DEFAULT nextval('person_person_id_seq');

ALTER SEQUENCE person_person_id_seq OWNED BY person.person_id;

ALTER TABLE person ALTER COLUMN name SET NOT NULL;

Expand Down
2 changes: 1 addition & 1 deletion t/46xml-to-pg.t
Original file line number Diff line number Diff line change
Expand Up @@ -45,7 +45,7 @@ CREATE TABLE "Basic" (
-- Hello emptytagdef
"emptytagdef" character varying DEFAULT '',
"another_id" integer DEFAULT 2,
"timest" timestamp,
"timest" timestamp without time zone,
PRIMARY KEY ("id"),
CONSTRAINT "emailuniqueindex" UNIQUE ("email"),
CONSTRAINT "very_long_index_name_on_title_field_which_should_be_truncated_for_various_rdbms" UNIQUE ("title")
Expand Down
4 changes: 2 additions & 2 deletions t/47postgres-producer.t
Original file line number Diff line number Diff line change
Expand Up @@ -292,7 +292,7 @@ my $field3 = SQL::Translator::Schema::Field->new( name => 'time_field',

my $field3_sql = SQL::Translator::Producer::PostgreSQL::create_field($field3);

is($field3_sql, 'time_field time NOT NULL', 'Create time field works');
is($field3_sql, 'time_field time without time zone NOT NULL', 'Create time field works');

my $field3_datetime_with_TZ = SQL::Translator::Schema::Field->new(
name => 'datetime_with_TZ',
Expand Down Expand Up @@ -496,7 +496,7 @@ my $field12 = SQL::Translator::Schema::Field->new( name => 'time_field',

my $field12_sql = SQL::Translator::Producer::PostgreSQL::create_field($field12,{ postgres_version => 8.3 });

is($field12_sql, 'time_field timestamp NOT NULL', 'time with precision');
is($field12_sql, 'time_field timestamp without time zone NOT NULL', 'time with precision');

my $field13 = SQL::Translator::Schema::Field->new( name => 'enum_field_with_type_name',
table => $table,
Expand Down
5 changes: 2 additions & 3 deletions t/66-postgres-dbi-parser.t
Original file line number Diff line number Diff line change
Expand Up @@ -91,7 +91,7 @@ is( scalar @t1_fields, 4, '4 fields in sqlt_test1' );

my $f1 = shift @t1_fields;
is( $f1->name, 'f_serial', 'First field is "f_serial"' );
is( $f1->data_type, 'integer', 'Field is an integer' );
is( $f1->data_type, 'serial', 'Field is a serial' );
is( $f1->is_nullable, 0, 'Field cannot be null' );
is( $f1->default_value, "nextval('sqlt_test1_f_serial_seq'::regclass)", 'Default value is nextval()' );
is( $f1->is_primary_key, 1, 'Field is PK' );
Expand All @@ -102,8 +102,7 @@ my $f2 = shift @t1_fields;
is( $f2->name, 'f_varchar', 'Second field is "f_varchar"' );
is( $f2->data_type, 'character varying(255)', 'Field is a character varying(255)' );
is( $f2->is_nullable, 1, 'Field can be null' );
#FIXME: should not be 255?
is( $f2->size, 259, 'Size is "259"' );
is( $f2->size, 255, 'Size is "255"' );
is( $f2->default_value, undef, 'Default value is undefined' );
is( $f2->is_primary_key, 0, 'Field is not PK' );
is( $f2->is_auto_increment, 0, 'Field is not auto increment' );
Expand Down