diff --git a/Changes b/Changes index 7669e1d3..4ae29131 100644 --- a/Changes +++ b/Changes @@ -2,6 +2,7 @@ Changes for SQL::Translator * sqlt-diff: Change producer_args to sqlt_args for better self-documentation * Support INCLUDE on indices for Pg (producer + parser) + * Postgres producer now supports materialized views via $extra->{materialized} 1.62 - 2020-09-14 * Update Pg support to allow version 12 (still supporting back to 7.4) diff --git a/lib/SQL/Translator/Parser/PostgreSQL.pm b/lib/SQL/Translator/Parser/PostgreSQL.pm index 5318a6f1..409bd0ad 100644 --- a/lib/SQL/Translator/Parser/PostgreSQL.pm +++ b/lib/SQL/Translator/Parser/PostgreSQL.pm @@ -266,6 +266,19 @@ create : CREATE or_replace(?) temporary(?) VIEW view_id view_fields(?) /AS/i vie } } +create: CREATE /MATERIALIZED VIEW/i if_not_exists(?) view_id view_fields(?) /AS/i view_target ';' + { + push @views, { + schema_name => $item{view_id}{schema_name}, + view_name => $item{view_id}{view_name}, + sql => $item{view_target}, + fields => $item[5], + extra => { materialized => 1 } + } + } + +if_not_exists : /IF NOT EXISTS/i + trigger_name : NAME trigger_scope : /FOR/i /EACH/i /(ROW|STATEMENT)/i { $return = lc $1 } diff --git a/lib/SQL/Translator/Producer/PostgreSQL.pm b/lib/SQL/Translator/Producer/PostgreSQL.pm index 9f37b40b..79d7c443 100644 --- a/lib/SQL/Translator/Producer/PostgreSQL.pm +++ b/lib/SQL/Translator/Producer/PostgreSQL.pm @@ -19,6 +19,9 @@ Does not yet support PostGIS Views. =head2 Producer Args +You can change the global behavior of the producer by passing the following options to the +C attribute of C. + =over 4 =item postgres_version @@ -50,6 +53,52 @@ instead of this =back +=head2 Extra args + +Various schema types support various options via the C attribute. + +=over 2 + +=item Tables + +=over 2 + +=item temporary + +Produces a temporary table. + +=back + +=item Views + +=over 2 + +=item temporary + +Produces a temporary view. + +=item materialized + +Produces a materialized view. + +=back + +=item Fields + +=over 2 + +=item list, custom_type_name + +For enum types, list is the list of valid values, and custom_type_name is the name that +the type should have. Defaults to $table_$field_type. + +=item geometry_type, srid, dimensions, geography_type + +Fields for use with PostGIS types. + +=back + +=back =cut @@ -425,6 +474,7 @@ sub create_view { my $extra = $view->extra; $create .= " TEMPORARY" if exists($extra->{temporary}) && $extra->{temporary}; + $create .= " MATERIALIZED" if exists($extra->{materialized}) && $extra->{materialized}; $create .= " VIEW " . $generator->quote($view_name); if ( my @fields = $view->fields ) { diff --git a/t/14postgres-parser.t b/t/14postgres-parser.t index 30a0d683..9228861f 100644 --- a/t/14postgres-parser.t +++ b/t/14postgres-parser.t @@ -114,6 +114,12 @@ baz $foo$, alter table t_test1 owner to foo; + -- we should tests views if they're supported, right? + + create or replace temporary view fez (foo, bar) as select foo, count(bar) as bar from baz group by foo; + + create materialized view if not exists baa (black, sheep) as select foo black, bar sheep from baz; + commit; }; diff --git a/t/47postgres-producer.t b/t/47postgres-producer.t index 09434f4f..44a14fb5 100644 --- a/t/47postgres-producer.t +++ b/t/47postgres-producer.t @@ -714,4 +714,20 @@ CREATE VIEW view_foo ( id, name ) AS is($drop_view_9_1_produced, $drop_view_9_1_expected, "My DROP VIEW statement for 9.1 is correct"); +my $mat_view = SQL::Translator::Schema::View->new( + name => 'view_foo', + fields => [qw/id name/], + sql => 'SELECT id, name FROM thing', + extra => { + materialized => 1 + } +); + +my $mat_view_sql = SQL::Translator::Producer::PostgreSQL::create_view($mat_view, { no_comments => 1 }); + +my $mat_view_sql_expected = "CREATE MATERIALIZED VIEW view_foo ( id, name ) AS + SELECT id, name FROM thing +"; + +is($mat_view_sql, $mat_view_sql_expected, 'correct "MATERIALIZED VIEW" SQL'); done_testing;