Pg producer improvements by mo: ALTER TABLE / ALTER COLUMN / DROP DEFAULT
Peter Rabbitson [Fri, 24 Apr 2009 00:20:41 +0000 (00:20 +0000)]
Changes
lib/SQL/Translator/Producer/PostgreSQL.pm
t/47postgres-producer.t

diff --git a/Changes b/Changes
index 9a50894..8c4716b 100644 (file)
--- a/Changes
+++ b/Changes
@@ -4,6 +4,7 @@
 * Properly quote absolute table names in the MySQL producer
 * Added semi-colon for (DROP|CREATE) TYPE statements in the Pg producer (wreis)
 * Added CREATE VIEW subrules for mysql parser (wreis)
+* ALTER TABLE/ALTER COLUMN/DROP DEFAULT support in Pg producer (mo)
 
 # ----------------------------------------------------------
 # 0.09004 2009-02-13
index c342aae..3e4b2d4 100644 (file)
@@ -739,6 +739,12 @@ sub alter_field
                        $to_field->name) if(!$to_field->is_nullable and
                                            $from_field->is_nullable);
 
+    push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s DROP NOT NULL',
+                      $to_field->table->name,
+                      $to_field->name)
+       if ( !$from_field->is_nullable and $to_field->is_nullable );
+
+
     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',
@@ -753,13 +759,33 @@ sub alter_field
 
     my $old_default = $from_field->default_value;
     my $new_default = $to_field->default_value;
+    my $default_value = $to_field->default_value;
+    
+    # fixes bug where output like this was created:
+    # ALTER TABLE users ALTER COLUMN column SET DEFAULT ThisIsUnescaped;
+    if(ref $default_value eq "SCALAR" ) {
+        $default_value = $$default_value;
+    } elsif( defined $default_value && $to_dt =~ /^(character|text)/xsmi ) {
+        $default_value =~ s/'/''/xsmg;
+        $default_value = q(') . $default_value . q(');
+    }
+    
     push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s SET DEFAULT %s',
                        $to_field->table->name,
                        $to_field->name,
-                       $to_field->default_value)
+                       $default_value)
         if ( defined $new_default &&
              (!defined $old_default || $old_default ne $new_default) );
 
+     # fixes bug where removing the DEFAULT statement of a column
+     # would result in no change
+    
+     push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s DROP DEFAULT',
+                       $to_field->table->name,
+                       $to_field->name)
+        if ( !defined $new_default && defined $old_default );
+    
+
     return wantarray ? @out : join("\n", @out);
 }
 
@@ -838,9 +864,16 @@ sub alter_drop_constraint {
 sub alter_create_constraint {
     my ($index, $options) = @_;
     my $qt = $options->{quote_table_names} || '';
-    return $index->type eq FOREIGN_KEY ? join(q{}, @{create_constraint(@_)})
+    my ($defs, $fks) = create_constraint(@_);
+    
+    # return if there are no constraint definitions so we don't run
+    # into output like this:
+    # ALTER TABLE users ADD ;
+        
+    return unless(@{$defs} || @{$fks});
+    return $index->type eq FOREIGN_KEY ? join(q{}, @{$fks})
         : join( ' ', 'ALTER TABLE', $qt.$index->table->name.$qt,
-              'ADD', join(q{}, map { @{$_} } create_constraint(@_))
+              'ADD', join(q{}, @{$defs}, @{$fks})
           );
 }
 
index 9a5d2e9..6201091 100644 (file)
@@ -14,7 +14,7 @@ use FindBin qw/$Bin/;
 #=============================================================================
 
 BEGIN {
-    maybe_plan(13,
+    maybe_plan(17,
         'SQL::Translator::Producer::PostgreSQL',
         'Test::Differences',
     )
@@ -104,6 +104,59 @@ my $field5_sql = SQL::Translator::Producer::PostgreSQL::create_field($field5,{ p
 
 is($field5_sql, 'enum_field mytable_enum_field_type NOT NULL', 'Create real enum field works');
 
+
+
+
+my $field6 = SQL::Translator::Schema::Field->new(
+                                                  name      => 'character',
+                                                  table => $table,
+                                                  data_type => 'character',
+                                                  size => '123',
+                                                  default_value => 'foobar',
+                                                    is_auto_increment => 0,
+                                                    is_nullable => 0,
+                                                    is_foreign_key => 0,
+                                                    is_unique => 0);
+
+my $field7 = SQL::Translator::Schema::Field->new(
+                                name      => 'character',
+                                table => $table,
+                                data_type => 'character',
+                                size => '123',
+                                default_value => undef,
+                                  is_auto_increment => 0,
+                                  is_nullable => 0,
+                                  is_foreign_key => 0,
+                                  is_unique => 0);
+
+$alter_field = SQL::Translator::Producer::PostgreSQL::alter_field($field6,
+                                                                $field7);
+
+is($alter_field, q(ALTER TABLE mytable ALTER COLUMN character DROP DEFAULT), 'DROP DEFAULT');
+
+$field7->default_value(q(foo'bar'));
+
+$alter_field = SQL::Translator::Producer::PostgreSQL::alter_field($field6,
+                                                                $field7);
+
+is($alter_field, q(ALTER TABLE mytable ALTER COLUMN character SET DEFAULT 'foo''bar'''), 'DEFAULT with escaping');
+
+$field7->default_value(\q(foobar));
+
+$alter_field = SQL::Translator::Producer::PostgreSQL::alter_field($field6,
+                                                                $field7);
+
+is($alter_field, q(ALTER TABLE mytable ALTER COLUMN character SET DEFAULT foobar), 'DEFAULT unescaped if scalarref');
+
+$field7->is_nullable(1);
+$field7->default_value(q(foobar));
+
+$alter_field = SQL::Translator::Producer::PostgreSQL::alter_field($field6,
+                                                                $field7);
+
+is($alter_field, q(ALTER TABLE mytable ALTER COLUMN character DROP NOT NULL), 'DROP NOT NULL');
+
+
 {
     # let's test default values! -- rjbs, 2008-09-30
     my %field = (