├── LICENSE.md ├── MANIFEST.in ├── README.md ├── little_pger.py ├── setup.cfg └── setup.py /LICENSE.md: -------------------------------------------------------------------------------- 1 | License 2 | ======= 3 | 4 | Copyright (c) 2013, Christian Jauvin 5 | All rights reserved. 6 | 7 | Redistribution and use in source and binary forms, with or without 8 | modification, are permitted provided that the following conditions are met: 9 | * Redistributions of source code must retain the above copyright 10 | notice, this list of conditions and the following disclaimer. 11 | * Redistributions in binary form must reproduce the above copyright 12 | notice, this list of conditions and the following disclaimer in the 13 | documentation and/or other materials provided with the distribution. 14 | * Neither the name of the author nor the 15 | names of his contributors may be used to endorse or promote products 16 | derived from this software without specific prior written permission. 17 | 18 | THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND 19 | ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED 20 | WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE 21 | DISCLAIMED. IN NO EVENT SHALL OLIVIER BREULEUX BE LIABLE FOR ANY 22 | DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES 23 | (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; 24 | LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND 25 | ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT 26 | (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS 27 | SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 28 | -------------------------------------------------------------------------------- /MANIFEST.in: -------------------------------------------------------------------------------- 1 | include little_pger.py 2 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Little_PGer.py 2 | 3 | ## What is it? 4 | 5 | It's a thin layer just a tad above SQL, for use with Postgres and 6 | [psycopg2](http://www.initd.org/psycopg/), when you want to wrap 7 | queries in a convenient way, using plain data structures (but you 8 | don't feel like using an ORM, for some reason). 9 | 10 | ## Why? 11 | 12 | Of course `psycopg2` already does a very fine job on its own, but in 13 | the context of webapp backend development, I often found myself 14 | wanting for an extra-frictionless way of shuffling around Ajax/JSON 15 | data. As composing raw SQL queries quickly induces string-manipulation 16 | fatigue, I gradually evolved `little_pger` for that simple purpose. 17 | 18 | If you want to know more about it, I have also discussed its use in 19 | some particular contexts, on my blog: 20 | 21 | * 22 | 23 | * 24 | 25 | ## To install 26 | 27 | $ pip install little_pger 28 | 29 | or 30 | 31 | $ pip install -e git+git@github.com:cjauvin/little_pger.git#egg=little_pger 32 | 33 | Note that `psycopg2` will be automatically installed if it isn't 34 | already. 35 | 36 | ## Testing it with this README document 37 | 38 | Note that this `README.md` file can be executed as a test suite. To do 39 | so, simply create a dummy database (that you can destroy afterward): 40 | 41 | $ createdb little_pger_test -U 42 | 43 | and set this variable appropriately for your setup: 44 | 45 | ```python 46 | >>> pg_user = '' # an empty string works when the OS and PG users share the same name 47 | 48 | ``` 49 | 50 | Then simply execute the script with: 51 | 52 | $ python -m doctest -f -v README.md 53 | 54 | Let's go! 55 | 56 | ```python 57 | >>> from little_pger import LittlePGer 58 | 59 | ``` 60 | 61 | The first and mandatory parameter to a `LittlePGer` object is a 62 | connection, either as a string or as a `psycopg2` object (resulting 63 | from `psycopg2.connect`). A `LittlePGer` object can be used in two 64 | ways. The first is as a context manager, which implies that the 65 | transaction is encapsulated under the `with` statement (with a 66 | `rollback` or `commit` performed automatically at exit): 67 | 68 | ```python 69 | >>> conn_str = 'dbname=little_pger_test user={}'.format(pg_user) 70 | >>> with LittlePGer(conn=conn_str, commit=False) as pg: 71 | ... _ = pg.pg_version # (9, 5, 0) for me, perhaps not for you 72 | 73 | ``` 74 | 75 | You can also use it without the context manager: 76 | 77 | ```python 78 | >>> pg = LittlePGer(conn=conn_str, commit=False) 79 | >>> _ = pg.pg_version # (9, 5, 0) for me, perhaps not for you 80 | 81 | ``` 82 | 83 | in which case you are in charge of managing the transaction 84 | yourself. In this document we will not use the context manager because 85 | it makes things easier on the eyes. 86 | 87 | ## Insert and update 88 | 89 | Suppose we have two SQL tables: 90 | 91 | ```python 92 | >>> pg.sql(""" 93 | ... create table book ( 94 | ... book_id serial primary key, 95 | ... author_id int, 96 | ... title text, 97 | ... n_pages int, 98 | ... topics text[] 99 | ... ) 100 | ... """) 101 | 102 | >>> pg.sql(""" 103 | ... create table author ( 104 | ... author_id serial primary key, 105 | ... name text 106 | ... ) 107 | ... """) 108 | 109 | ``` 110 | 111 | you can `insert` a new `book`, along with its `author`: 112 | 113 | ```python 114 | >>> book = pg.insert('book', values={'title': 'PG is Fun!'}) 115 | >>> author = pg.insert('author', values={'name': 'Joe Foo', 'author_id': 100}) 116 | 117 | ``` 118 | 119 | and `update` it: 120 | 121 | ```python 122 | >>> book = pg.update( 123 | ... 'book', set={'author_id': author['author_id'], 'n_pages': 200}, 124 | ... where={'book_id': book['book_id']} 125 | ... ) 126 | >>> sorted(book.items()) # just to clamp the field order 127 | [('author_id', 100), ('book_id', 1), ('n_pages', 200), ('title', 'PG is Fun!'), ('topics', None)] 128 | 129 | ``` 130 | 131 | As shown above, `insert` and `update` by default return a `dict` 132 | record. However, `insert` has a convenient `return_id` keyword 133 | argument, which means that the primary key value of the newly 134 | created record should be returned directly: 135 | 136 | ```python 137 | >>> pg.insert( 138 | ... 'book', values={'title': 'Python and PG, a Love Story'}, 139 | ... return_id=True 140 | ... ) 141 | 2 142 | 143 | ``` 144 | 145 | ## Upsert 146 | 147 | Even though `upsert` only appeared recently (with PG 9.5), 148 | `little_pger` supports it for every version of PG, with a "fake 149 | implementation" (i.e. check existence, then insert or update 150 | accordingly) in the cases where it is not natively supported (and when 151 | it is, a "real" implementation is used). Both implementations are 152 | simplified versions where the primary key is implicitly used to 153 | determine uniqueness. 154 | 155 | ```python 156 | >>> # does not yet exist, will be created 157 | >>> book_id = pg.upsert('book', set={'title': 'A Boring Story'}, return_id=True) 158 | >>> book_id 159 | 3 160 | 161 | >>> # already exists, will be updated 162 | >>> book = pg.upsert('book', values={'n_pages': 123, 'book_id': book_id}) 163 | >>> book_id, book['book_id'] 164 | (3, 3) 165 | 166 | ``` 167 | 168 | `insert`, `update` and `upsert` all have a convenient `filter_values` 169 | parameter which, if used, will remove any item in the `values` dict 170 | that doesn't belong to the target table. Without it here, an exception 171 | would be thrown, as the `book` table does not have a `publisher` 172 | column: 173 | 174 | ```python 175 | >>> _ = pg.upsert( 176 | ... 'book', filter_values=True, 177 | ... values={'book_id': book_id, 'publisher': 'Joe North'} 178 | ... ) 179 | 180 | ``` 181 | 182 | ## Select 183 | 184 | To `select` all books: 185 | 186 | ```python 187 | >>> books = pg.select('book') 188 | >>> len(books) 189 | 3 190 | 191 | ``` 192 | 193 | or a particular book: 194 | 195 | ```python 196 | >>> books = pg.select('book', where={'book_id': book_id}) 197 | >>> len(books) 198 | 1 199 | 200 | ``` 201 | 202 | or: 203 | 204 | ```python 205 | >>> book = pg.select1('book', where={'book_id': book_id}) 206 | >>> type(book) 207 | 208 | 209 | ``` 210 | 211 | It's easy to (inner) join books and authors: 212 | 213 | ```python 214 | >>> book = pg.select1( 215 | ... 'book', join='author', where={'book_id': 1} 216 | ... ) 217 | >>> sorted(book.items()) # just to clamp the field order 218 | [('author_id', 100), ('book_id', 1), ('n_pages', 200), ('name', 'Joe Foo'), ('title', 'PG is Fun!'), ('topics', None)] 219 | 220 | ``` 221 | 222 | or left join them: 223 | 224 | ```python 225 | >>> book_author = pg.select1( 226 | ... 'book', left_join='author', where={'book_id': 2} 227 | ... ) 228 | >>> sorted(book_author.items()) # just to clamp the field order 229 | [('author_id', None), ('book_id', 2), ('n_pages', None), ('name', None), ('title', 'Python and PG, a Love Story'), ('topics', None)] 230 | 231 | ``` 232 | 233 | Using a `tuple` value in the `where` clause: 234 | 235 | ```python 236 | >>> books = pg.select('book', where={'book_id': (1, 2, 3)}) 237 | >>> len(books) 238 | 3 239 | 240 | ``` 241 | 242 | translates to a SQL query using the `in` operator: 243 | 244 | ```sql 245 | select * from book where book_id in (1, 2, 3) 246 | ``` 247 | 248 | Make sure that you do not use `tuple`s and `list`s interchangeably 249 | when working with `psycopg2` and `little_pger`, as they are used for 250 | very different purposes. Python arrays translate into PG arrays (note 251 | that the `book.topics` column has type `text[]`): 252 | 253 | ```python 254 | >>> book = pg.update( 255 | ... 'book', set={'topics': ['database', 'programming']}, 256 | ... where={'book_id': 1} 257 | ... ) 258 | >>> book['topics'] 259 | ['database', 'programming'] 260 | 261 | ``` 262 | 263 | You can use operators other than `=`, like this: 264 | 265 | ```python 266 | >>> books = pg.select('book', where={('book_id', '<='): 2}) 267 | >>> len(books) 268 | 2 269 | 270 | ``` 271 | 272 | Using a `set` (instead of a `tuple` or a `list`) will result in a 273 | third type of semantics: 274 | 275 | ```python 276 | >>> pg.select1( 277 | ... 'book', where={('title', 'like'): {'%PG%', '%Fun%'}} 278 | ... )['title'] 279 | 'PG is Fun!' 280 | 281 | ``` 282 | 283 | which translates to: 284 | 285 | ```sql 286 | select * from book where title like '%PG%' and title like '%Fun%' 287 | ``` 288 | 289 | which can be a powerful way to implement an autocomplete mechanism, 290 | [as I explain in more details elsewhere](http://cjauvin.blogspot.ca/2012/10/a-tribute-to-unsung-pattern.html). 291 | 292 | Until now we have assumed `*` selection, but the `what` keyword allows 293 | for more flexibility: 294 | 295 | ```python 296 | >>> res = pg.select( 297 | ... 'book', what={'*':1, 'title is not null': 'has_title'} 298 | ... ) 299 | >>> [book['has_title'] for book in res] 300 | [True, True, True] 301 | 302 | ``` 303 | 304 | Similarly: 305 | 306 | ```python 307 | >>> res = pg.select( 308 | ... 'book', left_join='author', 309 | ... what=['name', 'count(*)'], 310 | ... group_by='name', order_by='count desc' 311 | ... ) 312 | >>> res[0]['name'], int(res[0]['count']) 313 | (None, 2) 314 | >>> res[1]['name'], int(res[1]['count']) 315 | ('Joe Foo', 1) 316 | 317 | ``` 318 | 319 | ## Delete 320 | 321 | The `delete` function includes an option to "tighten" the 322 | primary key sequence, to make sure that if you delete a row with some 323 | ID that is the maximum one currently existing, it will be reused the 324 | next time you create a new row (in other words: it prevents "gaps" in 325 | the ID sequences). 326 | 327 | Without `tighten_sequence`: 328 | 329 | ```python 330 | >>> pg.delete('book', where={'book_id': 3}) 331 | >>> pg.insert('book', return_id=True) 332 | 4 333 | 334 | ``` 335 | 336 | With it: 337 | 338 | ```python 339 | >>> pg.delete('book', where={'book_id': 4}, tighten_sequence=True) 340 | >>> pg.insert('book', return_id=True) 341 | 3 342 | 343 | ``` 344 | -------------------------------------------------------------------------------- /little_pger.py: -------------------------------------------------------------------------------- 1 | """A thin PostgreSQL/Psycopg2 wrapper, using only plain data structures. 2 | 3 | .. moduleauthor:: Christian Jauvin 4 | 5 | """ 6 | from collections import namedtuple 7 | from collections.abc import Hashable 8 | import psycopg2.extras 9 | import re 10 | 11 | 12 | # Helper functions 13 | 14 | def _flatten(values): 15 | v = [] 16 | for val in values: 17 | if isinstance(val, set): 18 | v += list(val) 19 | else: 20 | v.append(val) 21 | return v 22 | 23 | 24 | # returns a triple: (field, comp_operator, value placeholder) 25 | def _get_where_clause_comp_item(c, v): 26 | if isinstance(c, tuple): 27 | assert len(c) in [2, 3] 28 | if len(c) == 2: 29 | # (field, comp_operator, value placeholder) 30 | return c + ('%s',) 31 | elif len(c) == 3: 32 | # (field, comp_operator, transformed value placeholder) 33 | return ('%s(%s)' % (c[2], c[0]), c[1], '%s(%%s)' % c[2]) 34 | if isinstance(v, tuple): 35 | return (c, 'in', '%s') 36 | return (c, '=', '%s') 37 | 38 | 39 | def _get_where_clause(items, type_='and'): 40 | assert type_ in ('and', 'or') 41 | wc = [] 42 | for c, v in items: 43 | if c == 'exists': 44 | assert isinstance(v, str) 45 | wc.append('exists (%s)' % v) 46 | elif isinstance(v, set): 47 | sub_wc = ' and '.join(['%s %s %s' % _get_where_clause_comp_item(c, vv) for vv in v]) # noqa 48 | wc.append('(%s)' % sub_wc) 49 | else: 50 | wc.append('%s %s %s' % _get_where_clause_comp_item(c, v)) 51 | return (" %s " % type_).join(wc) 52 | 53 | 54 | def _check_args(func_name, args, allowed_args): 55 | if not set(args) <= set(allowed_args): 56 | s = 'unexpected keyword argument(s) in {}: {}' 57 | s = s.format(func_name, list(set(args) - set(allowed_args))) 58 | raise TypeError(s) 59 | return True 60 | 61 | 62 | TableInfos = namedtuple( 63 | 'TableInfo', 64 | ['pkey', 'columns'] 65 | ) 66 | 67 | 68 | class LittlePGerError(Exception): 69 | pass 70 | 71 | 72 | class LittlePGer(object): 73 | 74 | def __init__(self, conn, commit=False): 75 | if isinstance(conn, str): 76 | self.conn = psycopg2.connect(conn) 77 | else: 78 | self.conn = conn 79 | self.cursor = self.conn.cursor( 80 | cursor_factory=psycopg2.extras.RealDictCursor 81 | ) 82 | self._table_infos = {} # name -> TableInfos 83 | self._to_commit = commit 84 | self.pg_version = self.get_pg_version() 85 | if self.pg_version >= (9, 5): 86 | self._upsert_impl = self._real_upsert 87 | else: 88 | self._upsert_impl = self._fake_upsert 89 | 90 | def __enter__(self): 91 | return LittlePGer(self.conn, self._to_commit) 92 | 93 | def __exit__(self, exc_type, exc_value, traceback): 94 | if self._to_commit: 95 | self.commit() 96 | # print('commit') 97 | else: 98 | self.conn.rollback() 99 | # print('rollback') 100 | 101 | def commit(self): 102 | if not self._to_commit: 103 | raise LittlePGerError('asking to commit when _to_commit is False') 104 | self.conn.commit() 105 | 106 | def rollback(self): 107 | self.conn.rollback() 108 | 109 | def get_pg_version(self): 110 | self.cursor.execute('select version() as ver') 111 | rec = self.cursor.fetchone() 112 | return tuple( 113 | [int(d) for d in re.search('PostgreSQL ([0-9.]+)', rec['ver']).group(1).split('.')] # noqa 114 | ) 115 | 116 | def select(self, table, **kw): 117 | """SQL select statement helper. 118 | 119 | Mandatory positional argument: 120 | table -- name of the table 121 | 122 | Optional keyword arguments: 123 | what -- projection items (str, list or dict, default '*') 124 | ex1: what='color' --> "select color from .." 125 | ex2: what=['color', 'name'] --> "select color, name from .." 126 | ex3: what='max(price)' --> "select max(price) from .." 127 | ex4: what={'*':True, 'price is null':'is_price_valid'} --> "select *, price is null as is_price_valid from .." 128 | ex5: what=['age', 'count(*)'], group_by='age' --> "select age, count(*) from .. group by age" 129 | [inner_]join -- either: table `str` or (table, field) `tuple`, (or list of those) 130 | left_join -- similar to join 131 | right_join -- similar to join 132 | where -- AND-joined where clause dict (default empty) 133 | where_or -- OR-joined where clause dict (default empty) 134 | group_by -- group by clause (str or list, default None) 135 | order_by -- order by clause (str or list, default None) 136 | limit -- limit clause (default None) 137 | offset -- offset clause (default None) 138 | rows -- all, or one row (default 'all'; if 'one', will assert that len <= 1) 139 | get_count -- wrap the entire query inside a select count(*) outer query (default False) 140 | debug_print -- print query before executing it (default False) 141 | debug_assert -- throw assert exception (showing query), without executing it; 142 | useful for web dev debugging (default False) 143 | 144 | """ 145 | _check_args('select', kw.keys(), ( 146 | 'what', 'join', 'inner_join', 'left_join', 'right_join', 'where', 147 | 'where_or', 'order_by', 'group_by', 'limit', 'offset', 'rows', 148 | 'get_count', 'debug_print', 'debug_assert' 149 | )) 150 | what = kw.pop('what', '*') 151 | inner_join = kw.pop('join', kw.pop('inner_join', {})) 152 | left_join = kw.pop('left_join', {}) 153 | right_join = kw.pop('right_join', {}) 154 | where = kw.pop('where', {}).copy() # need a copy because we might pop an 'exists' item 155 | where_or = kw.pop('where_or', {}).copy() # idem 156 | order_by = kw.pop('order_by', None) 157 | group_by = kw.pop('group_by', None) 158 | limit = kw.pop('limit', None) 159 | offset = kw.pop('offset', None) 160 | rows = kw.pop('rows', 'all') 161 | if rows not in ('all', 'one'): 162 | raise LittlePGerError('rows arg should be either all or one') 163 | get_count = kw.pop('get_count', False) 164 | proj_items = [] 165 | if what: 166 | if isinstance(what, dict): 167 | proj_items = [ 168 | '%s%s' % (w, ' as %s' % n if isinstance(n, str) else '') 169 | for w, n in what.items() 170 | ] 171 | elif isinstance(what, str): 172 | proj_items = [what] 173 | else: 174 | proj_items = list(what) 175 | # if isinstance(table, dict): 176 | # table = ['%s %s' % (t, a) for t, a in table.items()] 177 | # elif isinstance(table, string_types): 178 | # table = [table] 179 | # else: 180 | # table = list(table) 181 | # q = "select %s from %s " % (', '.join(proj_items), ', '.join(table)) 182 | assert isinstance(table, str) 183 | q = "select {proj} from {table} ".format( 184 | proj=', '.join(proj_items), 185 | table=table 186 | ) 187 | 188 | jj = [(inner_join, 'inner'), (left_join, 'left'), (right_join, 'right')] 189 | for join_elem, join_type in jj: 190 | if not join_elem: 191 | continue 192 | for e in (join_elem if isinstance(join_elem, list) else [join_elem]): 193 | if isinstance(e, str): 194 | pkey = self.get_table_infos(e.split()[0]).pkey # split()[0] in case of a 'bla b' pattern 195 | q += ' %s join %s using (%s)' % (join_type, e, pkey) 196 | elif isinstance(e, tuple): 197 | # if len(e) == 3: 198 | # t, f1, f2 = e 199 | # q += ' %s join %s on %s = %s' % (join_type, t, f1, f2) 200 | if len(e) == 2: 201 | t, f = e 202 | q += ' %s join %s using (%s)' % (join_type, t, f) 203 | else: 204 | raise LittlePGerError('wrong data type for `join`: can only be table_as_str, a (table_as_str, field_as_str) tuple, or a list of those') 205 | else: 206 | raise LittlePGerError('wrong data type for `join`: can only be table_as_str, a (table_as_str, field_as_str) tuple, or a list of those') 207 | 208 | q += ' where true ' 209 | 210 | if where: 211 | where_clause = _get_where_clause(where.items()) 212 | q += " and %s" % where_clause 213 | where.pop('exists', None) 214 | if where_or: 215 | where_or_clause = _get_where_clause(where_or.items(), 'or') 216 | q += ' and (%s)' % where_or_clause 217 | where_or.pop('exists', None) 218 | if group_by: 219 | if isinstance(group_by, str): q += ' group by %s' % group_by 220 | else: q += ' group by %s' % ', '.join([e for e in group_by]) 221 | if order_by: 222 | if isinstance(order_by, str): q += ' order by %s' % order_by 223 | else: q += ' order by %s' % ', '.join([e for e in order_by]) 224 | if limit: q += ' limit %s' % limit 225 | if offset: q += ' offset %s' % offset 226 | if get_count: 227 | q = 'select count(*) from (%s) _' % q 228 | rows = 'one' 229 | self._exec_query(q, list(where.values()) + list(where_or.values()), **kw) 230 | results = self.cursor.fetchall() 231 | if rows == 'all': 232 | return results 233 | elif rows == 'one': 234 | if len(results) > 1: 235 | raise LittlePGerError('your query returns more than one row') 236 | return results[0] if results else None 237 | 238 | def select1(self, table, **kw): 239 | """SQL select statement helper (syntactic sugar for single row select call). 240 | 241 | Mandatory positional argument: 242 | table -- name of the table 243 | 244 | Optional keyword arguments: 245 | what -- projection items (str, list or dict, default '*') 246 | ex1: what='color' --> "select color from .." 247 | ex2: what=['color', 'name'] --> "select color, name from .." 248 | ex3: what='max(price)' --> "select max(price) from .." 249 | ex4: what={'*':True, 'price is null':'is_price_valid'} --> "select *, price is null as is_price_valid from .." 250 | ex5: what=['age', 'count(*)'], group_by='age' --> "select age, count(*) from .. group by age" 251 | [inner_]join -- either: table `str` or (table, field) `tuple`, (or list of those) 252 | left_join -- similar to join 253 | right_join -- similar to join 254 | where -- AND-joined where clause dict (default empty) 255 | where_or -- OR-joined where clause dict (default empty) 256 | group_by -- group by clause (str or list, default None) 257 | order_by -- order by clause (str or list, default None) 258 | limit -- limit clause (default None) 259 | offset -- offset clause (default None) 260 | debug_print -- print query before executing it (default False) 261 | debug_assert -- throw assert exception (showing query), without executing it; 262 | useful for web dev debugging (default False) 263 | 264 | """ 265 | _check_args('select1', kw.keys(), ( 266 | 'what', 'join', 'inner_join', 'left_join', 'right_join', 'where', 267 | 'where_or', 'order_by', 'group_by','limit','offset','debug_print', 268 | 'debug_assert' 269 | )) 270 | return self.select(table, rows='one', **kw) 271 | 272 | def select_id(self, table, **kw): 273 | """SQL select statement helper (fetch primary key value, assuming only one row). 274 | 275 | Mandatory positional argument: 276 | table -- name of the table 277 | 278 | Optional keyword arguments: 279 | where -- AND-joined where clause dict (default empty) 280 | where_or -- OR-joined where clause dict (default empty) 281 | debug_print -- print query before executing it (default False) 282 | debug_assert -- throw assert exception (showing query), without executing it; 283 | useful for web dev debugging (default False) 284 | 285 | """ 286 | _check_args('select_id', kw.keys(), ( 287 | 'where', 'where_or', 'debug_print', 'debug_assert' 288 | )) 289 | pkey = self.get_table_infos(table).pkey 290 | row = self.select1(table, **kw) 291 | return row[pkey] if row else None 292 | 293 | def insert(self, table, **kw): 294 | """SQL insert statement helper, by default with a "returning *" clause. 295 | 296 | Mandatory positional argument: 297 | table -- name of the table 298 | 299 | Optional keyword arguments: 300 | values -- dict with values to set (default empty) 301 | filter_values -- if True, trim values so that it contains only columns found in table (default False) 302 | map_values -- dict containing a mapping to be performed on 'values' (e.g. {'': None}, to convert empty strings to nulls) 303 | return_id -- (potentially unsafe, use with caution) if True, will select the primary key value among the returning clause 304 | elements (assuming it has a "_id" name form if using a dict-like cursor, or that it's 305 | at position 0 otherwise) 306 | debug_print -- print query before executing it (default False) 307 | debug_assert -- throw assert exception (showing query), without executing it; 308 | useful for web dev debugging (default False) 309 | 310 | """ 311 | _check_args('insert', kw.keys(), ( 312 | 'values', 'filter_values', 'map_values', 'return_id', 313 | 'debug_print','debug_assert' 314 | )) 315 | values = kw.pop('values', {}) 316 | return_id = kw.pop('return_id', False) 317 | if not values: 318 | q = "insert into %s default values returning *" % table 319 | else: 320 | if kw.pop('filter_values', False): 321 | columns = self.get_table_infos(table).columns 322 | values = {c: v for c, v in values.items() if c in columns} 323 | map_values = kw.pop('map_values', {}) 324 | values = { 325 | k: (map_values.get(v, v) if isinstance(v, Hashable) else v) 326 | for k, v in values.items() 327 | } 328 | q = "insert into {table} ({fields}) values ({values}) returning *" 329 | q = q.format( 330 | table=table, 331 | fields=','.join(values.keys()), 332 | values=','.join('%s' for v in values) 333 | ) 334 | self._exec_query(q, values.values(), **kw) 335 | returning = self.cursor.fetchone() 336 | if return_id: 337 | return returning[self.get_table_infos(table).pkey] 338 | else: 339 | return returning 340 | 341 | def update(self, table, **kw): 342 | """SQL update statement helper, with a "returning *" clause. 343 | 344 | Mandatory positional argument: 345 | table -- name of the table 346 | 347 | Optional keyword arguments: 348 | set|values -- dict with values to set (either keyword works; default empty) 349 | where -- AND-joined where clause dict (default empty) 350 | where_or -- OR-joined where clause dict (default empty) 351 | filter_values -- if True, trim values so that it contains only columns found in table (default False) 352 | map_values -- dict containing a mapping to be performed on 'values' (e.g. {'': None}, to convert empty strings to nulls) 353 | debug_print -- print query before executing it (default False) 354 | debug_assert -- throw assert exception (showing query), without executing it; 355 | useful for web dev debugging (default False) 356 | 357 | """ 358 | _check_args('update', kw.keys(), ( 359 | 'set', 'values', 'where', 'where_or', 'filter_values', 360 | 'map_values', 'debug_print','debug_assert' 361 | )) 362 | values = kw.pop('values', kw.pop('set', {})) 363 | where = kw.pop('where', {}) 364 | where_or = kw.pop('where_or', {}) 365 | if kw.pop('filter_values', False): 366 | columns = self.get_table_infos(table).columns 367 | values = {c: v for c, v in values.items() if c in columns} 368 | map_values = kw.pop('map_values', {}) 369 | values = { 370 | k: (map_values.get(v, v) if isinstance(v, Hashable) else v) 371 | for k, v in values.items() 372 | } 373 | # This is needed for PG >= 10 374 | if len(values) > 1: 375 | q = 'update {table} set ({fields}) = ({placeholders})' 376 | else: 377 | q = 'update {table} set {fields} = {placeholders}' 378 | q = q.format( 379 | table=table, 380 | fields=','.join(values.keys()), 381 | placeholders=','.join(['%s' for _ in values]) 382 | ) 383 | if where: 384 | where_clause = _get_where_clause(where.items()) 385 | q += " where %s" % where_clause 386 | if where_or: 387 | where_or_clause = _get_where_clause(where_or.items(), 'or') 388 | if where: 389 | q += ' and (%s)' % where_or_clause 390 | else: 391 | q += ' where %s' % where_or_clause 392 | q += ' returning *' 393 | vals = list(values.values()) + list(where.values()) + list(where_or.values()) 394 | self._exec_query(q, vals, **kw) 395 | return self.cursor.fetchone() 396 | 397 | def upsert(self, table, **kw): 398 | """SQL insert/update statement helper, with a "returning *" clause. 399 | 400 | Mandatory positional argument: 401 | table -- name of the table 402 | 403 | Optional keyword arguments: 404 | set|values -- dict with values to set (either keyword works; default empty) 405 | filter_values -- if True, trim values so that it contains only columns found in table (default False) 406 | map_values -- dict containing a mapping to be performed on 'values' (e.g. {'': None}, to convert empty strings to nulls) 407 | debug_print -- print query before executing it (default False) 408 | debug_assert -- throw assert exception (showing query), without executing it; 409 | useful for web dev debugging (default False) 410 | 411 | """ 412 | _check_args('upsert', kw.keys(), ( 413 | 'set', 'values', 'filter_values', 'map_values', 'return_id', 'debug_print', 'debug_assert' 414 | )) 415 | return self._upsert_impl(table, **kw) 416 | 417 | def _fake_upsert(self, table, **kw): 418 | values = kw.pop('values', kw.pop('set', {})) 419 | kw['values'] = values 420 | pkey = self.get_table_infos(table).pkey 421 | if pkey in values and select1(cursor, table, where={pkey: values[pkey]}): 422 | kw['values'] = values 423 | kw['where'] = {pkey: values[pkey]} 424 | return self.update(table, **kw) 425 | else: 426 | return self.insert(table, **kw) 427 | 428 | def _real_upsert(self, table, **kw): 429 | values = kw.pop('values', kw.pop('set', {})) 430 | return_id = kw.pop('return_id', False) 431 | if not values: 432 | q = "insert into %s default values returning *" % table 433 | else: 434 | pkey = self.get_table_infos(table).pkey 435 | if kw.pop('filter_values', False): 436 | columns = self.get_table_infos(table).columns 437 | values = {c: v for c, v in values.items() if c in columns} 438 | # remove null primary key value 439 | if pkey in values and not values[pkey]: 440 | del values[pkey] 441 | map_values = kw.pop('map_values', {}) 442 | values = { 443 | k: map_values.get(v, v) if isinstance(v, Hashable) else v 444 | for k, v in values.items() 445 | } 446 | fields = ','.join(values.keys()) 447 | vals = ','.join(['%s' for _ in values]) 448 | updates = ','.join(['%s = excluded.%s' % (c, c) for c in values.keys()]) 449 | q = """ 450 | insert into {table} ({fields}) values ({vals}) 451 | on conflict ({pkey}) do update set {updates} returning * 452 | """ 453 | q = q.format( 454 | table=table, 455 | fields=fields, 456 | vals=vals, 457 | pkey=pkey, 458 | updates=updates 459 | ) 460 | self._exec_query(q, values.values(), **kw) 461 | returning = self.cursor.fetchone() 462 | if return_id: 463 | return returning[self.get_table_infos(table).pkey] 464 | else: 465 | return returning 466 | 467 | def delete(self, table, **kw): 468 | """SQL delete statement helper. 469 | 470 | Mandatory positional argument: 471 | table -- name of the table 472 | 473 | Optional keyword arguments: 474 | where -- AND-joined where clause dict (default empty) 475 | where_or -- OR-joined where clause dict (default empty) 476 | tighten_sequence -- if True, will decrement the pkey sequence when deleting the latest row, 477 | and has no effect otherwise (default False) 478 | debug_print -- print query before executing it (default False) 479 | debug_assert -- throw assert exception (showing query), without executing it; 480 | useful for web dev debugging (default False) 481 | 482 | """ 483 | _check_args('delete', kw.keys(), ( 484 | 'where','where_or','tighten_sequence','debug_print','debug_assert' 485 | )) 486 | where = kw.pop('where', {}) 487 | where_or = kw.pop('where_or', {}) 488 | q = "delete from %s" % table 489 | if where: 490 | where_clause = _get_where_clause(where.items()) 491 | q += " where %s" % where_clause 492 | if where_or: 493 | where_or_clause = _get_where_clause(where_or.items(), 'or') 494 | if where: 495 | q += ' and (%s)' % where_or_clause 496 | else: 497 | q += ' where %s' % where_or_clause 498 | ts_vals = [] 499 | if kw.pop('tighten_sequence', False): 500 | pkey = self.get_table_infos(table).pkey 501 | q += "; select setval(%%s, coalesce((select max(%s) + 1 from %s), 1), false)" % (pkey, table) 502 | ts_vals = [self.get_pkey_sequence(table)] 503 | self._exec_query(q, list(where.values()) + list(where_or.values()) + ts_vals, **kw) 504 | 505 | def count(self, table, **kw): 506 | """SQL select count statement helper. 507 | 508 | Mandatory positional argument: 509 | table -- name of the table 510 | 511 | Optional keyword arguments: 512 | [inner_]join -- either: table `str` or (table, field) `tuple`, (or list of those) 513 | left_join -- similar to join 514 | right_join -- similar to join 515 | left_join -- .. (default empty) 516 | where -- AND-joined where clause dict (default empty) 517 | where_or -- OR-joined where clause dict (default empty) 518 | order_by -- order by clause (str or list, default None) 519 | debug_print -- print query before executing it (default False) 520 | debug_assert -- throw assert exception (showing query), without executing it; 521 | useful for web dev debugging (default False) 522 | 523 | """ 524 | _check_args('count', kw.keys(), ( 525 | 'what', 'join', 'inner_join', 'left_join', 'right_join', 'where', 526 | 'where_or', 'group_by', 'debug_print', 'debug_assert' 527 | )) 528 | if kw.get('group_by', None) is None: 529 | kw.pop('what', None) # if it's there, we can remove it safely, as it won't affect the row count 530 | row = self.select(table, what='count(*)', rows='one', **kw) 531 | else: 532 | row = self.select(table, get_count=True, **kw) 533 | return int(row['count']) 534 | 535 | def exists(self, table, **kw): 536 | """Check whether at least one record exists. 537 | 538 | Mandatory positional argument: 539 | table -- name of the table 540 | 541 | Optional keyword arguments: 542 | what -- projection items (str, list or dict, default '*') 543 | where -- AND-joined where clause dict (default empty) 544 | where_or -- OR-joined where clause dict (default empty) 545 | debug_print -- print query before executing it (default False) 546 | debug_assert -- throw assert exception (showing query), without executing it; 547 | useful for web dev debugging (default False) 548 | 549 | """ 550 | _check_args('exists', kw.keys(), ( 551 | 'what', 'where', 'where_or', 'debug_print', 'debug_assert' 552 | )) 553 | return self.select(table, limit=1, rows='one', **kw) is not None 554 | 555 | def get_table_infos(self, table): 556 | self._table_infos.setdefault(table, TableInfos( 557 | pkey = self.get_pkey_column(table), 558 | columns = self.get_columns(table) 559 | )) 560 | return self._table_infos[table] 561 | 562 | def get_columns(self, table): 563 | """Return all columns. 564 | 565 | Mandatory positional argument: 566 | table -- name of the table 567 | 568 | """ 569 | self.cursor.execute('select * from %s where 1=0' % table) 570 | return [rec[0] for rec in self.cursor.description] 571 | 572 | # http://wiki.postgresql.org/wiki/Retrieve_primary_key_columns 573 | def get_pkey_column(self, table): 574 | self.cursor.execute(""" 575 | select pg_attribute.attname as pkey_name 576 | from pg_index, pg_class, pg_attribute 577 | where 578 | pg_class.oid = %s::regclass and indrelid = pg_class.oid and 579 | pg_attribute.attrelid = pg_class.oid and 580 | pg_attribute.attnum = any(pg_index.indkey) and indisprimary; 581 | """, [table]) 582 | return (self.cursor.fetchone() or {}).get('pkey_name') 583 | 584 | def _exec_query(self, query, qvalues=[], **kw): 585 | """(Internal, should not be used) Execute a query. 586 | 587 | Mandatory positional arguments: 588 | query -- query string (with %%s value placeholders if needed) 589 | qvalues -- query value list (default empty) 590 | 591 | Optional keyword arguments: 592 | debug_print -- print query before executing it (default False) 593 | debug_assert -- throw assert exception (showing query), without executing it; 594 | useful for web dev debugging (default False) 595 | 596 | """ 597 | # Should I add a switch to prevent setting transform_null_equals to on? 598 | _check_args('_exec_query', kw.keys(), ('debug_print','debug_assert')) 599 | query = "set transform_null_equals to on; " + query 600 | qvalues = _flatten(qvalues) 601 | if kw.get('debug_print', False): 602 | print(self.cursor.mogrify(query if isinstance(query, str) else query.encode('utf8'), qvalues)) 603 | if kw.get('debug_assert', False): 604 | assert False, self.cursor.mogrify(query if isinstance(query, str) else query.encode('utf8'), qvalues) 605 | self.cursor.execute(query, qvalues) 606 | 607 | def get_pkey_sequence(self, table): 608 | self.cursor.execute(""" 609 | select pg_get_serial_sequence(%s, a.attname) seq_name 610 | from pg_index i, pg_class c, pg_attribute a 611 | where 612 | c.oid = %s::regclass and indrelid = c.oid and 613 | a.attrelid = c.oid and a.attnum = any(i.indkey) and indisprimary; 614 | """, [table, table]) 615 | return (self.cursor.fetchone() or {}).get('seq_name') 616 | 617 | def get_current_pkey_value(self, table, **kw): 618 | """Current value of the primary key. 619 | 620 | Mandatory positional argument: 621 | table -- name of the table 622 | 623 | Optional keyword arguments: 624 | pkey_seq_name -- if None (default), assume that the primary key sequence name has the 625 | form "
_
_id_seq" 626 | debug_print -- print query before executing it (default False) 627 | debug_assert -- throw assert exception (showing query), without executing it; 628 | useful for web dev debugging (default False) 629 | 630 | """ 631 | _check_args('get_current_pkey_value', kw.keys(), ( 632 | 'pkey_seq_name','debug_print','debug_assert' 633 | )) 634 | pkey_seq_name = kw.pop('pkey_seq_name', '%s_%s_id_seq' % (table, table)) 635 | self._exec_query('select currval(%s)', [pkey_seq_name], **kw) 636 | return self.cursor.fetchone()['currval'] 637 | 638 | def get_next_pkey_value(self, table, **kw): 639 | """Next value of the primary key. 640 | 641 | Mandatory positional argument: 642 | table -- name of the table 643 | 644 | Optional keyword arguments: 645 | pkey_seq_name -- if None (default), assume that the primary key sequence name has the 646 | form "
_
_id_seq" 647 | debug_print -- print query before executing it (default False) 648 | debug_assert -- throw assert exception (showing query), without executing it; 649 | useful for web dev debugging (default False) 650 | 651 | """ 652 | _check_args('get_current_pkey_value', kw.keys(), ( 653 | 'pkey_seq_name','debug_print','debug_assert' 654 | )) 655 | pkey_seq_name = kw.pop('pkey_seq_name', '%s_%s_id_seq' % (table, table)) 656 | self._exec_query('select nextval(%s)', [pkey_seq_name], **kw) 657 | return self.cursor.fetchone()['nextval'] 658 | 659 | def get_nullable_columns(self, table, **kw): 660 | """Return all nullable columns. 661 | 662 | Mandatory positional argument: 663 | table -- name of the table 664 | 665 | Optional keyword arguments: 666 | debug_print -- print query before executing it (default False) 667 | debug_assert -- throw assert exception (showing query), without executing it; 668 | useful for web dev debugging (default False) 669 | 670 | """ 671 | _check_args('get_nullable_columns', kw.keys(), ( 672 | 'debug_print', 'debug_assert' 673 | )) 674 | self._exec_query(""" 675 | select * from information_schema.columns 676 | where table_name = %s 677 | """, [table], **kw) 678 | nullable_columns = [ 679 | row['column_name'] for row in self.cursor.fetchall() 680 | if row['is_nullable'] == 'YES' 681 | ] 682 | return nullable_columns 683 | 684 | def sql(self, q, qvals=None): 685 | self.cursor.execute(q, qvals) 686 | -------------------------------------------------------------------------------- /setup.cfg: -------------------------------------------------------------------------------- 1 | [metadata] 2 | description-file = README.md 3 | -------------------------------------------------------------------------------- /setup.py: -------------------------------------------------------------------------------- 1 | from setuptools import setup 2 | 3 | setup( 4 | name = 'little_pger', 5 | version = '1.0.4', 6 | author = 'Christian Jauvin', 7 | author_email = 'cjauvin@gmail.com', 8 | description = ( 9 | "A thin layer just a tad above SQL, for use with PostgreSQL and psycopg2, when you want to wrap queries " 10 | "in a convenient way, using plain data structures (but you don't feel like using an ORM, for some reason)."), 11 | license = 'BSD', 12 | keywords = 'postgresql psycopg2 sql', 13 | url = 'https://github.com/cjauvin/little_pger', 14 | #long_description=open('README.md').read(), 15 | py_modules=['little_pger'], 16 | classifiers=[ 17 | 'Development Status :: 4 - Beta', 18 | 'Intended Audience :: Developers', 19 | 'License :: OSI Approved :: BSD License', 20 | 'Operating System :: OS Independent', 21 | 'Programming Language :: Python', 22 | 'Topic :: Utilities' 23 | ], 24 | install_requires = ['psycopg2-binary'] 25 | ) 26 | --------------------------------------------------------------------------------