├── .gitignore ├── .travis.yml ├── LICENSE ├── README.md ├── crosstab.py ├── example.py ├── requirements.txt ├── setup.py └── test_crosstab.py /.gitignore: -------------------------------------------------------------------------------- 1 | *.py[co] 2 | 3 | # Packages 4 | *.egg 5 | *.egg-info 6 | dist 7 | build 8 | eggs 9 | parts 10 | bin 11 | var 12 | sdist 13 | develop-eggs 14 | .installed.cfg 15 | 16 | # Installer logs 17 | pip-log.txt 18 | 19 | # Unit test / coverage reports 20 | .coverage 21 | .tox 22 | 23 | #Translations 24 | *.mo 25 | 26 | #Mr Developer 27 | .mr.developer.cfg 28 | 29 | # Pytest/Connection String Storage 30 | envfile.txt 31 | .cache 32 | -------------------------------------------------------------------------------- /.travis.yml: -------------------------------------------------------------------------------- 1 | language: python 2 | services: 3 | - postgresql 4 | python: 5 | - "2.7" 6 | - "3.3" 7 | - "3.6" 8 | install: "pip install -r requirements.txt" 9 | script: pytest 10 | before_script: 11 | - psql -c 'create database travis_ci_test;' -U postgres 12 | - psql -c 'CREATE EXTENSION tablefunc' -d travis_ci_test -U postgres 13 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright (c) 2016, Mehmet Ali "Mali" Akmanalp 2 | All rights reserved. 3 | 4 | Redistribution and use in source and binary forms, with or without 5 | modification, are permitted provided that the following conditions are met: 6 | 7 | * Redistributions of source code must retain the above copyright notice, this 8 | list of conditions and the following disclaimer. 9 | 10 | * Redistributions in binary form must reproduce the above copyright notice, 11 | this list of conditions and the following disclaimer in the documentation 12 | and/or other materials provided with the distribution. 13 | 14 | * Neither the name of sqlalchemy-crosstab-postgresql nor the names of its 15 | contributors may be used to endorse or promote products derived from 16 | this software without specific prior written permission. 17 | 18 | THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" 19 | AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE 20 | IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE 21 | DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE LIABLE 22 | FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL 23 | DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR 24 | SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER 25 | CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, 26 | OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE 27 | OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 28 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | sqlalchemy-crosstab-postgresql 2 | ============================== 3 | 4 | New grammar for SQLAlchemy to make handling the crosstab() tablefunc 5 | (i.e. pivot tables) in Postgresql easy peasy. Jump down to the usage 6 | example if you're impatient. 7 | 8 | This is a work-in-progress and not all that clean right now, but you're welcome 9 | to bring in your fixes and patches! 10 | 11 | Author: Mali Akmanalp 12 | 13 | Thanks 14 | ------ 15 | * Michael Bayer of the sqlalchemy list for the original sample code. 16 | 17 | Similar Projects 18 | ---------------- 19 | * Tomas Drencak's [pandas-sqlalchemy-pivot](https://github.com/tomasd/pandas-sqlalchemy-pivot) that uses pandas for pivoting instead of the database itself. 20 | 21 | What is crosstab? 22 | ----------------- 23 | 24 | Crosstab, a.k.a. pivot tables, is best described by example. Let's say you have a table of population records: 25 | 26 | 27 | 28 | 29 | 30 | 31 | 32 | 33 | 34 | 35 | 36 | 37 | 38 | 39 | 40 | 41 | 42 | 43 | 44 | 45 | 46 | 47 | 48 | 49 | 50 | 51 | 52 | 53 | 54 | 55 | 56 | 57 |
CountryYearCount
India2009100
India2010150
India2011200
Czechoslovakia2008200
Czechoslovakia2010400
58 | 59 | and turning it into: 60 | 61 | 62 | 63 | 64 | 65 | 66 | 67 | 68 | 69 | 70 | 71 | 72 | 73 | 74 | 75 | 76 | 77 | 78 | 79 | 80 | 81 | 82 | 83 |
Country2008200920102011
India100150200
Czechoslovakia200400
84 | 85 | Another way to think about it is that it takes tuples of (y, x, value) and 86 | makes a new table where it puts value in location (x, y) e.g. 400 in (2010, 87 | "Czechoslovakia"). 88 | 89 | So a sample query would look like this: 90 | 91 | ```sql 92 | select * 93 | from crosstab('select country, year, count from pop order by 1', 'select distinct year from pop order by 1') 94 | as derp (country text, y1 int, y2 int, y3 int, y4 int) 95 | ``` 96 | 97 | where the first parameter is the input of form (key, 98 | thing_to_turn_into_columns, value) (e.g. India, 2009, 100 etc.) and the second 99 | is a list of possible column values (eg. 2008, 2009, 2010, 2011). The from 100 | clause needs to declare the expected return types, which usually are the types 101 | of (key, col1, col2, col3 ...) etc. 102 | 103 | For more, read the [tablefunc docs](http://www.postgresql.org/docs/current/static/tablefunc.html). 104 | 105 | Things I wish people had told me about crosstab 106 | ----------------------------------------------- 107 | * The form crosstab(text sql) is useless if you have any empty fields in the 108 | resulting table (as in the example above), since the function doesn't place 109 | the data in intelligently, it just lumps it in so you'll end up with data in 110 | the wrong columns. See: [this](http://stackoverflow.com/questions/3002499/postgresql-crosstab-query#11751905) 111 | * The fix for this is to use the form crosstab(text source_sql, text 112 | category_sql), where the second query must return a list of column names 113 | (e.g. "India", "Czechoslovakia"). These must be ordered also, otherwise the 114 | output gets wonky. Can't have dupes either. 115 | * The easy-to-miss conclusion from the previous point is that it is up to you 116 | to make sure that when you define your return types, they should accurately 117 | depict what your input data contains. Following our example, if you claim in 118 | the return types that you only have 2 columns for 2008 and 2009, it will 119 | complain. So you need to know beforehand all the possible column values and 120 | use a "where year = 2008 or year = 2010 etc" to make other possible values 121 | not appear. The benefit of the latter call form with 2 parameters is that any 122 | extra column values are ignored and you don't have to deal with that. 123 | * For your category query, you can use a regular select distinct or you can 124 | just "fake it" by doing a select * from values (...). 125 | * Your source sql *must* be ordered by 1, 2. 126 | * Your category query must be ordered also. 127 | * You have to pass in the queries as strings, which is a pain in the butt and 128 | causes issues when you need to escape things (e.g. a quote). Luckily, the 129 | [double dollar operator](http://www.postgresql.org/docs/current/interactive/sql-syntax-lexical.html#SQL-SYNTAX-DOLLAR-QUOTING) 130 | comes to the rescue. 131 | 132 | Usage 133 | ----- 134 | crosstab.py handles most of the grossness for you so you can get work done. Check example.py for the full runnable code. 135 | 136 | ```python 137 | crosstab_input = \ 138 | select([ raw.c.country, 139 | raw.c.year, 140 | raw.c.quantity]) 141 | 142 | categories = \ 143 | select([distinct(raw.c.year)]) 144 | 145 | 146 | ret_types = Table('ct', m, Column('country', Text), 147 | Column('y1', Integer), 148 | Column('y2', Integer), 149 | Column('y3', Integer), 150 | Column('y4', Integer), 151 | ) 152 | 153 | q = select(['*']).select_from(crosstab(crosstab_input, ret_types, categories=categories)) 154 | ``` 155 | 156 | generates the query: 157 | 158 | ```sql 159 | SELECT * 160 | FROM crosstab( 161 | $$SELECT raw.country, raw.year, raw.quantity FROM raw ORDER BY 1,2$$, 162 | $$SELECT DISTINCT raw.year FROM raw ORDER BY 1$$) 163 | AS ct(country TEXT, y1 INTEGER, y2 INTEGER, y3 INTEGER, y4 INTEGER) 164 | ``` 165 | 166 | crosstab.py also supplies row_total(), which allows you to sum a bunch of 167 | fields in a row while ignoring NULLs and pretending they were 0s. Otherwise, 168 | the NULLs would eat up the numbers and the total would be NULL. It does this 169 | under the hood by calling coalesce(x, 0) on each field and then summing them. 170 | This is meant to be used on the select part of a crosstab, such as: 171 | 172 | ```sql 173 | select(['header', 'y1', 'y2', row_total('y1', 'y2').label('sum')])\ 174 | .select_from(crosstab(...))\ 175 | .order_by('sum') 176 | ``` 177 | 178 | Which generates: 179 | 180 | ```sql 181 | select header, y1, y2, coalesce(y1, 0) + coalesce(y2, 0) as sum from crosstab(...) order by sum 182 | ``` 183 | 184 | This is useful for row totals and subtotals. 185 | -------------------------------------------------------------------------------- /crosstab.py: -------------------------------------------------------------------------------- 1 | from sqlalchemy.sql import FromClause, column, ColumnElement 2 | from sqlalchemy.orm import Query 3 | from sqlalchemy.ext.compiler import compiles 4 | 5 | class crosstab(FromClause): 6 | def __init__(self, stmt, return_def, categories=None, auto_order=True): 7 | if not (isinstance(return_def, (list, tuple)) 8 | or return_def.is_selectable): 9 | raise TypeError('return_def must be a selectable or tuple/list') 10 | self.stmt = stmt 11 | self.columns = return_def if isinstance(return_def, (list, tuple)) \ 12 | else return_def.columns 13 | self.categories = categories 14 | if hasattr(return_def, 'name'): 15 | self.name = return_def.name 16 | else: 17 | self.name = None 18 | 19 | if isinstance(self.stmt, Query): 20 | self.stmt = self.stmt.selectable 21 | if isinstance(self.categories, Query): 22 | self.categories = self.categories.selectable 23 | 24 | #Don't rely on the user to order their stuff 25 | if auto_order: 26 | self.stmt = self.stmt.order_by('1,2') 27 | if self.categories is not None: 28 | self.categories = self.categories.order_by('1') 29 | 30 | def _populate_column_collection(self): 31 | self._columns.update( 32 | column(name, type=type_) 33 | for name, type_ in self.names 34 | ) 35 | 36 | @compiles(crosstab, 'postgresql') 37 | def visit_element(element, compiler, **kw): 38 | if element.categories is not None: 39 | return """crosstab($$%s$$, $$%s$$) AS (%s)""" % ( 40 | compiler.visit_select(element.stmt), 41 | compiler.visit_select(element.categories), 42 | ", ".join( 43 | "\"%s\" %s" % (c.name, compiler.visit_typeclause(c)) 44 | for c in element.c 45 | ) 46 | ) 47 | else: 48 | return """crosstab($$%s$$) AS (%s)""" % ( 49 | compiler.visit_select(element.stmt), 50 | ", ".join( 51 | "%s %s" % (c.name, compiler.visit_typeclause(c)) 52 | for c in element.c 53 | ) 54 | ) 55 | 56 | from operator import add 57 | from sqlalchemy import func, INTEGER 58 | 59 | class row_total(ColumnElement): 60 | type = INTEGER() 61 | def __init__(self, cols): 62 | self.cols = cols 63 | 64 | @compiles(row_total) 65 | def compile_row_total(element, compiler, **kw): 66 | #coalesce_columns = [func.coalesce("'%s'" % x.name, 0) for x in element.cols] 67 | coalesce_columns = ['coalesce("%s", 0)' % x.name for x in element.cols] 68 | return "+".join(coalesce_columns) 69 | -------------------------------------------------------------------------------- /example.py: -------------------------------------------------------------------------------- 1 | from crosstab import crosstab 2 | from sqlalchemy import Table, Column, Text, Integer, MetaData, distinct, select 3 | 4 | #create Engine and bind 5 | from sqlalchemy import create_engine 6 | engine = create_engine("postgresql+psycopg2:///dbname") 7 | engine.echo = True 8 | m = MetaData() 9 | m.bind = engine 10 | 11 | #Set up the sample source data 12 | raw = Table('raw', m, Column('country', Text), 13 | Column('year', Integer), 14 | Column('quantity', Integer), 15 | Column('unrelated_field', Text)) 16 | 17 | data = [ 18 | ('India', 2009, 100, "foo"), 19 | ('India', 2010, 150, "foo"), 20 | ('India', 2011, 200, "foo"), 21 | ('Czechoslovakia', 2008, 200, "foo"), 22 | ('Czechoslovakia', 2010, 400, "foo") 23 | ] 24 | 25 | raw.create() 26 | for line in data: 27 | raw.insert().values(line).execute() 28 | 29 | #Define the input table 30 | crosstab_input = \ 31 | select([ raw.c.country, 32 | raw.c.year, 33 | raw.c.quantity]) 34 | 35 | #Define the categories. For us, this is 2008, 2009, 2010 etc. 36 | categories = \ 37 | select([distinct(raw.c.year)]) 38 | #or you could fake the values like so: 39 | #categories = select(['*']).select_from('(VALUES (2008), (2009), (2010), (2011)) x') 40 | 41 | 42 | #Define the return row types. The fact that we're defining a table is a 43 | #formality, it's just easier to do it that way. It won't ever get created. 44 | ret_types = Table('ct', m, Column('country', Text), 45 | Column('y1', Integer), 46 | Column('y2', Integer), 47 | Column('y3', Integer), 48 | Column('y4', Integer), 49 | ) 50 | 51 | #Finally, the crosstab query itself. Has the input query, the category query and the return types. 52 | q = select(['*']).select_from(crosstab(crosstab_input, ret_types, categories=categories)) 53 | 54 | #Ta-daaa! 55 | print [x for x in engine.execute(q)] 56 | 57 | #cleanup 58 | raw.drop() 59 | 60 | -------------------------------------------------------------------------------- /requirements.txt: -------------------------------------------------------------------------------- 1 | sqlalchemy>=1.0 2 | pytest>=3.0 3 | psycopg2 4 | -------------------------------------------------------------------------------- /setup.py: -------------------------------------------------------------------------------- 1 | from setuptools import setup 2 | 3 | 4 | setup( 5 | name='crosstab', 6 | version='0.1', 7 | description='New grammar for SQLAlchemy to make handling the crosstab() tablefunc (i.e. pivot tables) in Postgresql easy peasy', 8 | long_description='', 9 | # Get strings from http://pypi.python.org/pypi?%3Aaction=list_classifiers 10 | classifiers=[ 11 | 'License :: OSI Approved :: BSD License', 12 | ], 13 | keywords='', 14 | author='Mehmet Ali "Mali" Akmanalp', 15 | author_email='', 16 | url='https://github.com/makmanalp/sqlalchemy-crosstab-postgresql', 17 | license='BSD license', 18 | py_modules=['crosstab'], 19 | zip_safe=False, 20 | install_requires=[ 21 | 'sqlalchemy', 22 | 'pytest', 23 | 'psycopg2' 24 | ], 25 | ) 26 | -------------------------------------------------------------------------------- /test_crosstab.py: -------------------------------------------------------------------------------- 1 | from __future__ import print_function 2 | import os 3 | import pytest 4 | from sqlalchemy.orm import sessionmaker 5 | from sqlalchemy.ext.declarative import declarative_base 6 | from sqlalchemy.exc import CompileError 7 | from sqlalchemy import Table, Column, Text, Integer, MetaData, distinct, select 8 | from sqlalchemy import create_engine, func 9 | from crosstab import crosstab 10 | 11 | 12 | # Yes, this is a lot of fixtures. I think the modularity is useful. 13 | 14 | @pytest.fixture(scope="module", params=('envfile.txt',)) 15 | def pgengine(request): 16 | """Create a sqlalchemy engine for a PostgreSQL DB.""" 17 | envFile = request.param 18 | if os.environ.get('DBCONNECTION', None) is None: 19 | with open(envFile) as envVars: 20 | for line in envVars: 21 | var, val = line.split('=', 1) 22 | var = var.strip() 23 | val = val.strip() 24 | os.environ[var] = val 25 | dbConnectionString = os.environ['DBCONNECTION'] 26 | return create_engine(dbConnectionString, echo=True) 27 | 28 | 29 | @pytest.fixture(scope="module") 30 | def sqliteEngine(): 31 | """Create a sqlalchemy engine for a memory-only SQLite instance.""" 32 | return create_engine('sqlite:///:memory:', echo=True) 33 | 34 | 35 | @pytest.fixture(scope="function") 36 | def pgmetadata(pgengine): 37 | """Creates a metadata object for the engine for SQLA Core Tests.""" 38 | meta = MetaData(bind=pgengine) 39 | yield meta 40 | meta.drop_all() 41 | 42 | 43 | @pytest.fixture(scope="function") 44 | def tableraw(pgmetadata): 45 | #Set up the sample source data 46 | raw = Table('raw', pgmetadata, 47 | Column('country', Text), 48 | Column('year', Integer), 49 | Column('quantity', Integer), 50 | Column('unrelated_field', Text)) 51 | data = [ 52 | ('India', 2009, 100, "foo"), 53 | ('India', 2010, 150, "foo"), 54 | ('India', 2011, 200, "foo"), 55 | ('Czechoslovakia', 2008, 200, "foo"), 56 | ('Czechoslovakia', 2010, 400, "foo") 57 | ] 58 | raw.create() 59 | for line in data: 60 | raw.insert().values(line).execute() 61 | yield raw 62 | raw.drop() 63 | 64 | 65 | # ---------- ORM Fixtures ------------------------------------------------- 66 | 67 | 68 | @pytest.fixture(scope="module") 69 | def OrmBase(): 70 | return declarative_base() 71 | 72 | 73 | @pytest.fixture(scope="module") 74 | def ormCensus(OrmBase): 75 | class OrmCensus(OrmBase): 76 | __tablename__ = 'ormcensus' 77 | id = Column(Integer, primary_key=True) 78 | country = Column(Text) 79 | year = Column(Integer) 80 | quantity = Column(Integer) 81 | unrelated_field = Column(Text) 82 | 83 | return OrmCensus 84 | 85 | 86 | @pytest.fixture(scope="module") 87 | def pgsessionclass(pgengine, OrmBase, ormCensus): 88 | """Creates a Session class, which can then generate sessions.""" 89 | OrmBase.metadata.create_all(pgengine) 90 | return sessionmaker(bind=pgengine) 91 | 92 | 93 | @pytest.fixture(scope="function") 94 | def pgsession(pgsessionclass): 95 | """Create an ORM Session for PostgreSQL.""" 96 | sess = pgsessionclass() 97 | yield sess 98 | sess.rollback() 99 | 100 | 101 | @pytest.fixture(scope="function") 102 | def ormCensusData(ormCensus, pgsession): 103 | pgsession.add_all([ 104 | ormCensus(country='India', year=2009, quantity=100, unrelated_field='foo'), 105 | ormCensus(country='India', year=2010, quantity=150, unrelated_field='foo'), 106 | ormCensus(country='India', year=2011, quantity=200, unrelated_field='foo'), 107 | ormCensus(country='Czechoslovakia', year=2008, quantity=200, unrelated_field='foo'), 108 | ormCensus(country='Czechoslovakia', year=2010, quantity=400, unrelated_field='foo') 109 | ]) 110 | 111 | 112 | # ------------------------------------------------------------------------- 113 | # And now for the tests. 114 | 115 | 116 | def test_coreReturnAll(pgengine, pgmetadata, tableraw): 117 | """Test the simple case of crosstabing all of the data in the table.""" 118 | raw = tableraw 119 | # Define the input table 120 | crosstab_input = \ 121 | select([ raw.c.country, 122 | raw.c.year, 123 | raw.c.quantity]) 124 | 125 | # Define the categories. For us, this is 2008, 2009, 2010 etc. 126 | categories = \ 127 | select([distinct(raw.c.year)]) 128 | 129 | # Define return columns. Table is an easy way to do that. 130 | ret_types = Table('ct', pgmetadata, 131 | Column('country', Text), 132 | Column('y1', Integer), 133 | Column('y2', Integer), 134 | Column('y3', Integer), 135 | Column('y4', Integer), 136 | ) 137 | 138 | # Finally, the crosstab query itself. 139 | q = select(['*']).select_from(crosstab(crosstab_input, ret_types, 140 | categories=categories)) 141 | 142 | assert [tuple(x) for x in pgengine.execute(q)] == [ 143 | ('Czechoslovakia', 200, None, 400, None), 144 | ('India', None, 100, 150, 200) 145 | ] 146 | 147 | def test_coreReturnSome(pgengine, pgmetadata, tableraw): 148 | """Test the case of crossstabing a query with a where clause.""" 149 | raw = tableraw 150 | # Define the input table 151 | crosstab_input = \ 152 | select([ raw.c.country, 153 | raw.c.year, 154 | raw.c.quantity]).where(raw.c.country == 'India') 155 | 156 | # Define the categories. For us, this is 2008, 2009, 2010 etc. 157 | categories = \ 158 | select([distinct(raw.c.year)]) 159 | 160 | # Define return columns. Table is an easy way to do that. 161 | ret_types = Table('ct', pgmetadata, 162 | Column('country', Text), 163 | Column('y1', Integer), 164 | Column('y2', Integer), 165 | Column('y3', Integer), 166 | Column('y4', Integer), 167 | ) 168 | 169 | # Finally, the crosstab query itself. 170 | q = select(['*']).select_from(crosstab(crosstab_input, ret_types, 171 | categories=categories)) 172 | 173 | assert [tuple(x) for x in pgengine.execute(q)] == [ 174 | ('India', None, 100, 150, 200) 175 | ] 176 | 177 | 178 | def test_coreAggregation(pgengine, pgmetadata, tableraw): 179 | """Test the case of crossstabing with a sum() and a where clause.""" 180 | raw = tableraw 181 | # Define the input table 182 | crosstab_input = \ 183 | select([ raw.c.unrelated_field, 184 | raw.c.year, 185 | func.sum(raw.c.quantity).label('quantity')] 186 | ).where( 187 | raw.c.unrelated_field == 'foo' 188 | ).group_by( 189 | raw.c.unrelated_field, 190 | raw.c.year 191 | ) 192 | 193 | # Define the categories. For us, this is 2008, 2009, 2010 etc. 194 | categories = \ 195 | select([distinct(raw.c.year)]) 196 | 197 | # Define return columns. Table is an easy way to do that. 198 | ret_types = Table('ct', pgmetadata, 199 | Column('country', Text), 200 | Column('y1', Integer), 201 | Column('y2', Integer), 202 | Column('y3', Integer), 203 | Column('y4', Integer), 204 | ) 205 | 206 | # Finally, the crosstab query itself. 207 | q = select(['*']).select_from(crosstab(crosstab_input, ret_types, 208 | categories=categories)) 209 | 210 | assert [tuple(x) for x in pgengine.execute(q)] == [ 211 | ('foo', 200, 100, 550, 200) 212 | ] 213 | 214 | 215 | def test_breaksOnSqlite(sqliteEngine): 216 | meta = MetaData(bind=sqliteEngine) 217 | 218 | raw = Table('raw', meta, 219 | Column('country', Text), 220 | Column('year', Integer), 221 | Column('quantity', Integer), 222 | Column('unrelated_field', Text)) 223 | data = [ 224 | ('India', 2009, 100, "foo"), 225 | ('India', 2010, 150, "foo"), 226 | ('India', 2011, 200, "foo"), 227 | ('Czechoslovakia', 2008, 200, "foo"), 228 | ('Czechoslovakia', 2010, 400, "foo") 229 | ] 230 | raw.create() 231 | for line in data: 232 | raw.insert().values(line).execute() 233 | 234 | # Define the input table 235 | crosstab_input = \ 236 | select([ raw.c.country, 237 | raw.c.year, 238 | raw.c.quantity]).where(raw.c.country == 'India') 239 | 240 | # Define the categories. For us, this is 2008, 2009, 2010 etc. 241 | categories = \ 242 | select([distinct(raw.c.year)]) 243 | 244 | # Define return columns. Table is an easy way to do that. 245 | ret_types = Table('ct', meta, 246 | Column('country', Text), 247 | Column('y1', Integer), 248 | Column('y2', Integer), 249 | Column('y3', Integer), 250 | Column('y4', Integer), 251 | ) 252 | 253 | # Finally, the crosstab query itself. 254 | q = select(['*']).select_from(crosstab(crosstab_input, ret_types, 255 | categories=categories)) 256 | 257 | with pytest.raises(Exception): 258 | sqliteEngine.execute(q) 259 | 260 | raw.drop() 261 | meta.drop_all() 262 | 263 | 264 | def test_coreReturnBySelect(pgengine, pgmetadata, tableraw): 265 | """Test the simple case of crosstabing all of the data in the table.""" 266 | raw = tableraw 267 | # Define the input table 268 | crosstab_input = \ 269 | select([ raw.c.country, 270 | raw.c.year, 271 | raw.c.quantity]) 272 | 273 | # Define the categories. For us, this is 2008, 2009, 2010 etc. 274 | categories = \ 275 | select([distinct(raw.c.year)]) 276 | 277 | # Define return columns. Table is an easy way to do that. 278 | ret_types = select([ 279 | raw.c.country.label('country'), 280 | raw.c.quantity.label('y1'), 281 | raw.c.quantity.label('y2'), 282 | raw.c.quantity.label('y3'), 283 | raw.c.quantity.label('y4') 284 | ]) 285 | 286 | # Finally, the crosstab query itself. 287 | q = select(['*']).select_from(crosstab(crosstab_input, ret_types, 288 | categories=categories)) 289 | 290 | assert [tuple(x) for x in pgengine.execute(q)] == [ 291 | ('Czechoslovakia', 200, None, 400, None), 292 | ('India', None, 100, 150, 200) 293 | ] 294 | 295 | 296 | def test_coreReturnByTuple(pgengine, pgmetadata, tableraw): 297 | """Test the simple case of crosstabing all of the data in the table.""" 298 | raw = tableraw 299 | # Define the input table 300 | crosstab_input = \ 301 | select([ raw.c.country, 302 | raw.c.year, 303 | raw.c.quantity]) 304 | 305 | # Define the categories. For us, this is 2008, 2009, 2010 etc. 306 | categories = \ 307 | select([distinct(raw.c.year)]) 308 | 309 | # Define return columns. Table is an easy way to do that. 310 | ret_types = ( 311 | Column('country', Text), 312 | Column('y1', Integer), 313 | Column('y2', Integer), 314 | Column('y3', Integer), 315 | Column('y4', Integer) 316 | ) 317 | 318 | # Finally, the crosstab query itself. 319 | q = select(['*']).select_from(crosstab(crosstab_input, ret_types, 320 | categories=categories)) 321 | 322 | assert [tuple(x) for x in pgengine.execute(q)] == [ 323 | ('Czechoslovakia', 200, None, 400, None), 324 | ('India', None, 100, 150, 200) 325 | ] 326 | 327 | 328 | # --------------------- ORM Tests ------------------------------------- 329 | @pytest.mark.usefixtures("ormCensusData") 330 | def test_ormReturnAll(ormCensus, pgsession): 331 | """Test that you can combine crosstab with ORM Queries.""" 332 | # Define the input table 333 | crosstab_input = pgsession.query(ormCensus.country, ormCensus.year, 334 | ormCensus.quantity) 335 | 336 | # Define the categories. For us, this is 2008, 2009, 2010 etc. 337 | categories = pgsession.query(ormCensus.year).group_by(ormCensus.year) 338 | 339 | # Define return columns. Table is an easy way to do that. 340 | ret_types = ( 341 | Column('country', Text), 342 | Column('y1', Integer), 343 | Column('y2', Integer), 344 | Column('y3', Integer), 345 | Column('y4', Integer) 346 | ) 347 | 348 | # Finally, the crosstab query itself. 349 | q = pgsession.query(*ret_types).select_from( 350 | crosstab(crosstab_input, ret_types, categories=categories)) 351 | 352 | assert [tuple(x) for x in q.all()] == [ 353 | ('Czechoslovakia', 200, None, 400, None), 354 | ('India', None, 100, 150, 200) 355 | ] 356 | 357 | 358 | @pytest.mark.usefixtures("ormCensusData") 359 | def test_ormReturnSome(ormCensus, pgsession): 360 | """Test that you can combine crosstab with ORM Queries.""" 361 | # Define the input table 362 | crosstab_input = pgsession.query( 363 | ormCensus.country, 364 | ormCensus.year, 365 | ormCensus.quantity 366 | ).filter(ormCensus.country == 'India') 367 | 368 | # Define the categories. For us, this is 2008, 2009, 2010 etc. 369 | categories = pgsession.query(ormCensus.year).group_by(ormCensus.year) 370 | 371 | # Define return columns. Table is an easy way to do that. 372 | ret_types = ( 373 | Column('country', Text), 374 | Column('y1', Integer), 375 | Column('y2', Integer), 376 | Column('y3', Integer), 377 | Column('y4', Integer) 378 | ) 379 | 380 | # Finally, the crosstab query itself. 381 | q = pgsession.query(*ret_types).select_from( 382 | crosstab(crosstab_input, ret_types, categories=categories)) 383 | 384 | assert [tuple(x) for x in q.all()] == [ 385 | ('India', None, 100, 150, 200) 386 | ] 387 | 388 | 389 | @pytest.mark.usefixtures("ormCensusData") 390 | def test_ormReturnAggregate(ormCensus, pgsession): 391 | """Test that you can combine crosstab with ORM Queries.""" 392 | # Define the input table 393 | crosstab_input = pgsession.query( 394 | ormCensus.unrelated_field, 395 | ormCensus.year, 396 | func.sum(ormCensus.quantity) 397 | ).filter( 398 | ormCensus.unrelated_field == 'foo' 399 | ).group_by( 400 | ormCensus.unrelated_field, 401 | ormCensus.year 402 | ) 403 | 404 | # Define the categories. For us, this is 2008, 2009, 2010 etc. 405 | categories = pgsession.query(ormCensus.year).group_by(ormCensus.year) 406 | 407 | # Define return columns. Table is an easy way to do that. 408 | ret_types = ( 409 | Column('country', Text), 410 | Column('y1', Integer), 411 | Column('y2', Integer), 412 | Column('y3', Integer), 413 | Column('y4', Integer) 414 | ) 415 | 416 | # Finally, the crosstab query itself. 417 | q = pgsession.query(*ret_types).select_from( 418 | crosstab(crosstab_input, ret_types, categories=categories)) 419 | 420 | assert [tuple(x) for x in q.all()] == [ 421 | ('foo', 200, 100, 550, 200) 422 | ] 423 | --------------------------------------------------------------------------------