├── README.md ├── LICENSE ├── flask-sqlalchemy-example ├── models.py └── materialized_view_factory.py └── materialized_view_factory.py /README.md: -------------------------------------------------------------------------------- 1 | # A SQLAlchemy recipe for PostgreSQL Materialized Views 2 | A SQLAlchemy recipe for managing PostgreSQL Materialized views that handles: 3 | * Creating 4 | * Dropping 5 | * Indexing 6 | * Refreshing (including concurrent background refreshes) 7 | 8 | Accompanying blog post: [http://www.jeffwidman.com/blog/847/using-sqlalchemy-to-create-and-manage-postgresql-materialized-views/](http://www.jeffwidman.com/blog/847/using-sqlalchemy-to-create-and-manage-postgresql-materialized-views/) 9 | 10 | Many thanks to [Mike Bayer](http://techspot.zzzeek.org/) for his help 11 | with this. 12 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | The MIT License (MIT) 2 | 3 | Copyright (c) 2016 Jeff Widman 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /flask-sqlalchemy-example/models.py: -------------------------------------------------------------------------------- 1 | # models.py example for use with Flask-SQLAlchemy 2 | 3 | from sqlalchemy.ext.hybrid import hybrid_property 4 | 5 | from app import db 6 | from app.models.view_factory import MaterializedView, create_mat_view 7 | 8 | 9 | class GearItem(db.Model): 10 | id = db.Column(db.Integer, primary_key=True) 11 | name = db.Column(db.Text, nullable=False, index=True) 12 | description = db.Column(db.Text) 13 | reviews = db.relationship('GearReview', backref='gear_item', lazy='dynamic') 14 | mat_view = db.relationship('GearItemMV', backref='original', 15 | uselist=False, # makes it a one-to-one relationship 16 | primaryjoin='GearItem.id==GearItemMV.id', 17 | foreign_keys='GearItemMV.id') 18 | time_created = db.Column(db.DateTime(timezone=True), 19 | server_default=db.func.current_timestamp(),) 20 | 21 | @hybrid_property 22 | def review_count(self): 23 | if self.mat_view is not None: # if None, mat_view needs refreshing 24 | return self.mat_view.review_count 25 | 26 | @hybrid_property 27 | def review_rating(self): 28 | if self.mat_view is not None: # if None, mat_view needs refreshing 29 | return self.mat_view.review_rating 30 | 31 | 32 | class GearItemMV(MaterializedView): 33 | __table__ = create_mat_view("gear_item_mv", 34 | db.select( 35 | [GearItem.id.label('id'), 36 | db.func.count(GearReview.id).label('review_count'), 37 | db.func.avg(GearReview.rating).label('review_rating'),] 38 | ).select_from(db.join(GearItem, GearReview, isouter=True) 39 | ).group_by(GearItem.id)) 40 | 41 | db.Index('gear_item_mv_id_idx', GearItemMV.id, unique=True) 42 | -------------------------------------------------------------------------------- /materialized_view_factory.py: -------------------------------------------------------------------------------- 1 | # materialized_view_factory.py 2 | # standalone SQLAlchemy example 3 | 4 | # Accompanying blog post: 5 | # http://www.jeffwidman.com/blog/847/ 6 | 7 | # Many thanks to Mike Bayer (@zzzeek) for his help. 8 | 9 | from sqlalchemy.ext import compiler 10 | from sqlalchemy.schema import DDLElement, PrimaryKeyConstraint 11 | import sqlalchemy as db 12 | 13 | 14 | class CreateMaterializedView(DDLElement): 15 | def __init__(self, name, selectable): 16 | self.name = name 17 | self.selectable = selectable 18 | 19 | 20 | @compiler.compiles(CreateMaterializedView) 21 | def compile(element, compiler, **kw): 22 | # Could use "CREATE OR REPLACE MATERIALIZED VIEW..." 23 | # but I'd rather have noisy errors 24 | return "CREATE MATERIALIZED VIEW %s AS %s" % ( 25 | element.name, 26 | compiler.sql_compiler.process(element.selectable, literal_binds=True), 27 | ) 28 | 29 | 30 | def create_mat_view(metadata, name, selectable): 31 | _mt = db.MetaData() # temp metadata just for initial Table object creation 32 | t = db.Table(name, _mt) # the actual mat view class is bound to db.metadata 33 | for c in selectable.c: 34 | t.append_column(db.Column(c.name, c.type, primary_key=c.primary_key)) 35 | 36 | if not (any([c.primary_key for c in selectable.c])): 37 | t.append_constraint(PrimaryKeyConstraint(*[c.name for c in selectable.c])) 38 | 39 | db.event.listen( 40 | metadata, "after_create", 41 | CreateMaterializedView(name, selectable) 42 | ) 43 | 44 | @db.event.listens_for(metadata, "after_create") 45 | def create_indexes(target, connection, **kw): 46 | for idx in t.indexes: 47 | idx.create(connection) 48 | 49 | db.event.listen( 50 | metadata, "before_drop", 51 | db.DDL('DROP MATERIALIZED VIEW IF EXISTS ' + name) 52 | ) 53 | return t 54 | 55 | # NOTE: For functions showing how to refresh these views, see the 56 | # Flask-SQLAlchemy section. 57 | 58 | 59 | from sqlalchemy.ext.declarative import declarative_base 60 | Base = declarative_base() 61 | 62 | 63 | class Gear(Base): 64 | __tablename__ = 'gear' 65 | id = db.Column(db.Integer, primary_key=True) 66 | rating = db.Column(db.Integer) 67 | 68 | 69 | class GearMV(Base): 70 | __table__ = create_mat_view( 71 | Base.metadata, 72 | "gear_mv", 73 | db.select([ 74 | Gear.id.label('id'), 75 | db.func.count(Gear.id).label('review_count'), 76 | db.func.avg(Gear.rating).label('review_rating'), 77 | ]).select_from(Gear) 78 | .group_by(Gear.id)) 79 | 80 | db.Index('test_index', GearMV.id, unique=True) 81 | 82 | 83 | e = db.create_engine("postgresql://scott:tiger@localhost/test", echo=True) 84 | Base.metadata.drop_all(e) 85 | Base.metadata.create_all(e) 86 | 87 | Base.metadata.drop_all(e) 88 | -------------------------------------------------------------------------------- /flask-sqlalchemy-example/materialized_view_factory.py: -------------------------------------------------------------------------------- 1 | # materialized_view_factory.py 2 | # example for use with Flask-SQLAlchemy 3 | 4 | # Accompanying blog post: 5 | # http://www.jeffwidman.com/blog/847/ 6 | 7 | # Many thanks to Mike Bayer (@zzzeek) for his help. 8 | 9 | from sqlalchemy.ext import compiler 10 | from sqlalchemy.schema import DDLElement, PrimaryKeyConstraint 11 | from app import db 12 | 13 | 14 | class CreateMaterializedView(DDLElement): 15 | def __init__(self, name, selectable): 16 | self.name = name 17 | self.selectable = selectable 18 | 19 | 20 | @compiler.compiles(CreateMaterializedView) 21 | def compile(element, compiler, **kw): 22 | # Could use "CREATE OR REPLACE MATERIALIZED VIEW..." 23 | # but I'd rather have noisy errors 24 | return 'CREATE MATERIALIZED VIEW %s AS %s' % ( 25 | element.name, 26 | compiler.sql_compiler.process(element.selectable, literal_binds=True), 27 | ) 28 | 29 | 30 | def create_mat_view(name, selectable, metadata=db.metadata): 31 | _mt = db.MetaData() # temp metadata just for initial Table object creation 32 | t = db.Table(name, _mt) # the actual mat view class is bound to db.metadata 33 | for c in selectable.c: 34 | t.append_column(db.Column(c.name, c.type, primary_key=c.primary_key)) 35 | 36 | if not (any([c.primary_key for c in selectable.c])): 37 | t.append_constraint(PrimaryKeyConstraint(*[c.name for c in selectable.c])) 38 | 39 | db.event.listen( 40 | metadata, 'after_create', 41 | CreateMaterializedView(name, selectable) 42 | ) 43 | 44 | @db.event.listens_for(metadata, 'after_create') 45 | def create_indexes(target, connection, **kw): 46 | for idx in t.indexes: 47 | idx.create(connection) 48 | 49 | db.event.listen( 50 | metadata, 'before_drop', 51 | db.DDL('DROP MATERIALIZED VIEW IF EXISTS ' + name) 52 | ) 53 | return t 54 | 55 | 56 | def refresh_mat_view(name, concurrently): 57 | # since session.execute() bypasses autoflush, must manually flush in order 58 | # to include newly-created/modified objects in the refresh 59 | db.session.flush() 60 | _con = 'CONCURRENTLY ' if concurrently else '' 61 | db.session.execute('REFRESH MATERIALIZED VIEW ' + _con + name) 62 | 63 | 64 | def refresh_all_mat_views(concurrently=True): 65 | '''Refreshes all materialized views. Currently, views are refreshed in 66 | non-deterministic order, so view definitions can't depend on each other.''' 67 | mat_views = db.inspect(db.engine).get_view_names(include='materialized') 68 | for v in mat_views: 69 | refresh_mat_view(v, concurrently) 70 | 71 | 72 | class MaterializedView(db.Model): 73 | __abstract__ = True 74 | 75 | @classmethod 76 | def refresh(cls, concurrently=True): 77 | '''Refreshes the current materialized view''' 78 | refresh_mat_view(cls.__table__.fullname, concurrently) 79 | --------------------------------------------------------------------------------