3333from sqlalchemy .exc import MultipleResultsFound
3434from sqlalchemy .orm .session import Session
3535from sqlalchemy .sql .expression import (
36+ case ,
3637 column ,
3738 exists ,
3839 func ,
39- literal ,
4040 select ,
4141 table ,
4242 text ,
4343)
4444from sqlalchemy .sql .schema import Table
45- from sqlalchemy .sql .selectable import Select
45+ from sqlalchemy .sql .selectable import Select , TableClause
4646
4747from cardinal_pythonlib .logs import get_brace_style_log_with_null_handler
48- from cardinal_pythonlib .sqlalchemy .dialect import SqlaDialectName
4948
5049log = get_brace_style_log_with_null_handler (__name__ )
5150
@@ -233,15 +232,17 @@ def count_star_and_max(
233232# http://docs.sqlalchemy.org/en/latest/orm/query.html
234233
235234
236- def exists_in_table (session : Session , table_ : Table , * criteria : Any ) -> bool :
235+ def exists_in_table (
236+ session : Session , table_ : Union [Table , TableClause ], * criteria : Any
237+ ) -> bool :
237238 """
238239 Implements an efficient way of detecting if a record or records exist;
239240 should be faster than ``COUNT(*)`` in some circumstances.
240241
241242 Args:
242243 session: SQLAlchemy :class:`Session`, :class:`Engine`, or
243244 :class:`Connection` object
244- table_: SQLAlchemy :class:`Table` object
245+ table_: SQLAlchemy :class:`Table` object or table clause
245246 criteria: optional SQLAlchemy "where" criteria
246247
247248 Returns:
@@ -262,15 +263,70 @@ def exists_in_table(session: Session, table_: Table, *criteria: Any) -> bool:
262263 exists_clause = exists_clause .where (criterion )
263264 # ... EXISTS (SELECT * FROM tablename WHERE ...)
264265
265- if session .get_bind ().dialect .name == SqlaDialectName .MSSQL :
266- query = select (literal (True )).where (exists_clause )
267- # ... SELECT 1 WHERE EXISTS (SELECT * FROM tablename WHERE ...)
268- else :
269- query = select (exists_clause )
270- # ... SELECT EXISTS (SELECT * FROM tablename WHERE ...)
271-
266+ # Methods as follows.
267+ # SQL validation: http://developer.mimer.com/validator/
268+ # Standard syntax: https://en.wikipedia.org/wiki/SQL_syntax
269+ # We can make it conditional on dialect via
270+ # session.get_bind().dialect.name
271+ # but it would be better not to need to.
272+ #
273+ # ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
274+ # SELECT 1 FROM mytable WHERE EXISTS (SELECT * FROM mytable WHERE ...)
275+ # ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
276+ # - Produces multiple results (a 1 for each row).
277+ #
278+ # ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
279+ # SELECT 1 WHERE EXISTS (SELECT * FROM tablename WHERE ...)
280+ # ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
281+ # - Produces either 1 or NULL (no rows).
282+ # - Implementation:
283+ #
284+ # query = select(literal(True)).where(exists_clause)
285+ # result = session.execute(query).scalar()
286+ # return bool(result) # None/0 become False; 1 becomes True
287+ #
288+ # - However, may be non-standard: no FROM clause.
289+ # - Works on SQL Server (empirically).
290+ #
291+ # ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
292+ # SELECT EXISTS (SELECT * FROM tablename WHERE ...)
293+ # ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
294+ # - Produces 0 or 1.
295+ # - Implementation:
296+ #
297+ # query = select(exists_clause)
298+ # result = session.execute(query).scalar()
299+ # return bool(result)
300+ #
301+ # - But it may not be standard.
302+ #
303+ # - Supported by MySQL:
304+ # - https://dev.mysql.com/doc/refman/8.4/en/exists-and-not-exists-subqueries.html # noqa: E501
305+ # - and an empirical test
306+ #
307+ # Suported by SQLite:
308+ # - https://www.sqlite.org/lang_expr.html#the_exists_operator
309+ # - and an empirical test
310+ #
311+ # Possibly not SQL Server.
312+ #
313+ # Possibly not Databricks.
314+ # - https://docs.databricks.com/en/sql/language-manual/sql-ref-syntax-qry-select.html # noqa: E501
315+ # - https://docs.databricks.com/en/sql/language-manual/sql-ref-syntax-qry-select-where.html # noqa: E501
316+ #
317+ # ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
318+ # SELECT CASE WHEN EXISTS(SELECT * FROM tablename WHERE...) THEN 0 ELSE 1 END # noqa: E501
319+ # ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
320+ # - ANSI standard.
321+ # - https://stackoverflow.com/questions/17284688/how-to-efficiently-check-if-a-table-is-empty # noqa: E501
322+ # - Returns 0 or 1.
323+ # - May be possible to use "SELECT 1 FROM tablename" also, but unclear
324+ # what's faster, and likely EXISTS() should optimise.
325+ # - Implementation as below.
326+
327+ query = select (case ((exists_clause , 1 ), else_ = 0 ))
272328 result = session .execute (query ).scalar ()
273- return bool (result )
329+ return bool (result ) # None/0 become False; 1 becomes True
274330
275331
276332def exists_plain (session : Session , tablename : str , * criteria : Any ) -> bool :
0 commit comments