diff --git a/.gitignore b/.gitignore index afea502a..0766a715 100644 --- a/.gitignore +++ b/.gitignore @@ -52,6 +52,9 @@ Session.vim # JetBrains .idea/ +# vscode +.vscode/ + # Environments .env .venv diff --git a/setup.cfg b/setup.cfg index 9d6861e7..36202f34 100644 --- a/setup.cfg +++ b/setup.cfg @@ -6,3 +6,7 @@ exclude = .venv build docs/conf.py +# E501: line too long in comments +# F811: redefinition of unused (to support different dialect compiles) +per-file-ignores = + sqlalchemy_utils/view.py:E501,F811 diff --git a/sqlalchemy_utils/view.py b/sqlalchemy_utils/view.py index 7fe4f043..347fe3c9 100644 --- a/sqlalchemy_utils/view.py +++ b/sqlalchemy_utils/view.py @@ -6,21 +6,149 @@ class CreateView(DDLElement): - def __init__(self, name, selectable, materialized=False): + def __init__( + self, + name, + selectable, + materialized=False, + if_not_exists=False, + or_replace=False, + ): self.name = name self.selectable = selectable self.materialized = materialized + self.if_not_exists = if_not_exists + self.or_replace = or_replace @compiler.compiles(CreateView) def compile_create_materialized_view(element, compiler, **kw): + return 'CREATE {}{}VIEW {}{} AS {}'.format( + 'OR REPLACE ' if element.or_replace else '', + 'MATERIALIZED ' if element.materialized else '', + 'IF NOT EXISTS ' if element.if_not_exists else '', + compiler.dialect.identifier_preparer.quote(element.name), + compiler.sql_compiler.process(element.selectable, literal_binds=True), + ) + + +@compiler.compiles(CreateView, 'postgresql') +def compile_create_materialized_view_postgresql(element, compiler, **kw): + """ + CREATE [ OR REPLACE ] [ TEMP | TEMPORARY ] [ RECURSIVE ] VIEW name [ ( column_name [, ...] ) ] + [ WITH ( view_option_name [= view_option_value] [, ... ] ) ] + AS query + [ WITH [ CASCADED | LOCAL ] CHECK OPTION ] + + CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] table_name + [ (column_name [, ...] ) ] + [ USING method ] + [ WITH ( storage_parameter [= value] [, ... ] ) ] + [ TABLESPACE tablespace_name ] + AS query + [ WITH [ NO ] DATA ] + + see https://www.postgresql.org/docs/current/sql-createview.html + see https://www.postgresql.org/docs/current/sql-creatematerializedview.html + """ + return 'CREATE {}{}VIEW {}{} AS {}'.format( + 'OR REPLACE ' if not element.materialized and element.or_replace else '', + 'MATERIALIZED ' if element.materialized else '', + 'IF NOT EXISTS ' if element.materialized and element.if_not_exists else '', + compiler.dialect.identifier_preparer.quote(element.name), + compiler.sql_compiler.process(element.selectable, literal_binds=True), + ) + + +@compiler.compiles(CreateView, 'mysql') +def compile_create_materialized_view_mysql(element, compiler, **kw): + """ + CREATE + [OR REPLACE] + [ALGORITHM = {UNDEFINED | MERGE | TEMPTABLE}] + [DEFINER = user] + [SQL SECURITY { DEFINER | INVOKER }] + VIEW view_name [(column_list)] + AS select_statement + [WITH [CASCADED | LOCAL] CHECK OPTION] + + See https://dev.mysql.com/doc/refman/8.0/en/create-view.html + NOTE mysql does not support materialized view + """ + if element.materialized: + raise ValueError('mysql does not support materialized view!') return 'CREATE {}VIEW {} AS {}'.format( + 'OR REPLACE ' if element.or_replace else '', + compiler.dialect.identifier_preparer.quote(element.name), + compiler.sql_compiler.process(element.selectable, literal_binds=True), + ) + + +@compiler.compiles(CreateView, 'mssql') +def compile_create_materialized_view_mssql(element, compiler, **kw): + """ + CREATE [ OR ALTER ] VIEW [ schema_name . ] view_name [ (column [ ,...n ] ) ] + [ WITH [ ,...n ] ] + AS select_statement + [ WITH CHECK OPTION ] + [ ; ] + + CREATE MATERIALIZED VIEW [ schema_name. ] materialized_view_name + WITH ( + + ) + AS + [;] + + see https://docs.microsoft.com/en-us/sql/t-sql/statements/create-view-transact-sql?view=sql-server-ver15 + see https://docs.microsoft.com/en-us/sql/t-sql/statements/create-materialized-view-as-select-transact-sql?view=azure-sqldw-latest&viewFallbackFrom=sql-server-ver15 + """ + return 'CREATE {}{}VIEW {} AS {}'.format( + 'OR ALTER ' if not element.materialized and element.or_replace else '', 'MATERIALIZED ' if element.materialized else '', compiler.dialect.identifier_preparer.quote(element.name), compiler.sql_compiler.process(element.selectable, literal_binds=True), ) +@compiler.compiles(CreateView, 'snowflake') +def compile_create_materialized_view_snowflake(element, compiler, **kw): + """ + CREATE [ OR REPLACE ] [ SECURE ] [ RECURSIVE ] VIEW [ IF NOT EXISTS ] + [ ( ) ] + [ [ WITH ] MASKING POLICY [ USING ( , , ... ) ] + [ WITH ] TAG ( = '' [ , = '' , ... ] ) ] + [ , [ ... ] ] + [ [ WITH ] ROW ACCESS POLICY ON ( [ , ... ] ) ] + [ WITH ] TAG ( = '' [ , = '' , ... ] ) ] + [ COPY GRANTS ] + [ COMMENT = '' ] + AS + + CREATE [ OR REPLACE ] [ SECURE ] MATERIALIZED VIEW [ IF NOT EXISTS ] + [ COPY GRANTS ] + ( ) + [ [ WITH ] MASKING POLICY [ USING ( , , ... ) ] + [ WITH ] TAG ( = '' [ , = '' , ... ] ) ] + [ , [ ... ] ] + [ [ WITH ] ROW ACCESS POLICY ON ( [ , ... ] ) ] + [ WITH ] TAG ( = '' [ , = '' , ... ] ) ] + [ COMMENT = '' ] + [ CLUSTER BY ( [, ... ] ) ] + AS + + see https://docs.snowflake.com/en/sql-reference/sql/create-view.html + see https://docs.snowflake.com/en/sql-reference/sql/create-materialized-view.html + """ + return 'CREATE {}{}VIEW {}{} AS {}'.format( + 'OR REPLACE ' if element.or_replace else '', + 'MATERIALIZED ' if element.materialized else '', + 'IF NOT EXISTS ' if element.if_not_exists else '', + compiler.dialect.identifier_preparer.quote(element.name), + compiler.sql_compiler.process(element.selectable, literal_binds=True), + ) + + class DropView(DDLElement): def __init__(self, name, materialized=False, cascade=True): self.name = name @@ -33,17 +161,12 @@ def compile_drop_materialized_view(element, compiler, **kw): return 'DROP {}VIEW IF EXISTS {} {}'.format( 'MATERIALIZED ' if element.materialized else '', compiler.dialect.identifier_preparer.quote(element.name), - 'CASCADE' if element.cascade else '' + 'CASCADE' if element.cascade else '', ) def create_table_from_selectable( - name, - selectable, - indexes=None, - metadata=None, - aliases=None, - **kwargs + name, selectable, indexes=None, metadata=None, aliases=None, **kwargs ): if indexes is None: indexes = [] @@ -53,10 +176,7 @@ def create_table_from_selectable( aliases = {} args = [ sa.Column( - c.name, - c.type, - key=aliases.get(c.name, c.name), - primary_key=c.primary_key + c.name, c.type, key=aliases.get(c.name, c.name), primary_key=c.primary_key ) for c in get_columns(selectable) ] + indexes @@ -74,9 +194,11 @@ def create_materialized_view( selectable, metadata, indexes=None, - aliases=None + aliases=None, + if_not_exists=False, + or_replace=False, ): - """ Create a view on a given metadata + """Create a view on a given metadata :param name: The name of the view to create. :param selectable: An SQLAlchemy selectable e.g. a select() statement. @@ -87,6 +209,12 @@ def create_materialized_view( :param aliases: An optional dictionary containing with keys as column names and values as column aliases. + :param if_not_exists: + An optional flag to indicate whether to use the + ``CREATE MATERIALIZED VIEW IF NOT EXISTS`` statement. + :param or_replace: + An optional flag to indicate whether to use the + ``CREATE OR REPLACE MATERIALIZED VIEW`` statement. Same as for ``create_view`` except that a ``CREATE MATERIALIZED VIEW`` statement is emitted instead of a ``CREATE VIEW``. @@ -97,13 +225,19 @@ def create_materialized_view( selectable=selectable, indexes=indexes, metadata=None, - aliases=aliases + aliases=aliases, ) sa.event.listen( metadata, 'after_create', - CreateView(name, selectable, materialized=True) + CreateView( + name, + selectable, + materialized=True, + if_not_exists=if_not_exists, + or_replace=or_replace, + ), ) @sa.event.listens_for(metadata, 'after_create') @@ -111,11 +245,7 @@ def create_indexes(target, connection, **kw): for idx in table.indexes: idx.create(connection) - sa.event.listen( - metadata, - 'before_drop', - DropView(name, materialized=True) - ) + sa.event.listen(metadata, 'before_drop', DropView(name, materialized=True)) return table @@ -123,15 +253,23 @@ def create_view( name, selectable, metadata, - cascade_on_drop=True + cascade_on_drop=True, + if_not_exists=False, + or_replace=False, ): - """ Create a view on a given metadata + """Create a view on a given metadata :param name: The name of the view to create. :param selectable: An SQLAlchemy selectable e.g. a select() statement. :param metadata: An SQLAlchemy Metadata instance that stores the features of the database being described. + :param if_not_exists: + An optional flag to indicate whether to use the + ``CREATE VIEW IF NOT EXISTS`` statement. + :param or_replace: + An optional flag to indicate whether to use the + ``CREATE OR REPLACE VIEW`` statement. (``OR ALTER`` will be used for mysql) The process for creating a view is similar to the standard way that a table is constructed, except that a selectable is provided instead of @@ -156,28 +294,28 @@ def create_view( """ table = create_table_from_selectable( - name=name, - selectable=selectable, - metadata=None + name=name, selectable=selectable, metadata=None ) - sa.event.listen(metadata, 'after_create', CreateView(name, selectable)) + sa.event.listen( + metadata, + 'after_create', + CreateView( + name, selectable, if_not_exists=if_not_exists, or_replace=or_replace + ), + ) @sa.event.listens_for(metadata, 'after_create') def create_indexes(target, connection, **kw): for idx in table.indexes: idx.create(connection) - sa.event.listen( - metadata, - 'before_drop', - DropView(name, cascade=cascade_on_drop) - ) + sa.event.listen(metadata, 'before_drop', DropView(name, cascade=cascade_on_drop)) return table def refresh_materialized_view(session, name, concurrently=False): - """ Refreshes an already existing materialized view + """Refreshes an already existing materialized view :param session: An SQLAlchemy Session instance. :param name: The name of the materialized view to refresh. @@ -191,6 +329,6 @@ def refresh_materialized_view(session, name, concurrently=False): session.execute( 'REFRESH MATERIALIZED VIEW {}{}'.format( 'CONCURRENTLY ' if concurrently else '', - session.bind.engine.dialect.identifier_preparer.quote(name) + session.bind.engine.dialect.identifier_preparer.quote(name), ) ) diff --git a/tests/test_views.py b/tests/test_views.py index 4bd8b0a5..482c11f4 100644 --- a/tests/test_views.py +++ b/tests/test_views.py @@ -6,6 +6,7 @@ create_view, refresh_materialized_view ) +from sqlalchemy_utils.view import CreateView @pytest.fixture @@ -74,6 +75,28 @@ class ArticleView(Base): return ArticleView +@pytest.fixture +def Booking(Base, Person): + class Booking(Base): + __tablename__ = "booking" + id = sa.Column(sa.Integer, primary_key=True) + name = sa.Column(sa.String) + person_id = sa.Column(sa.Integer, sa.ForeignKey(Person.id)) + person = sa.orm.relationship(Person) + + return Booking + + +@pytest.fixture +def Person(Base): + class Person(Base): + __tablename__ = "person" + id = sa.Column(sa.Integer, primary_key=True) + name = sa.Column(sa.String) + + return Person + + @pytest.fixture def init_models(ArticleMV, ArticleView): pass @@ -134,6 +157,31 @@ def life_cycle( __table__.create(engine) __table__.drop(engine) + def create_view( + self, + Booking, + Person, + if_not_exists=None, + or_replace=None, + materialized=None, + ): + return CreateView( + name="booking-view", + selectable=sa.select( + [ + Booking.id, + Booking.name, + Person.id.label('person_id'), + Person.name.label('person_name'), + ], + from_obj=(Booking.__table__.join( + Person, Booking.person_id == Person.id)), + ), + materialized=materialized, + if_not_exists=if_not_exists, + or_replace=or_replace, + ) + class SupportsCascade(TrivialViewTestCases): def test_life_cycle_cascade( @@ -166,8 +214,102 @@ def test_life_cycle_no_cascade( self.life_cycle(engine, Base.metadata, User.id, cascade_on_drop=False) +class SupportCreateViewIfNotExists(TrivialViewTestCases): + def test_create_view_if_not_exists(self, engine, Booking, Person): + view = self.create_view(Booking, Person, if_not_exists=True) + expected = ( + 'CREATE VIEW IF NOT EXISTS "booking-view" AS SELECT booking.id, ' + 'booking.name, person.id AS person_id, person.name AS person_name ' + '\nFROM booking JOIN person ON booking.person_id = person.id' + ) + assert str(view.compile(dialect=engine.dialect)) == expected + + +class SupportCreateOrReplaceView(TrivialViewTestCases): + def test_create_or_replace_view(self, engine, Booking, Person): + view = self.create_view(Booking, Person, or_replace=True) + expected = ( + 'CREATE OR REPLACE VIEW "booking-view" AS SELECT booking.id, ' + 'booking.name, person.id AS person_id, person.name AS person_name ' + '\nFROM booking JOIN person ON booking.person_id = person.id' + ) + assert str(view.compile(dialect=engine.dialect)) == expected + + +class SupportCreateMaterializedViewIfNotExists(TrivialViewTestCases): + def test_create_materialized_view_if_not_exists( + self, engine, Booking, Person, + ): + view = self.create_view( + Booking, Person, if_not_exists=True, materialized=True) + expected = ( + 'CREATE MATERIALIZED VIEW IF NOT EXISTS "booking-view" AS SELECT ' + 'booking.id, booking.name, person.id AS person_id, ' + 'person.name AS person_name \n' + 'FROM booking JOIN person ON booking.person_id = person.id' + ) + assert str(view.compile(dialect=engine.dialect)) == expected + + +class SupportCreateOrReplaceMaterializedView(TrivialViewTestCases): + def test_create_or_replace_materialized_view( + self, engine, Booking, Person, + ): + view = self.create_view( + Booking, Person, or_replace=True, materialized=True) + expected = ( + 'CREATE OR REPLACE MATERIALIZED VIEW "booking-view" AS SELECT ' + 'booking.id, booking.name, person.id AS person_id, ' + 'person.name AS person_name \n' + 'FROM booking JOIN person ON booking.person_id = person.id' + ) + assert str(view.compile(dialect=engine.dialect)) == expected + + +class DoesNotSupportCreateViewIfNotExists(TrivialViewTestCases): + def test_create_view_if_not_exists(self, engine, Booking, Person): + view = self.create_view(Booking, Person, if_not_exists=True) + expected = ( + 'CREATE VIEW "booking-view" AS SELECT booking.id, booking.name, ' + 'person.id AS person_id, person.name AS person_name \n' + 'FROM booking JOIN person ON booking.person_id = person.id' + ) + assert str(view.compile(dialect=engine.dialect)) == expected + + +class DoesNotSupportCreateOrReplaceMaterializedView(TrivialViewTestCases): + def test_create_or_replace_materialized_view( + self, engine, Booking, Person, + ): + view = self.create_view( + Booking, Person, or_replace=True, materialized=True) + expected = ( + 'CREATE MATERIALIZED VIEW "booking-view" AS SELECT booking.id, ' + 'booking.name, ' + 'person.id AS person_id, person.name AS person_name \n' + 'FROM booking JOIN person ON booking.person_id = person.id' + ) + assert str(view.compile(dialect=engine.dialect)) == expected + + +class TestGenericDbTrivialView( + SupportCreateViewIfNotExists, + SupportCreateOrReplaceView, + SupportCreateMaterializedViewIfNotExists, + SupportCreateOrReplaceMaterializedView +): + ... + + @pytest.mark.usefixtures('postgresql_dsn') -class TestPostgresTrivialView(SupportsCascade, SupportsNoCascade): +class TestPostgresTrivialView( + SupportsCascade, + SupportsNoCascade, + SupportCreateOrReplaceView, + SupportCreateMaterializedViewIfNotExists, + DoesNotSupportCreateViewIfNotExists, + DoesNotSupportCreateOrReplaceMaterializedView, +): pass