├── .coveragerc ├── .github └── workflows │ └── app.yaml ├── .gitignore ├── CHANGELOG.md ├── DEV.md ├── LICENSE ├── README.md ├── conftest.py ├── pyproject.toml ├── pytest.ini ├── requirements-lint.txt ├── requirements-test.txt ├── setup.cfg ├── setup.py ├── sqlbind ├── __init__.py └── py.typed └── tests ├── __init__.py ├── test_sqlbind.py └── test_sqlite3.py /.coveragerc: -------------------------------------------------------------------------------- 1 | [run] 2 | source = sqlbind 3 | 4 | [report] 5 | fail_under = 100 6 | -------------------------------------------------------------------------------- /.github/workflows/app.yaml: -------------------------------------------------------------------------------- 1 | name: sqlbind 2 | 3 | on: 4 | push: 5 | branches: [ "main" ] 6 | pull_request: 7 | branches: [ "main" ] 8 | 9 | permissions: 10 | contents: read 11 | 12 | jobs: 13 | test: 14 | runs-on: ${{ matrix.os }} 15 | strategy: 16 | matrix: 17 | include: 18 | - python: "3.6" 19 | os: "ubuntu-20.04" 20 | - python: "3.8" 21 | os: "ubuntu-20.04" 22 | - python: "3.12" 23 | os: "ubuntu-22.04" 24 | steps: 25 | - uses: actions/checkout@v4 26 | - name: prepare 27 | uses: actions/setup-python@v5 28 | with: 29 | python-version: ${{ matrix.python }} 30 | - name: deps 31 | run: | 32 | pip install -r requirements-test.txt 33 | - name: test 34 | run: python -m coverage run -m pytest 35 | - name: coverage 36 | run: python -m coverage report -m 37 | 38 | lint: 39 | runs-on: ubuntu-latest 40 | steps: 41 | - uses: actions/checkout@v4 42 | - name: prepare 43 | uses: actions/setup-python@v5 44 | with: 45 | python-version: "3.12" 46 | - name: deps 47 | run: pip install -r requirements-lint.txt 48 | - name: black 49 | run: black --check . 50 | - name: mypy 51 | run: mypy --strict sqlbind 52 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | *.pyc 2 | /.coverage 3 | /dist 4 | /build 5 | *.egg-info 6 | -------------------------------------------------------------------------------- /CHANGELOG.md: -------------------------------------------------------------------------------- 1 | # 1.2 2 | 3 | * [Added] `truthy` alias for `not_empty`. 4 | * [Added] LIKE/ILIKE operators for `QueryParams` and `QExpr`. 5 | 6 | # 1.1 7 | 8 | * Accept `Str` where it's possible to be able to use `QExpr` instances. 9 | -------------------------------------------------------------------------------- /DEV.md: -------------------------------------------------------------------------------- 1 | # Requirements 2 | 3 | ``` 4 | pip install twine build 5 | ``` 6 | 7 | # Build 8 | 9 | ``` 10 | python -m build -nw . 11 | ``` 12 | 13 | # Upload 14 | 15 | ``` 16 | TWINE_PASSWORD="$(pass dev/pypy-tokens/all)" twine upload -u __token__ dist/ 17 | ``` 18 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2023 Anton Bobrov 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 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # sqlbind 2 | 3 | **sqlbind** allows to bind parameters in text based raw SQL queries. 4 | 5 | ```python 6 | >>> q = sqlbind.Dialect.default() 7 | >>> email = 'some@domain.com' 8 | >>> sql = f'SELECT * FROM users WHERE email = {q/email}' 9 | >>> sql 10 | 'SELECT * FROM users WHERE email = ?' 11 | >>> q 12 | ['some@domain.com'] 13 | >>> data = connection.execute(sql, q) 14 | 15 | ``` 16 | 17 | Supports all [DBAPI parameter styles][dbapi]. Isn't limited by DBAPI compatible drivers and 18 | could be used with anything accepting raw SQL query and parameters in some way. For example 19 | **sqlbind** could be used with [SQLAlchemy textual queries][sqa-text]. Or with [clickhouse-driver][ch]'s 20 | non-DBAPI interface. 21 | 22 | [dbapi]: https://peps.python.org/pep-0249/#paramstyle 23 | [sqa-text]: https://docs.sqlalchemy.org/en/20/core/sqlelement.html#sqlalchemy.sql.expression.text 24 | [ch]: https://clickhouse-driver.readthedocs.io/en/latest/quickstart.html#selecting-data 25 | 26 | 27 | ## Installation 28 | 29 | ``` 30 | pip install sqlbind 31 | ``` 32 | 33 | 34 | ## Motivation 35 | 36 | ORMs are great and could be used effectively for a huge number of tasks. But 37 | after many years with SQLAlchemy I've noticed some repeating patterns: 38 | 39 | * It's really not an easy task to decipher complex SQLAlchemy expression back into SQL. 40 | Especially when CTEs, sub-queries, nested queries or self-referential queries 41 | are involved. It composes quite well but it takes too much effort to write 42 | and read SQLAlchemy queries. For novices it could be a hard time to deal 43 | with it. 44 | 45 | * Most of reporting queries are big enough already not to be bothered with ORMs and 46 | use raw SQL anyway. This kind of SQL often requires dynamic constructs and becomes 47 | string fiddling contraption. 48 | 49 | * For a few tasks ORMs bring too much overhead and the only solution is to get 50 | down to raw DBAPI connection and raw SQL. 51 | 52 | * (*Minor personal grudge, please ignore it*) For some ORMs (like Django ORM) your 53 | SQL intuition could be useless and requires deep ORM understanding. To the 54 | side: sqlalchemy hybrid properties, cough. 55 | 56 | It boils down to one thing: from time to time you have to write raw 57 | SQL queries. I could highlight 3 types of queries: 58 | 59 | 1. Fixed queries. They don't contain any parameters. For example 60 | `SELECT id, name FROM users ORDER BY registered DESC LIMIT 10`. 61 | In general fixed queries or fixed query parts compose well and don't require any 62 | special treatment. Python's f-strings are enough. 63 | 64 | 2. Static queries. They contain parameters but structure is fully known beforehand. 65 | For example `SELECT id, name FROM users WHERE email = :email LIMIT 1`. They 66 | are also could be composed without large issues, especially for connection 67 | drivers supporting named parameters (`:param`, `%(param)s`) and accepting dicts as parameters. 68 | Although for positional connection drivers (`%s`, `?`) composition requires careful 69 | parameter tracking and queries could be fragile to change. 70 | 71 | 3. Dynamic queries. Query part presence could depend on parameter value or 72 | external condition. For example to provide result on input filter you have 73 | to add CTE and corresponding JOIN to a query. Or add filters only for non 74 | `None` input values. ORMs are effective for composing such queries. Using 75 | raw SQL are almost impossible for abstraction and leads to a complex 76 | boilerplate heavy code. 77 | 78 | Note: here and in following sections I deliberately use simple examples. In real life 79 | there is no need to use **sqlbind** for such kind of queries. 80 | 81 | Note: by composing I mean ability to assemble a final query from parts which could be 82 | abstracted and reused. 83 | 84 | **sqlbind** tries to address issues with static and dynamic query types. It tracks 85 | parameter binds and could help with dynamic query parts. 86 | 87 | 88 | ## Quick start 89 | 90 | Some things to consider: 91 | 92 | * **sqlbind** tries to provide an API for a simple composition of raw SQL. Most 93 | operations return string-like objects ready to be inserted in the final query. 94 | **sqlbind** does trivial things and is easy to reason about. 95 | 96 | * There is a large set of functions/methods to address dynamic queries but you 97 | haven't use it inline in a single query string. You could use variables to 98 | keep query parts and stitch resulted SQL from these parts. 99 | 100 | * This README misses large portions of API. Feel free to explore doc strings 101 | with examples of fully strictly type-hinted **sqlbind**'s source code! 102 | 103 | General use case looks like: 104 | 105 | ```python 106 | # a global alias to a dialect used by connection backend, see `sqlbind.Dialect` 107 | QParams = sqlbind.Dialect.some_dialect 108 | 109 | def get_my_data(value1, value2): 110 | # Construct empty fresh sqlbind.QueryParams 111 | q = QParams() 112 | 113 | # Use `q` to bind parameter values in SQL string. 114 | sql = f'SELECT * FROM table WHERE field1 = {q/value1} AND field2 > {q/value2}' 115 | 116 | # Pass query and parameters into connection's execute. 117 | return get_connection().execute(sql, q).fetchall() 118 | ``` 119 | 120 | 121 | ## Static queries 122 | 123 | For queries or query parts with a known structure the most simple way to bind a parameter is to 124 | use bind operator `/`: 125 | 126 | ```python 127 | >>> date = "2023-01-01" 128 | >>> q = sqlbind.Dialect.default() 129 | >>> f'SELECT * FROM users WHERE registered > {q/date}' 130 | 'SELECT * FROM users WHERE registered > ?' 131 | >>> q 132 | ['2023-01-01'] 133 | 134 | ``` 135 | 136 | Or for named style parameters: 137 | 138 | ```python 139 | >>> date = "2023-01-01" 140 | >>> q = sqlbind.Dialect.default_named() 141 | >>> f'SELECT * FROM users WHERE registered > {q/date}' 142 | 'SELECT * FROM users WHERE registered > :p0' 143 | >>> q 144 | {'p0': '2023-01-01'} 145 | 146 | ``` 147 | 148 | There is no any magic. Bind operator returns a string with a placeholder for a 149 | corresponding dialect and adds parameter's value to `q` object. That's all. 150 | `q` object is inherited from a `dict` or a `list` depending from a used 151 | dialect. 152 | 153 | ```python 154 | >>> value = 10 155 | >>> q = sqlbind.Dialect.default() 156 | >>> q/value 157 | '?' 158 | >>> q 159 | [10] 160 | 161 | ``` 162 | 163 | 164 | Note: there is no much value in **sqlbind** if you have only static 165 | queries and use connection backends accepting named parameters. 166 | 167 | 168 | ## Dynamic queries 169 | 170 | Here begins a fun part. We can't use simple binds for dynamic queries. 171 | For example we have a function returning recently registered users: 172 | 173 | ```python 174 | def get_fresh_users(registered_since: datetime): 175 | q = QParams() # an alias to some dialect to construct sqlbind.QueryParams instance 176 | sql = f'''\ 177 | SELECT * FROM users 178 | WHERE registered > {q/registered_since} 179 | ORDER BY registered 180 | ''' 181 | return connection.execute(sql, q) 182 | ``` 183 | 184 | And later there is a new requirement for the function. It should return only 185 | enabled or only disabled users if corresponding argument is passed. 186 | 187 | ```python 188 | def get_fresh_users(registered_since: datetime, enabled: Optional[bool] = None): 189 | q = QParams() 190 | 191 | if enabled is not None: 192 | enabled_filter = f' AND enabled = {q/enabled}' 193 | else: 194 | enabled_filter = '' 195 | 196 | sql = f'''\ 197 | SELECT * FROM users 198 | WHERE registered > {q/registered_since} {enabled_filter} 199 | ORDER BY registered 200 | ''' 201 | return connection.execute(sql, q) 202 | ``` 203 | 204 | It looks almost pretty. See how `q/enabled` helped to track additional parameter. 205 | But you can predict where we are going. Another one or two 206 | additional filters and it would be a complete mess. Take note how `WHERE` lost `AND` 207 | between two filters. 208 | 209 | 210 | ### q-templates 211 | 212 | In reality bind operator `/` is a sugar on top of generic **sqlbind**'s API to 213 | bind parameters via q-templates. 214 | 215 | ```python 216 | >>> q = sqlbind.Dialect.default() 217 | >>> q('field BETWEEN {} AND {}', 10, 20) 218 | 'field BETWEEN ? AND ?' 219 | >>> q 220 | [10, 20] 221 | 222 | ``` 223 | 224 | `QueryParams` `q` object is also a callable accepting a template with `{}` 225 | placeholders and following parameters to substitute. `q/value` is same as calling 226 | `q('{}', value)` 227 | 228 | ```python 229 | >>> q/10 230 | '?' 231 | >>> q('{}', 10) 232 | '?' 233 | 234 | ``` 235 | 236 | You could use q-templates to bind parameters in complex SQL expressions. 237 | 238 | 239 | ### Conditionals 240 | 241 | `q.cond` could render a q-template as an empty string based on some condition. 242 | 243 | ```python 244 | >>> enabled = True 245 | >>> q.cond(enabled is not None, ' AND enabled = {}', enabled) 246 | ' AND enabled = ?' 247 | >>> enabled = None 248 | >>> q.cond(enabled is not None, ' AND enabled = {}', enabled) 249 | '' 250 | 251 | ``` 252 | 253 | `q.cond` is a generic form. To remove a repetition (`enabled is not 254 | None`/`enabled`) when value is used both in a condition and as a parameter 255 | value there are two helpers for most common cases: 256 | 257 | * `q.not_none`: to check value is not None. 258 | * `q.truthy`: to check value's trueness (`bool(value) is True`). `not_empty` 259 | could be used as an alias to `truthy`. 260 | 261 | ```python 262 | >>> enabled = True 263 | >>> q.not_none(' AND enabled = {}', enabled) 264 | ' AND enabled = ?' 265 | >>> enabled = None 266 | >>> q.not_none(' AND enabled = {}', enabled) 267 | '' 268 | 269 | ``` 270 | 271 | Let's try it in the function: 272 | 273 | ```python 274 | def get_fresh_users(registered_since: datetime, enabled: Optional[bool] = None): 275 | q = QParams() 276 | 277 | enabled_filter = q.not_none(' AND enabled = {}', enabled) 278 | 279 | sql = f'''\ 280 | SELECT * FROM users 281 | WHERE registered > {q/registered_since} {enabled_filter} 282 | ORDER BY registered 283 | ''' 284 | return connection.execute(sql, q) 285 | ``` 286 | 287 | Hmm. But really nothing was changed. You could write previous code with ternary 288 | if/else and it would look the same from semantic standpoint. May be use it 289 | inline? 290 | 291 | 292 | ```python 293 | def get_fresh_users(registered_since: datetime, enabled: Optional[bool] = None): 294 | q = QParams() 295 | 296 | sql = f'''\ 297 | SELECT * FROM users 298 | WHERE registered > {q/registered_since} 299 | {q.not_none(' AND enabled = {}', enabled)} 300 | ORDER BY registered 301 | ''' 302 | return connection.execute(sql, q) 303 | ``` 304 | 305 | Ugh. Abomination, to say at least. 306 | 307 | * `AND` in the middle of a cryptic expression. 308 | * `q.not_none` and `enabled` are far away and it's not obvious they are connected 309 | * expression is too long and noisy 310 | 311 | Let's tackle issues bit by bit. 312 | 313 | 314 | ### `AND_`/`OR_` prependers 315 | 316 | Prependers could render non-empty inputs with corresponding prefixes and empty 317 | string otherwise. 318 | 319 | ```python 320 | >>> AND_('field1 > 1', 'field2 < 1') 321 | 'AND field1 > 1 AND field2 < 1' 322 | >>> OR_('field1 > 1', 'field2 < 1') 323 | 'OR field1 > 1 OR field2 < 1' 324 | >>> AND_(q.not_none('enabled = {}', True)) 325 | 'AND enabled = ?' 326 | >>> AND_(q.not_none('enabled = {}', None)) 327 | '' 328 | 329 | ``` 330 | 331 | Our function with prependers: 332 | 333 | ```python 334 | from sqlbind import AND_ 335 | 336 | def get_fresh_users(registered_since: datetime, enabled: Optional[bool] = None): 337 | q = QParams() 338 | 339 | sql = f'''\ 340 | SELECT * FROM users 341 | WHERE registered > {q/registered_since} 342 | {AND_(q.not_none('enabled = {}', enabled))} 343 | ORDER BY registered 344 | ''' 345 | return connection.execute(sql, q) 346 | ``` 347 | 348 | At least AND is almost on it's place in SQL structure. 349 | 350 | 351 | ### Conditional markers 352 | 353 | Conditional markers `sqlbind.not_none`/`sqlbind.truthy`/`sqlbind.cond` allows to tie conditionals 354 | with a value via `/` operator: 355 | 356 | ```python 357 | >>> q('enabled = {}', sqlbind.not_none/10) 358 | 'enabled = ?' 359 | >>> q('enabled = {}', sqlbind.not_none/None) 360 | '' 361 | 362 | ``` 363 | 364 | Conditional markers return value itself or special UNDEFINED object. 365 | UNDEFINED parameters force expressions to be rendered as empty strings. 366 | 367 | **`sqlbind.not_none`** returns `UNDEFINED` if value is `None`: 368 | 369 | ```python 370 | >>> sqlbind.not_none/10 371 | 10 372 | >>> sqlbind.not_none/None is sqlbind.UNDEFINED 373 | True 374 | 375 | ``` 376 | 377 | **`sqlbind.truthy`** or `sqlbind.not_empty` returns `UNDEFINED` if `bool(value) != True`: 378 | 379 | ```python 380 | >>> sqlbind.truthy/10 381 | 10 382 | >>> sqlbind.not_empty/10 383 | 10 384 | >>> sqlbind.truthy/0 is sqlbind.UNDEFINED 385 | True 386 | 387 | ``` 388 | 389 | **`sqlbind.cond`** returns `UNDEFINED` if condition is False: 390 | 391 | ```python 392 | >>> sqlbind.cond(True)/10 393 | 10 394 | >>> sqlbind.cond(False)/10 is sqlbind.UNDEFINED 395 | True 396 | 397 | ``` 398 | 399 | Note: `sqlbind.cond` is almost always awkward to use inline in real life and exists largely for symmetry with `q.cond`. 400 | 401 | Rewritten function: 402 | 403 | ```python 404 | from sqlbind import AND_, not_none 405 | 406 | def get_fresh_users(registered_since: datetime, enabled: Optional[bool] = None): 407 | q = QParams() 408 | 409 | sql = f'''\ 410 | SELECT * FROM users 411 | WHERE registered > {q/registered_since} 412 | {AND_(q('enabled = {}', not_none/enabled))} 413 | ORDER BY registered 414 | ''' 415 | return connection.execute(sql, q) 416 | ``` 417 | 418 | Almost there. May be there is a way to reduce number of quotes inside `AND_`? 419 | 420 | 421 | ### q-expressions 422 | 423 | q-expressions allow to generate templated results with infix operators. 424 | 425 | Any unknown attribute access to `q` object returns `QExpr` which has str 426 | conversion as an attribute name: 427 | 428 | ```python 429 | >>> str(q.field) 430 | 'field' 431 | >>> str(q.table.field) 432 | 'table.field' 433 | 434 | ``` 435 | 436 | `q` has a number of attributes itself those names could conflict with existing 437 | DB tables/columns. To resolve conflicts you could use `q._.` (stare) expression: 438 | 439 | ```python 440 | >>> str(q._.cond) 441 | 'cond' 442 | 443 | ``` 444 | 445 | Real DB tables/columns could use quite peculiar names. You could youse `q._` 446 | (pirate) expression to construct `QExpr` from any string: 447 | 448 | ```python 449 | >>> str(q._('"weird table"."weird column"')) 450 | '"weird table"."weird column"' 451 | 452 | ``` 453 | 454 | `QExpr` object knows about parent `q` object and defines a set of infix operators 455 | allowing to bind a right value: 456 | 457 | ```python 458 | >>> q.field > 10 459 | 'field > ?' 460 | >>> q.table.field == 20 461 | 'table.field = ?' 462 | >>> q._.table.field == None 463 | 'table.field IS NULL' 464 | >>> q._('"my column"') != None 465 | '"my column" IS NOT NULL' 466 | >>> q.field <= not_none/None # conditional marks also work! 467 | '' 468 | >>> q.field.IN(not_none/[10]) # BTW sqlbind has workaround for SQLite to deal with arrays in IN 469 | 'field IN ?' 470 | 471 | ``` 472 | 473 | It could look like a hack and feel ORM-ish but there is no any 474 | expression trees and tree compilation passes. q-expressions 475 | are immediately rendered as strings and simple to reason about. 476 | 477 | Also set of operations is really small it includes only comparisons and `QExpr.IN`. 478 | 479 | Let's use q-expressions with the function: 480 | 481 | ```python 482 | from sqlbind import AND_, not_none 483 | 484 | def get_fresh_users(registered_since: datetime, enabled: Optional[bool] = None): 485 | q = QParams() 486 | 487 | sql = f'''\ 488 | SELECT * FROM users 489 | WHERE registered > {q/registered_since} 490 | {AND_(q.enabled == not_none/enabled)} 491 | ORDER BY registered 492 | ''' 493 | return connection.execute(sql, q) 494 | ``` 495 | 496 | I have no any other tricks. It's the final inline version. I can't make it 497 | more pretty or readable. It's true, inline expressions looks a bit noisy and to 498 | make it manageable try to extract as much logic and use only `not_none` conditional marker. 499 | 500 | IMHO instead of 501 | 502 | ```python 503 | >>> now = None 504 | >>> show_only_enabled = True 505 | >>> f'SELECT * FROM users WHERE registered > {q/((now or datetime.utcnow()) - timedelta(days=30))} {AND_(q.enabled == cond(show_only_enabled)/1)}' 506 | 'SELECT * FROM users WHERE registered > ? AND enabled = ?' 507 | 508 | ``` 509 | 510 | please consider to use: 511 | 512 | ```python 513 | >>> now = None 514 | >>> show_only_enabled = True 515 | >>> registered_since = (now or datetime.utcnow()) - timedelta(days=30) 516 | >>> enabled = 1 if show_only_enabled else None 517 | >>> f'SELECT * FROM users WHERE registered > {q/registered_since} {AND_(q.enabled == not_none/enabled)}' 518 | 'SELECT * FROM users WHERE registered > ? AND enabled = ?' 519 | 520 | ``` 521 | 522 | Also there is a possibility to construct filters out of line via `WHERE` 523 | prepender. 524 | 525 | 526 | ### WHERE prepender 527 | 528 | It could be useful to extract filters outside of f-strings and use `sqlbind.WHERE` 529 | prepender. It can help with readability of long complex filters. 530 | 531 | ```python 532 | from sqlbind import not_none, WHERE 533 | 534 | def get_fresh_users(registered_since: datetime, enabled: Optional[bool] = None): 535 | q = QParams() 536 | 537 | filters = [ 538 | q.registered > registered_since, 539 | q.enabled == not_none/enabled, 540 | ] 541 | 542 | sql = f'SELECT * FROM users {WHERE(*filters)} ORDER BY registered' 543 | return connection.execute(sql, q) 544 | ``` 545 | 546 | There are also other prependers: `WITH`, `LIMIT`, `OFFSET`, `GROUP_BY`, 547 | `ORDER_BY`, `SET`. They all omit empty parts or are rendered as 548 | empty string if all parts are empty. 549 | 550 | Also you could use `&` operator to join filters to assemble condition expression without a list: 551 | 552 | ```python 553 | >>> filters = (q.registered > '2023-01-01') & (q.enabled == not_none/True) 554 | >>> WHERE(filters) 555 | 'WHERE (registered > ? AND enabled = ?)' 556 | 557 | ``` 558 | 559 | — "Wait a minute. How does it work? You said there is no expression trees and compilation! And 560 | all operations return strings!" 561 | 562 | 563 | ### Expressions 564 | 565 | Well, technically they are strings. Almost all methods and functions return `sqlbind.Expr`. It's a very shallow 566 | descendant of `str` with only `__or__`, `__and__` and `__invert__` overrides. 567 | 568 | ```python 569 | >>> q('enabled') & q('registered') 570 | '(enabled AND registered)' 571 | >>> type(q('enabled')) 572 | 573 | >>> type(q.enabled == True) 574 | 575 | 576 | ``` 577 | 578 | All Expr instances could be composed with `&`, `|` and `~` (negate) operations. 579 | Sadly due to python's' precedence rules you have to wrap expressions into 580 | additional parens to make it work. 581 | 582 | 583 | ### Outro 584 | 585 | It's a matter of preference and team code agreements. Personally I don't see anything 586 | criminal in inline expressions. But it could be a huge red flag for other 587 | person and it's ok. **sqlbind** gives a choice to use inline or out of line 588 | approach. 589 | 590 | But take a note. For positional dialects (like qmark style) out of line 591 | rendering has a major drawback. You should take care on part ordering. Binding 592 | and part usage should be synchronised. For example: 593 | 594 | ```python 595 | >>> q = sqlbind.Dialect.default() 596 | >>> filter1 = q.registered > '2023-01-01' 597 | >>> filter2 = q.enabled == 1 598 | >>> f'SELECT * FROM users WHERE {filter2} AND {filter1}' 599 | 'SELECT * FROM users WHERE enabled = ? AND registered > ?' 600 | >>> q # parameter ordering mismatches placeholders 601 | ['2023-01-01', 1] 602 | 603 | ``` 604 | 605 | It's a largely artificial example but for complex queries composed from 606 | multiple parts it could be an issue. To reduce chance you could abstract composition 607 | parts in a way to contain bindings and SQL construction in one go to be 608 | fully synchronised. 609 | 610 | BTW, you could already noticed but out of line variants of `get_fresh_users` 611 | from [Dynamic queries](#dynamic-queries) and [Conditionals](#conditionals) have 612 | the same ordering bug: inline and out of line approaches mix quite bad. Always 613 | use named style Dialect if your connection backend allows it. 614 | -------------------------------------------------------------------------------- /conftest.py: -------------------------------------------------------------------------------- 1 | import datetime 2 | import pytest 3 | import sqlbind 4 | 5 | 6 | class conn: 7 | @staticmethod 8 | def execute(query, parameters): 9 | pass 10 | 11 | 12 | @pytest.fixture(autouse=True) 13 | def set_doctest_ns(doctest_namespace): 14 | doctest_namespace['q'] = sqlbind.Dialect.default() 15 | doctest_namespace['sqlbind'] = sqlbind 16 | doctest_namespace['conn'] = conn 17 | doctest_namespace['connection'] = conn 18 | doctest_namespace['AND_'] = sqlbind.AND_ 19 | doctest_namespace['OR_'] = sqlbind.OR_ 20 | doctest_namespace['not_none'] = sqlbind.not_none 21 | doctest_namespace['cond'] = sqlbind.cond 22 | doctest_namespace['WHERE'] = sqlbind.WHERE 23 | doctest_namespace['timedelta'] = datetime.timedelta 24 | doctest_namespace['datetime'] = datetime.datetime 25 | -------------------------------------------------------------------------------- /pyproject.toml: -------------------------------------------------------------------------------- 1 | [build-system] 2 | requires = ["setuptools"] 3 | build-backend = "setuptools.build_meta" 4 | 5 | [tool.black] 6 | line-length = 120 7 | target-version = ['py36'] 8 | skip-string-normalization = true 9 | -------------------------------------------------------------------------------- /pytest.ini: -------------------------------------------------------------------------------- 1 | [pytest] 2 | addopts = --doctest-glob README.md --doctest-modules 3 | -------------------------------------------------------------------------------- /requirements-lint.txt: -------------------------------------------------------------------------------- 1 | mypy==1.8.0 2 | black==24.2.0 3 | -------------------------------------------------------------------------------- /requirements-test.txt: -------------------------------------------------------------------------------- 1 | coverage 2 | pytest 3 | -------------------------------------------------------------------------------- /setup.cfg: -------------------------------------------------------------------------------- 1 | [metadata] 2 | name = sqlbind 3 | version = attr: sqlbind.version 4 | author = Anton Bobrov 5 | author_email = baverman+pypi@gmail.com 6 | description = sqlbind allows to bind parameters in text based raw SQL queries 7 | long_description = file: README.md 8 | long_description_content_type = text/markdown 9 | license = MIT 10 | classifiers = 11 | Programming Language :: Python :: 3 12 | License :: OSI Approved :: MIT License 13 | Operating System :: OS Independent 14 | 15 | [options] 16 | zip_safe = False 17 | include_package_data = True 18 | packages = find: 19 | python_requires = >=3.6 20 | 21 | [options.package_data] 22 | sqlbind = py.typed 23 | 24 | [options.packages.find] 25 | exclude = tests 26 | -------------------------------------------------------------------------------- /setup.py: -------------------------------------------------------------------------------- 1 | from setuptools import setup 2 | 3 | setup() 4 | -------------------------------------------------------------------------------- /sqlbind/__init__.py: -------------------------------------------------------------------------------- 1 | import typing as t 2 | 3 | version = '1.2' 4 | 5 | Str = t.Union[str, 'QExpr'] 6 | 7 | 8 | class Expr(str): 9 | """Expr is a result of QueryParams rendering 10 | 11 | It provides basic &, | and ~ operations to compose 12 | expressions without lowering to string operations. 13 | 14 | Technically Expr instances are strings and could be used 15 | freely in string context. 16 | 17 | >>> (q.field > 10) & (q.field < 20) & ~q.enabled 18 | '((field > ? AND field < ?) AND NOT enabled)' 19 | 20 | >>> (q('name = {}', 'bob') | 'enabled = 1') 21 | '(name = ? OR enabled = 1)' 22 | """ 23 | 24 | def __or__(self, other: str) -> 'Expr': 25 | return OR(self, other) 26 | 27 | def __and__(self, other: str) -> 'Expr': 28 | return AND(self, other) 29 | 30 | def __invert__(self) -> 'Expr': 31 | if self: 32 | return Expr('NOT ' + self) 33 | else: 34 | return EMPTY 35 | 36 | 37 | def join_fragments(sep: str, fragments: t.Sequence[Str], wrap: t.Optional[str] = None) -> Expr: 38 | fragments = list(filter(None, fragments)) 39 | if not fragments: 40 | return EMPTY 41 | elif len(fragments) == 1: 42 | return Expr(str(fragments[0])) 43 | 44 | e = sep.join(map(str, fragments)) 45 | if wrap: 46 | e = wrap.format(e) 47 | return Expr(e) 48 | 49 | 50 | def OR(*fragments: Str) -> Expr: 51 | """Joins parts with OR 52 | 53 | >>> OR('enabled = 1', q.date < '2020-01-01') 54 | '(enabled = 1 OR date < ?)' 55 | """ 56 | return join_fragments(' OR ', fragments, '({})') 57 | 58 | 59 | def AND(*fragments: Str) -> Expr: 60 | """Joins parts with AND 61 | 62 | >>> AND('enabled = 1', q.date < '2020-01-01') 63 | '(enabled = 1 AND date < ?)' 64 | """ 65 | return join_fragments(' AND ', fragments, '({})') 66 | 67 | 68 | def AND_(*fragments: Str) -> str: 69 | """Allows to make dynamic additions into existing static WHERE clause 70 | 71 | >>> date = None 72 | >>> f'SELECT * from users WHERE enabled = 1 {AND_(q.registration_date < not_none/date)}' 73 | 'SELECT * from users WHERE enabled = 1 ' 74 | 75 | >>> date = '2023-01-01' 76 | >>> f'SELECT * from users WHERE enabled = 1 {AND_(q.registration_date < not_none/date)}' 77 | 'SELECT * from users WHERE enabled = 1 AND registration_date < ?' 78 | """ 79 | return prefix_join('AND ', ' AND ', fragments) 80 | 81 | 82 | def OR_(*fragments: Str) -> str: 83 | """Allows to make dynamic additions into existing static WHERE clause 84 | 85 | See `AND_` for usage. 86 | """ 87 | return prefix_join('OR ', ' OR ', fragments) 88 | 89 | 90 | def prefix_join(prefix: str, sep: str, fragments: t.Sequence[Str], wrap: t.Optional[str] = None) -> str: 91 | e = join_fragments(sep, fragments, wrap) 92 | return (prefix + e) if e else EMPTY 93 | 94 | 95 | def WHERE(*fragments: Str) -> str: 96 | """WHERE concatenates not empty input with AND 97 | 98 | Could be used in context where all filters are static or dynamic 99 | to gracefully remove WHERE clause with empty filters. 100 | 101 | >>> name, age = None, None 102 | >>> f'SELECT * FROM users {WHERE(q.name == not_none/name, q.age > not_none/age)}' 103 | 'SELECT * FROM users ' 104 | 105 | >>> name, age = 'bob', 30 106 | >>> f'SELECT * FROM users {WHERE(q.name == not_none/name, q.age > not_none/age)}' 107 | 'SELECT * FROM users WHERE name = ? AND age > ?' 108 | """ 109 | return prefix_join('WHERE ', ' AND ', fragments) 110 | 111 | 112 | def WITH(*fragments: Str) -> str: 113 | """Concatenates fragments with `,` and prepends WITH if not empty 114 | 115 | Could be used to add dynamic CTEs. 116 | 117 | >>> cte = '' 118 | >>> f'{WITH(cte)} SELECT * FROM users {WHERE(q.cond(cte, "name IN (SELECT name from cte_table)"))}' 119 | ' SELECT * FROM users ' 120 | 121 | >>> cte = 'cte_table AS (SELECT name FROM banned)' 122 | >>> f'{WITH(cte)} SELECT * FROM users {WHERE(q.cond(cte, "name IN (SELECT name from cte_table)"))}' 123 | 'WITH cte_table AS (SELECT name FROM banned) SELECT * FROM users WHERE name IN (SELECT name from cte_table)' 124 | """ 125 | return prefix_join('WITH ', ', ', fragments) 126 | 127 | 128 | def SET(*fragments: Str) -> str: 129 | return prefix_join('SET ', ', ', fragments) 130 | 131 | 132 | def FIELDS(*fragments: Str) -> str: 133 | """Concatenates fragments with `,` 134 | 135 | >>> FIELDS('name', 'age') 136 | 'name, age' 137 | """ 138 | return join_fragments(', ', fragments) 139 | 140 | 141 | def GROUP_BY(*fragments: Str) -> str: 142 | """Concatenates fragments with `,` and prepends GROUP BY if not empty 143 | 144 | >>> show_dates = True 145 | >>> GROUP_BY(q.name, q.cond(show_dates, 'date')) 146 | 'GROUP BY name, date' 147 | 148 | >>> show_dates = False 149 | >>> GROUP_BY(q.name, q.cond(show_dates, 'date')) 150 | 'GROUP BY name' 151 | """ 152 | return prefix_join('GROUP BY ', ', ', fragments) 153 | 154 | 155 | def ORDER_BY(*fragments: Str) -> str: 156 | """Concatenates fragments with `,` and prepends ORDER BY if not empty 157 | 158 | >>> sort_columns = [q.name, q.cond(True, 'date DESC')] 159 | >>> ORDER_BY(*sort_columns) 160 | 'ORDER BY name, date DESC' 161 | 162 | >>> sort_columns = [q.name, q.cond(False, 'date DESC')] 163 | >>> ORDER_BY(*sort_columns) 164 | 'ORDER BY name' 165 | """ 166 | return prefix_join('ORDER BY ', ', ', fragments) 167 | 168 | 169 | UNDEFINED = object() 170 | EMPTY = Expr('') 171 | 172 | 173 | class NotNone: 174 | """Conditional marker to mark None values as UNDEFINED objects 175 | 176 | UNDEFINED objects nullifies expression effect and could be used 177 | to construct dynamic queries. 178 | 179 | Most often used with QExpr operations. 180 | 181 | >>> q.field > not_none/None 182 | '' 183 | >>> q('field > {}', not_none/None) 184 | '' 185 | >>> q.eq(field=not_none/None) 186 | '' 187 | >>> q.IN('field', not_none/None) 188 | '' 189 | 190 | Dynamic query based on passed not none values: 191 | 192 | >>> age, name = 30, None 193 | >>> f'SELECT * FROM users WHERE enabled = 1 {AND_(q.age > not_none/age)} {AND_(q.name == not_none/name)}' 194 | 'SELECT * FROM users WHERE enabled = 1 AND age > ? ' 195 | """ 196 | 197 | def __truediv__(self, other: t.Any) -> t.Any: 198 | if other is None: 199 | return UNDEFINED 200 | return other 201 | 202 | 203 | not_none = NotNone() 204 | 205 | 206 | class Truthy: 207 | """Conditional marker to mark empty (None, False, 0, empty containers) values as UNDEFINED objects 208 | 209 | UNDEFINED objects nullifies expression effect and could be used 210 | to construct dynamic queries. 211 | 212 | Most often used with QExpr operations. 213 | 214 | See NotNone usage 215 | """ 216 | 217 | def __truediv__(self, other: t.Any) -> t.Any: 218 | if not other: 219 | return UNDEFINED 220 | return other 221 | 222 | 223 | not_empty = truthy = Truthy() 224 | 225 | 226 | class cond: 227 | """Conditional marker to mark values based on condition as UNDEFINED objects 228 | 229 | UNDEFINED objects nullifies expression effect and could be used 230 | to construct dynamic queries. 231 | 232 | Most often used with QExpr operations. 233 | 234 | >>> q.field > cond(False)/10 235 | '' 236 | 237 | >>> q.field > cond(True)/10 238 | 'field > ?' 239 | 240 | Also see NotNone usage. 241 | """ 242 | 243 | def __init__(self, cond: t.Any): 244 | self._cond = cond 245 | 246 | def __truediv__(self, other: t.Any) -> t.Any: 247 | if not self._cond: 248 | return UNDEFINED 249 | return other 250 | 251 | 252 | def _in_range(q: 'QueryParams', field: Str, lop: str, left: t.Any, rop: str, right: t.Any) -> Expr: 253 | return AND( 254 | q.compile(f'{field} {lop} {{}}', (left,)) if left is not UNDEFINED else '', 255 | q.compile(f'{field} {rop} {{}}', (right,)) if right is not UNDEFINED else '', 256 | ) 257 | 258 | 259 | class QExpr: 260 | def __init__(self, q: 'QueryParams', value: str = ''): 261 | self.q = q 262 | self._sqlbind_value = value 263 | 264 | def __getattr__(self, name: str) -> 'QExpr': 265 | if self._sqlbind_value: 266 | return QExpr(self.q, f'{self._sqlbind_value}.{name}') 267 | return QExpr(self.q, name) 268 | 269 | def __call__(self, value: str) -> 'QExpr': 270 | return QExpr(self.q, value) 271 | 272 | def __str__(self) -> str: 273 | return self._sqlbind_value 274 | 275 | def __lt__(self, other: t.Any) -> Expr: 276 | return self.q(f'{self._sqlbind_value} < {{}}', other) 277 | 278 | def __le__(self, other: t.Any) -> Expr: 279 | return self.q(f'{self._sqlbind_value} <= {{}}', other) 280 | 281 | def __gt__(self, other: t.Any) -> Expr: 282 | return self.q(f'{self._sqlbind_value} > {{}}', other) 283 | 284 | def __ge__(self, other: t.Any) -> Expr: 285 | return self.q(f'{self._sqlbind_value} >= {{}}', other) 286 | 287 | def __eq__(self, other: t.Any) -> Expr: # type: ignore[override] 288 | if other is None: 289 | return Expr(f'{self._sqlbind_value} IS NULL') 290 | return self.q(f'{self._sqlbind_value} = {{}}', other) 291 | 292 | def __ne__(self, other: t.Any) -> Expr: # type: ignore[override] 293 | if other is None: 294 | return Expr(f'{self._sqlbind_value} IS NOT NULL') 295 | return self.q(f'{self._sqlbind_value} != {{}}', other) 296 | 297 | def __invert__(self) -> Expr: 298 | return Expr('NOT ' + self._sqlbind_value) 299 | 300 | def IN(self, other: t.Any) -> Expr: 301 | return self.q.IN(self._sqlbind_value, other) 302 | 303 | def LIKE(self, template: str, other: t.Any) -> Expr: 304 | return self.q.LIKE(self._sqlbind_value, template, other) 305 | 306 | def ILIKE(self, template: str, other: t.Any) -> Expr: 307 | return self.q.ILIKE(self._sqlbind_value, template, other) 308 | 309 | 310 | class QExprDesc: 311 | def __get__(self, inst: t.Any, cls: t.Any) -> QExpr: 312 | assert inst is not None 313 | return QExpr(inst) 314 | 315 | 316 | class QueryParams: 317 | """ 318 | QueryParams accumulates query data and can be passed to actual 319 | `execute` later. QueryParams is a list or dictionary of values 320 | depending from used dialect. See `Dialect` for convenient way to 321 | get QueryParams instance. 322 | 323 | In general you should create new QueryParams instance for every 324 | constructed query. 325 | 326 | Most common usage patterns are: 327 | 328 | 1) to bind (add) a value via `/` operator: 329 | 330 | >>> q = Dialect.default() 331 | >>> value = 10 332 | >>> f'SELECT * FROM table WHERE field = {q/value}' 333 | 'SELECT * FROM table WHERE field = ?' 334 | >>> q 335 | [10] 336 | 337 | 2) to bind a value with explicit template (note `{}` placeholder): 338 | 339 | >>> days_ago = 7 340 | >>> f'SELECT * FROM table WHERE {q("date > today() - {}", days_ago)}' 341 | 'SELECT * FROM table WHERE date > today() - ?' 342 | 343 | 3) to bind a value using `QExpr`, it allows to use comparison operators in "natural" way 344 | 345 | >>> start_date = '2023-01-01' 346 | >>> f'SELECT * FROM table WHERE {q.date > start_date}' 347 | 'SELECT * FROM table WHERE date > ?' 348 | 349 | >>> q.name == 'Bob' # unknown attribute access returns QExpr 350 | 'name = ?' 351 | >>> q.users.name == 'Bob' # any level of attributes could be used 352 | 'users.name = ?' 353 | >>> q._.users.name == 'Bob' # `_` provides an escape hatch to avoid conflicts with QueryParams methods/attributes 354 | 'users.name = ?' 355 | >>> q._('LOWER(name)') == 'bob' # `_()` call allow to use any literal as QExpr 356 | 'LOWER(name) = ?' 357 | """ 358 | 359 | dialect: t.Type['BaseDialect'] 360 | _ = QExprDesc() 361 | 362 | def __getattr__(self, name: str) -> QExpr: 363 | return QExpr(self, name) 364 | 365 | def __truediv__(self, value: t.Any) -> Expr: 366 | return Expr(self.compile('{}', (value,))) 367 | 368 | def compile(self, expr: str, params: t.Sequence[t.Any]) -> str: 369 | raise NotImplementedError # pragma: no cover 370 | 371 | def __call__(self, expr: str, *params: t.Any) -> Expr: 372 | """Binds provided params via template using `{}` placeholder 373 | 374 | >>> q('field BETWEEN {} AND {}', 10, 20) 375 | 'field BETWEEN ? AND ?' 376 | >>> q 377 | [10, 20] 378 | """ 379 | if any(it is UNDEFINED for it in params): 380 | return EMPTY 381 | return Expr(self.compile(expr, params)) 382 | 383 | def cond(self, cond: t.Any, expr: Str, *params: t.Any) -> Expr: 384 | """Conditional binding 385 | 386 | >>> q.cond(False, 'enabled = 1') 387 | '' 388 | >>> q.cond(True, 'enabled = 1') 389 | 'enabled = 1' 390 | """ 391 | if cond: 392 | return Expr(self.compile(str(expr), params)) 393 | return EMPTY 394 | 395 | def not_none(self, expr: Str, param: t.Optional[t.Any]) -> Expr: 396 | """Conditional binding based on param None-ness 397 | 398 | >>> q.not_none('field = {}', None) 399 | '' 400 | >>> q.not_none('field = {}', 10) 401 | 'field = ?' 402 | """ 403 | if param is not None: 404 | return Expr(self.compile(str(expr), (param,))) 405 | return EMPTY 406 | 407 | def truthy(self, expr: Str, param: t.Optional[t.Any]) -> Expr: 408 | """Conditional binding based on param emptiness 409 | 410 | >>> q.truthy('field IN {}', []) 411 | '' 412 | >>> q.not_empty('field IN {}', []) # alias to truthy 413 | '' 414 | >>> q.truthy('field IN {}', [10, 20]) 415 | 'field IN ?' 416 | """ 417 | if param: 418 | return Expr(self.compile(str(expr), (param,))) 419 | return EMPTY 420 | 421 | not_empty = truthy 422 | 423 | def IN(self, field: Str, values: t.Optional[t.List[t.Any]]) -> Expr: 424 | """Helper to abstract dealing with IN for different database backends 425 | 426 | >>> q = Dialect.default() 427 | >>> q.IN('field', [10, 20]) 428 | 'field IN ?' 429 | >>> q 430 | [[10, 20]] 431 | 432 | >>> q = Dialect.sqlite() # sqlite can't bind whole arrays and all values should be unwrapped 433 | >>> q.IN('field', [10, 20]) 434 | 'field IN (?,?)' 435 | >>> q 436 | [10, 20] 437 | 438 | >>> q = Dialect.sqlite() # also sqlite has a limit for number of parameters 439 | >>> q.IN('field', list(range(11))) # after some threshold sqlbind render values inline 440 | 'field IN (0,1,2,3,4,5,6,7,8,9,10)' 441 | >>> q 442 | [] 443 | """ 444 | if values is None or values is UNDEFINED: 445 | return EMPTY 446 | elif values: 447 | return self.dialect.IN(self, field, values) 448 | else: 449 | return Expr(self.dialect.FALSE) 450 | 451 | def LIKE(self, field: Str, template: str, value: t.Any, op: str = 'LIKE') -> Expr: 452 | r"""Renders LIKE expression with escaped value. 453 | 454 | template is a LIKE pattern with `{}` as a value placeholder, for example: 455 | 456 | * `{}%`: startswith 457 | * `%{}`: endswith 458 | * `%{}%`: contains 459 | 460 | >>> q.LIKE('tag', '{}%', 'my_tag') 461 | 'tag LIKE ?' 462 | >>> q 463 | ['my\\_tag%'] 464 | >>> q.LIKE('tag', '{}%', not_none/None) # supports UNDEFINED values 465 | '' 466 | """ 467 | if value is UNDEFINED: 468 | return EMPTY 469 | value = like_escape(value, self.dialect.LIKE_ESCAPE, self.dialect.LIKE_CHARS) 470 | return Expr(self.compile(f'{field} {op} {{}}', (template.format(value),))) 471 | 472 | def ILIKE(self, field: Str, template: str, value: t.Any) -> Expr: 473 | return self.LIKE(field, template, value, 'ILIKE') 474 | 475 | def eq(self, field__: t.Optional[Str] = None, value__: t.Any = None, **kwargs: t.Any) -> Expr: 476 | """Helper to generate equality comparisons 477 | 478 | >>> q.eq('field', 10) 479 | 'field = ?' 480 | >>> q.eq('field', None) 481 | 'field IS NULL' 482 | >>> q.eq(name='bob', age=30) 483 | '(name = ? AND age = ?)' 484 | >>> q.eq(**{'"weird field name"': 'value'}) 485 | '"weird field name" = ?' 486 | """ 487 | if field__: 488 | kwargs[str(field__)] = value__ 489 | return AND( 490 | *( 491 | self.compile(f'{field} IS NULL', ()) if value is None else self.compile(f'{field} = {{}}', (value,)) 492 | for field, value in kwargs.items() 493 | if value is not UNDEFINED 494 | ) 495 | ) 496 | 497 | def neq(self, field__: t.Optional[Str] = None, value__: t.Any = None, **kwargs: t.Any) -> Expr: 498 | """Opposite to `.eq` 499 | 500 | >>> q.neq(field=10, data=None) 501 | '(field != ? AND data IS NOT NULL)' 502 | """ 503 | if field__: 504 | kwargs[str(field__)] = value__ 505 | return AND( 506 | *( 507 | ( 508 | self.compile(f'{field} IS NOT NULL', ()) 509 | if value is None 510 | else self.compile(f'{field} != {{}}', (value,)) 511 | ) 512 | for field, value in kwargs.items() 513 | if value is not UNDEFINED 514 | ) 515 | ) 516 | 517 | def in_range(self, field: Str, left: t.Any, right: t.Any) -> Expr: 518 | """Helper to check field is in [left, right) bounds 519 | 520 | >>> q.in_range('date', '2023-01-01', '2023-02-01') 521 | '(date >= ? AND date < ?)' 522 | >>> q 523 | ['2023-01-01', '2023-02-01'] 524 | """ 525 | return _in_range(self, field, '>=', left, '<', right) 526 | 527 | def in_crange(self, field: Str, left: t.Any, right: t.Any) -> Expr: 528 | """Helper to check field is in [left, right] bounds 529 | 530 | >>> q.in_crange('date', '2023-01-01', '2023-02-01') 531 | '(date >= ? AND date <= ?)' 532 | >>> q 533 | ['2023-01-01', '2023-02-01'] 534 | """ 535 | return _in_range(self, field, '>=', left, '<=', right) 536 | 537 | def WHERE(self, *cond: Str, **kwargs: t.Any) -> str: 538 | """Helper to render the whole WHERE part based on available conditions 539 | 540 | >>> value = None 541 | >>> f'SELECT * FROM table {q.WHERE(field=not_none/value)}' 542 | 'SELECT * FROM table ' 543 | 544 | >>> value = 10 545 | >>> f'SELECT * FROM table {q.WHERE(field=not_none/value)}' 546 | 'SELECT * FROM table WHERE field = ?' 547 | """ 548 | return WHERE(self.eq(**kwargs), *cond) 549 | 550 | def assign(self, **kwargs: t.Any) -> Expr: 551 | """Helper to render a sequence of assignments 552 | 553 | >>> q.assign(name='bob', age=30, confirmed_date=None) 554 | 'name = ?, age = ?, confirmed_date = ?' 555 | """ 556 | fragments = [ 557 | self.compile(f'{field} = {{}}', (value,)) for field, value in kwargs.items() if value is not UNDEFINED 558 | ] 559 | return join_fragments(', ', fragments) 560 | 561 | def SET(self, **kwargs: t.Any) -> str: 562 | """Helper to render a SET clause 563 | 564 | >>> q.SET(name='bob', age=30, confirmed_date=None) 565 | 'SET name = ?, age = ?, confirmed_date = ?' 566 | """ 567 | return SET(self.assign(**kwargs)) 568 | 569 | def VALUES(self, data: t.Optional[t.List[t.Dict[str, t.Any]]] = None, **kwargs: t.Any) -> str: 570 | """Helper to render field list and VALUES expression 571 | 572 | >>> data = [{'name': 'bob', 'age': 30}, {'name': 'fred', 'age': 20}] 573 | >>> f'INSERT INTO users {q.VALUES(data)}' 574 | 'INSERT INTO users (name, age) VALUES (?, ?), (?, ?)' 575 | >>> q 576 | ['bob', 30, 'fred', 20] 577 | 578 | >>> f'INSERT INTO users {q.VALUES(name="bob", age=30)}' 579 | 'INSERT INTO users (name, age) VALUES (?, ?)' 580 | """ 581 | if not data: 582 | data = [kwargs] 583 | 584 | names = list(data[0].keys()) 585 | params: t.List[t.Any] = [] 586 | marks = '({})'.format(', '.join(['{}'] * len(names))) 587 | for it in data: 588 | params.extend(it[f] for f in names) 589 | 590 | return self.compile(f"({', '.join(names)}) VALUES {', '.join(marks for _ in range(len(data)))}", params) 591 | 592 | def LIMIT(self, value: t.Any) -> Expr: 593 | """Helper to render LIMIT 594 | 595 | value could be conditional 596 | 597 | >>> q.LIMIT(not_none/None) 598 | '' 599 | >>> q.LIMIT(10) 600 | 'LIMIT ?' 601 | """ 602 | return self('LIMIT {}', value) 603 | 604 | def OFFSET(self, value: t.Any) -> Expr: 605 | """Helper to render OFFSET 606 | 607 | value could be conditional 608 | 609 | >>> q.OFFSET(not_none/None) 610 | '' 611 | >>> q.OFFSET(10) 612 | 'OFFSET ?' 613 | """ 614 | return self('OFFSET {}', value) 615 | 616 | 617 | def like_escape(value: str, escape: str = '\\', likechars: str = '%_') -> str: 618 | r"""Escapes special LIKE characters 619 | 620 | In general application couldn't use untrusted input in LIKE 621 | expressions because it could easily lead to incorrect results in best case 622 | and DDoS in worst. 623 | 624 | >>> q('tag LIKE {}', like_escape('my_tag') + '%') 625 | 'tag LIKE ?' 626 | >>> q 627 | ['my\\_tag%'] 628 | 629 | Note: QueryParams.LIKE provides more convenient way to use it. 630 | """ 631 | value = value.replace(escape, escape + escape) 632 | for c in likechars: 633 | value = value.replace(c, escape + c) 634 | return value 635 | 636 | 637 | class DictQueryParams(t.Dict[str, t.Any], QueryParams): 638 | def __init__(self, dialect: t.Type['BaseDialect']): 639 | dict.__init__(self, {}) 640 | self.dialect = dialect 641 | self._count = 0 642 | 643 | def add(self, params: t.Sequence[t.Any]) -> t.List[str]: 644 | start = self._count 645 | self._count += len(params) 646 | names = [f'p{i}' for i, _ in enumerate(params, start)] 647 | self.update(zip(names, params)) 648 | return names 649 | 650 | 651 | class ListQueryParams(t.List[t.Any], QueryParams): 652 | def __init__(self, dialect: t.Type['BaseDialect']): 653 | list.__init__(self, []) 654 | self.dialect = dialect 655 | self._count = 0 656 | 657 | def add(self, params: t.Sequence[t.Any]) -> int: 658 | start = self._count 659 | self._count += len(params) 660 | self.extend(params) 661 | return start 662 | 663 | 664 | class QMarkQueryParams(ListQueryParams): 665 | """QueryParams implementation for qmark (?) parameter style""" 666 | 667 | def compile(self, expr: str, params: t.Sequence[t.Any]) -> str: 668 | self.add(params) 669 | return expr.format(*('?' * len(params))) 670 | 671 | 672 | class NumericQueryParams(ListQueryParams): 673 | """QueryParams implementation for numeric (:1, :2) parameter style""" 674 | 675 | def compile(self, expr: str, params: t.Sequence[t.Any]) -> str: 676 | start = self.add(params) + 1 677 | return expr.format(*(f':{i}' for i, _ in enumerate(params, start))) 678 | 679 | 680 | class FormatQueryParams(ListQueryParams): 681 | """QueryParams implementation for format (%s) parameter style""" 682 | 683 | def compile(self, expr: str, params: t.Sequence[t.Any]) -> str: 684 | self.add(params) 685 | return expr.format(*(['%s'] * len(params))) 686 | 687 | 688 | class NamedQueryParams(DictQueryParams): 689 | """QueryParams implementation for named (:name) parameter style""" 690 | 691 | def compile(self, expr: str, params: t.Sequence[t.Any]) -> str: 692 | names = self.add(params) 693 | return expr.format(*(f':{it}' for it in names)) 694 | 695 | 696 | class PyFormatQueryParams(DictQueryParams): 697 | """QueryParams implementation for pyformat (%(name)s) parameter style""" 698 | 699 | def compile(self, expr: str, params: t.Sequence[t.Any]) -> str: 700 | names = self.add(params) 701 | return expr.format(*(f'%({it})s' for it in names)) 702 | 703 | 704 | class DollarQueryParams(ListQueryParams): 705 | """QueryParams implementation for format ($1, $2, ...) parameter style""" 706 | 707 | def compile(self, expr: str, params: t.Sequence[t.Any]) -> str: 708 | start = self.add(params) + 1 709 | return expr.format(*(f"${i}" for i, _ in enumerate(params, start))) 710 | 711 | 712 | class BaseDialect: 713 | """Dialect compatible with most of backends""" 714 | 715 | FALSE = 'FALSE' 716 | LIKE_ESCAPE = '\\' 717 | LIKE_CHARS = '%_' 718 | 719 | @staticmethod 720 | def IN(q: QueryParams, field: Str, values: t.List[t.Any]) -> Expr: 721 | return q(f'{field} IN {{}}', values) 722 | 723 | 724 | class SQLiteDialect(BaseDialect): 725 | """Dedicated SQLite dialiect to handle FALSE literal and IN operator""" 726 | 727 | FALSE = '0' 728 | 729 | @staticmethod 730 | def IN(q: QueryParams, field: Str, values: t.List[t.Any]) -> Expr: 731 | if len(values) > 10: 732 | # Trying to escape and assemble sql manually to avoid too many 733 | # parameters exception 734 | return Expr(f'{field} IN ({sqlite_value_list(values)})') 735 | else: 736 | qmarks = ','.join(['{}'] * len(values)) 737 | return q(f'{field} IN ({qmarks})', *values) 738 | 739 | 740 | def sqlite_escape(val: t.Union[float, int, str]) -> str: 741 | tval = type(val) 742 | if tval is str: 743 | return "'{}'".format(val.replace("'", "''")) # type: ignore[union-attr] 744 | elif tval is int or tval is float: 745 | return str(val) 746 | raise ValueError(f'Invalid type: {val}') 747 | 748 | 749 | def sqlite_value_list(values: t.List[t.Union[float, int, str]]) -> str: 750 | return ','.join(map(sqlite_escape, values)) 751 | 752 | 753 | class Dialect: 754 | """Namespace to hold most popular Dialect/QueryParams combinations""" 755 | 756 | def __init__(self, factory: t.Callable[[], QueryParams]): 757 | self.factory = factory 758 | 759 | def __get__(self, inst: t.Any, cls: t.Any) -> QueryParams: 760 | return self.factory() 761 | 762 | @staticmethod 763 | def default() -> QueryParams: 764 | """Uses qmarks (?) as placeholders 765 | 766 | >>> q = Dialect.default() 767 | >>> f'field = {q/20}' 768 | 'field = ?' 769 | """ 770 | return QMarkQueryParams(BaseDialect) 771 | 772 | @staticmethod 773 | def default_named() -> QueryParams: 774 | """Uses named params (:param) as placeholders. 775 | 776 | Backend examples: SQLAlchemy 777 | 778 | >>> q = Dialect.default_named() 779 | >>> f'field = {q/20}' 780 | 'field = :p0' 781 | """ 782 | return NamedQueryParams(BaseDialect) 783 | 784 | @staticmethod 785 | def default_pyformat() -> QueryParams: 786 | """Uses pyformat params (%(param)s) as placeholders. 787 | 788 | Backend examples: psycopg2 and clickhouse-driver 789 | 790 | >>> q = Dialect.default_pyformat() 791 | >>> f'field = {q/20}' 792 | 'field = %(p0)s' 793 | """ 794 | return PyFormatQueryParams(BaseDialect) 795 | 796 | @staticmethod 797 | def default_format() -> QueryParams: 798 | """Uses format params (%s) as placeholders. 799 | 800 | Backend examples: psycopg2 and mysql-connector-python 801 | 802 | >>> q = Dialect.default_format() 803 | >>> f'field = {q/20}' 804 | 'field = %s' 805 | """ 806 | return FormatQueryParams(BaseDialect) 807 | 808 | @staticmethod 809 | def default_dollar() -> QueryParams: 810 | """Uses dollar params ($1, $2, ...) as placeholders. 811 | Backend examples: asyncpg 812 | >>> q = Dialect.default_dollar() 813 | >>> f'field = {q/20}' 814 | 'field = $1' 815 | """ 816 | return DollarQueryParams(BaseDialect) 817 | 818 | @staticmethod 819 | def sqlite() -> QueryParams: 820 | """Uses sqlite dialect and renders binds with qmark (?) placeholders""" 821 | return QMarkQueryParams(SQLiteDialect) 822 | 823 | @staticmethod 824 | def sqlite_named() -> QueryParams: 825 | """Uses sqlite dialect and renders binds with named (:param) placeholders""" 826 | return NamedQueryParams(SQLiteDialect) 827 | -------------------------------------------------------------------------------- /sqlbind/py.typed: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/baverman/sqlbind/2f1c0a475b669a95d4e7a1c1c5ea227a56fcfb29/sqlbind/py.typed -------------------------------------------------------------------------------- /tests/__init__.py: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/baverman/sqlbind/2f1c0a475b669a95d4e7a1c1c5ea227a56fcfb29/tests/__init__.py -------------------------------------------------------------------------------- /tests/test_sqlbind.py: -------------------------------------------------------------------------------- 1 | import pytest 2 | 3 | import sqlbind as s 4 | 5 | 6 | def test_qmark(): 7 | q = s.QMarkQueryParams(s.BaseDialect) 8 | assert q('field1 = {}', 10) == 'field1 = ?' 9 | assert q('field2 = {}', 20) == 'field2 = ?' 10 | assert q == [10, 20] 11 | 12 | 13 | def test_numbered(): 14 | q = s.NumericQueryParams(s.BaseDialect) 15 | assert q('field1 = {}', 10) == 'field1 = :1' 16 | assert q('field2 = {}', 20) == 'field2 = :2' 17 | assert q == [10, 20] 18 | 19 | 20 | def test_format(): 21 | q = s.Dialect.default_format() 22 | assert q('field1 = {}', 10) == 'field1 = %s' 23 | assert q('field2 = {}', 20) == 'field2 = %s' 24 | assert q == [10, 20] 25 | 26 | 27 | def test_named(): 28 | q = s.NamedQueryParams(s.BaseDialect) 29 | assert q('field1 = {}', 10) == 'field1 = :p0' 30 | assert q('field2 = {}', 20) == 'field2 = :p1' 31 | assert q == {'p0': 10, 'p1': 20} 32 | 33 | 34 | def test_pyformat(): 35 | q = s.Dialect.default_pyformat() 36 | assert q('field1 = {}', 10) == 'field1 = %(p0)s' 37 | assert q('field2 = {}', 20) == 'field2 = %(p1)s' 38 | assert q == {'p0': 10, 'p1': 20} 39 | 40 | 41 | def test_dollar(): 42 | q = s.Dialect.default_dollar() 43 | assert q("field1 = {}", 10) == "field1 = $1" 44 | assert q("field2 = {}", 20) == "field2 = $2" 45 | assert q == [10, 20] 46 | 47 | 48 | def test_conditions(): 49 | q = s.Dialect.default() 50 | 51 | assert q.cond(True, 'field = {}', 10) == 'field = ?' 52 | assert q.cond(False, 'field = {}', 10) == '' 53 | 54 | assert q.not_none('field = {}', 20) == 'field = ?' 55 | assert q.not_none('field = {}', None) == '' 56 | 57 | assert q.not_empty('field = {}', 30) == 'field = ?' 58 | assert q.not_empty('field = {}', 0) == '' 59 | assert q == [10, 20, 30] 60 | 61 | 62 | def test_outbound_conditions(): 63 | q = s.Dialect.default() 64 | 65 | assert q('field = {}', s.cond(True) / 10) == 'field = ?' 66 | assert q('field = {}', s.cond(False) / 10) == '' 67 | 68 | assert q.eq('field', s.not_none / 20) == 'field = ?' 69 | assert q.eq('field', s.not_none / None) == '' 70 | 71 | assert q('field = {}', s.truthy / 30) == 'field = ?' 72 | assert q('field = {}', s.truthy / 0) == '' 73 | assert q == [10, 20, 30] 74 | 75 | 76 | def test_query_methods(): 77 | q = s.Dialect.default() 78 | assert q.IN('field', s.truthy / 0) == '' 79 | assert q.IN('field', None) == '' 80 | assert q.IN('field', []) == 'FALSE' 81 | assert q.field.IN([10]) == 'field IN ?' 82 | 83 | assert q.eq('t.bar', None, boo='foo') == '(boo = ? AND t.bar IS NULL)' 84 | assert q.neq('t.bar', None, boo='foo') == '(boo != ? AND t.bar IS NOT NULL)' 85 | assert q.neq('t.bar', s.not_none / None, boo=s.not_none / None) == '' 86 | 87 | assert q == [[10], 'foo', 'foo'] 88 | 89 | q = s.Dialect.default() 90 | assert q.in_range(q.val, 10, 20) == '(val >= ? AND val < ?)' 91 | assert q.in_crange(q._.c.val, 10, 20) == '(c.val >= ? AND c.val <= ?)' 92 | assert q == [10, 20, 10, 20] 93 | 94 | 95 | def test_bind(): 96 | q = s.Dialect.sqlite() 97 | assert q / 10 == '?' 98 | assert q == [10] 99 | 100 | 101 | def test_sqlite_in(): 102 | q = s.Dialect.sqlite() 103 | 104 | assert q.IN('field', [10, '20']) == 'field IN (?,?)' 105 | assert q.IN('field', list(range(10)) + ['boo', 1.5]) == "field IN (0,1,2,3,4,5,6,7,8,9,'boo',1.5)" 106 | assert q == [10, '20'] 107 | 108 | with pytest.raises(ValueError) as ei: 109 | q.IN('field', list(range(10)) + [object()]) 110 | assert ei.match('Invalid type') 111 | 112 | 113 | def test_logical_ops(): 114 | q = s.Dialect.default() 115 | 116 | assert q('field = {}', 10) & q.not_none('gargbage', None) == 'field = ?' 117 | assert q('field = {}', 10) & '' == 'field = ?' 118 | assert q('field = {}', 10) & 'boo' == '(field = ? AND boo)' 119 | assert q.not_none('garbage', None) & '' == '' 120 | 121 | assert q('field = {}', 10) | q.not_none('gargbage', None) == 'field = ?' 122 | assert q('field = {}', 10) | '' == 'field = ?' 123 | assert q('field = {}', 10) | 'boo' == '(field = ? OR boo)' 124 | assert q.not_none('garbage', None) | '' == '' 125 | 126 | rv = q('field1 < {}', 10) | q('field2 > {}', 20) & q('field3 = {}', 30) 127 | assert rv == '(field1 < ? OR (field2 > ? AND field3 = ?))' 128 | 129 | assert ~q('TRUE') == 'NOT TRUE' 130 | assert ~s.EMPTY == '' 131 | 132 | 133 | def test_prefix_join(): 134 | q = s.Dialect.default() 135 | 136 | assert s.WHERE(q('boo'), q('foo'), 'bar') == 'WHERE boo AND foo AND bar' 137 | assert s.WHERE() == '' 138 | assert s.WHERE('', '') == '' 139 | 140 | assert s.WITH('', '') == '' 141 | assert s.WITH('boo', 'foo') == 'WITH boo, foo' 142 | 143 | 144 | def test_prepend(): 145 | q = s.Dialect.default() 146 | assert s.AND_('') == '' 147 | assert s.AND_(q.f == s.not_none / None) == '' 148 | assert s.AND_(q.f == s.not_none / 10) == 'AND f = ?' 149 | assert q == [10] 150 | 151 | q = s.Dialect.default() 152 | assert s.OR_('') == '' 153 | assert s.OR_(q.f == s.not_none / None) == '' 154 | assert s.OR_(q.f == s.not_none / 10) == 'OR f = ?' 155 | assert q == [10] 156 | 157 | 158 | def test_set(): 159 | q = s.Dialect.default() 160 | assert f'UPDATE table {q.SET(boo=10, foo=20)}' == 'UPDATE table SET boo = ?, foo = ?' 161 | 162 | 163 | def test_where(): 164 | q = s.Dialect.default() 165 | assert f'SELECT * FROM table {q.WHERE(boo=10, foo=None)}' == 'SELECT * FROM table WHERE (boo = ? AND foo IS NULL)' 166 | assert q == [10] 167 | 168 | 169 | def test_fields(): 170 | q = s.Dialect.default() 171 | assert f'SELECT {s.FIELDS("boo", q.cond(False, "foo"))}' == 'SELECT boo' 172 | 173 | 174 | def test_limit(): 175 | q = s.Dialect.default() 176 | assert q.LIMIT(s.not_none / None) == '' 177 | assert q.LIMIT(20) == 'LIMIT ?' 178 | assert q.OFFSET(s.not_none / None) == '' 179 | assert q.OFFSET(20) == 'OFFSET ?' 180 | 181 | 182 | def test_qexpr(): 183 | q = s.Dialect.default() 184 | 185 | assert (q.val < 1) == 'val < ?' 186 | assert (q.val <= 2) == 'val <= ?' 187 | assert (q.val > 3) == 'val > ?' 188 | assert (q.val >= 4) == 'val >= ?' 189 | assert (q.val == 5) == 'val = ?' 190 | assert (q.val != 6) == 'val != ?' 191 | assert q == [1, 2, 3, 4, 5, 6] 192 | 193 | assert (q.val == s.not_none / None) is s.EMPTY 194 | assert (q.val == s.truthy / 0) is s.EMPTY 195 | assert q == [1, 2, 3, 4, 5, 6] 196 | 197 | q = s.Dialect.default() 198 | assert (q._('field + 10') < 1) == 'field + 10 < ?' 199 | assert q == [1] 200 | 201 | 202 | def test_dialect_descriptor(): 203 | class Q: 204 | p = s.Dialect(s.Dialect.default) 205 | 206 | q1 = Q.p 207 | q1 / 10 208 | 209 | q2 = Q.p 210 | q2 / 20 211 | 212 | assert q1 == [10] 213 | assert q2 == [20] 214 | 215 | 216 | def test_like_escape(): 217 | assert s.like_escape('boo') == 'boo' 218 | assert s.like_escape('boo%') == 'boo\\%' 219 | assert s.like_escape('boo_') == 'boo\\_' 220 | assert s.like_escape('boo\\') == 'boo\\\\' 221 | assert s.like_escape('%b\\oo_|', '|') == '|%b\\oo|_||' 222 | 223 | 224 | def test_like(): 225 | q = s.Dialect.default() 226 | q.tag.LIKE('{}%', 'my_tag') == 'tag LIKE ?' 227 | q.tag.ILIKE('{}%', 'my_tag') == 'tag ILIKE ?' 228 | assert q == ['my\\_tag%', 'my\\_tag%'] 229 | -------------------------------------------------------------------------------- /tests/test_sqlite3.py: -------------------------------------------------------------------------------- 1 | import sqlite3 2 | 3 | from sqlbind import Dialect, WHERE 4 | 5 | 6 | def test_story(): 7 | conn = sqlite3.connect(':memory:') 8 | 9 | with conn: 10 | conn.execute('CREATE TABLE t(name TEXT, age INTEGER)') 11 | 12 | q = Dialect.sqlite() 13 | data = [{'name': 'boo', 'age': 20}] 14 | conn.execute(f'INSERT INTO t {q.VALUES(data)}', q) 15 | 16 | q = Dialect.sqlite() 17 | conn.execute(f'INSERT INTO t {q.VALUES(name="bar", age=30)}', q) 18 | 19 | q = Dialect.sqlite() 20 | conn.execute(f'UPDATE t {q.SET(age=45)} {q.WHERE(name="boo")}', q) 21 | 22 | q = Dialect.sqlite_named() # dict based query params could be shared 23 | assert conn.execute(f'SELECT age FROM t {q.WHERE(name="boo")}', q).fetchall() == [(45,)] 24 | assert conn.execute(f'SELECT * FROM t {WHERE(q.neq(name="boo"))}', q).fetchall() == [('bar', 30)] 25 | --------------------------------------------------------------------------------