1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659
|
import itertools
import os
from collections.abc import Mapping, Sequence
from copy import copy
import sqlalchemy as sa
from sqlalchemy.engine.url import make_url
from sqlalchemy.exc import OperationalError, ProgrammingError
from ..utils import starts_with
from .orm import quote
def escape_like(string, escape_char='*'):
"""
Escape the string parameter used in SQL LIKE expressions.
::
from sqlalchemy_utils import escape_like
query = session.query(User).filter(
User.name.ilike(escape_like('John'))
)
:param string: a string to escape
:param escape_char: escape character
"""
return (
string
.replace(escape_char, escape_char * 2)
.replace('%', escape_char + '%')
.replace('_', escape_char + '_')
)
def json_sql(value, scalars_to_json=True):
"""
Convert python data structures to PostgreSQL specific SQLAlchemy JSON
constructs. This function is extremly useful if you need to build
PostgreSQL JSON on python side.
.. note::
This function needs PostgreSQL >= 9.4
Scalars are converted to to_json SQLAlchemy function objects
::
json_sql(1) # Equals SQL: to_json(1)
json_sql('a') # to_json('a')
Mappings are converted to json_build_object constructs
::
json_sql({'a': 'c', '2': 5}) # json_build_object('a', 'c', '2', 5)
Sequences (other than strings) are converted to json_build_array constructs
::
json_sql([1, 2, 3]) # json_build_array(1, 2, 3)
You can also nest these data structures
::
json_sql({'a': [1, 2, 3]})
# json_build_object('a', json_build_array[1, 2, 3])
:param value:
value to be converted to SQLAlchemy PostgreSQL function constructs
"""
scalar_convert = sa.text
if scalars_to_json:
def scalar_convert(a):
return sa.func.to_json(sa.text(a))
if isinstance(value, Mapping):
return sa.func.json_build_object(
*(
json_sql(v, scalars_to_json=False)
for v in itertools.chain(*value.items())
)
)
elif isinstance(value, str):
return scalar_convert(f"'{value}'")
elif isinstance(value, Sequence):
return sa.func.json_build_array(
*(
json_sql(v, scalars_to_json=False)
for v in value
)
)
elif isinstance(value, (int, float)):
return scalar_convert(str(value))
return value
def jsonb_sql(value, scalars_to_jsonb=True):
"""
Convert python data structures to PostgreSQL specific SQLAlchemy JSONB
constructs. This function is extremly useful if you need to build
PostgreSQL JSONB on python side.
.. note::
This function needs PostgreSQL >= 9.4
Scalars are converted to to_jsonb SQLAlchemy function objects
::
jsonb_sql(1) # Equals SQL: to_jsonb(1)
jsonb_sql('a') # to_jsonb('a')
Mappings are converted to jsonb_build_object constructs
::
jsonb_sql({'a': 'c', '2': 5}) # jsonb_build_object('a', 'c', '2', 5)
Sequences (other than strings) converted to jsonb_build_array constructs
::
jsonb_sql([1, 2, 3]) # jsonb_build_array(1, 2, 3)
You can also nest these data structures
::
jsonb_sql({'a': [1, 2, 3]})
# jsonb_build_object('a', jsonb_build_array[1, 2, 3])
:param value:
value to be converted to SQLAlchemy PostgreSQL function constructs
:boolean jsonbb:
Flag to alternatively convert the return with a to_jsonb construct
"""
scalar_convert = sa.text
if scalars_to_jsonb:
def scalar_convert(a):
return sa.func.to_jsonb(sa.text(a))
if isinstance(value, Mapping):
return sa.func.jsonb_build_object(
*(
jsonb_sql(v, scalars_to_jsonb=False)
for v in itertools.chain(*value.items())
)
)
elif isinstance(value, str):
return scalar_convert(f"'{value}'")
elif isinstance(value, Sequence):
return sa.func.jsonb_build_array(
*(
jsonb_sql(v, scalars_to_jsonb=False)
for v in value
)
)
elif isinstance(value, (int, float)):
return scalar_convert(str(value))
return value
def has_index(column_or_constraint):
"""
Return whether or not given column or the columns of given foreign key
constraint have an index. A column has an index if it has a single column
index or it is the first column in compound column index.
A foreign key constraint has an index if the constraint columns are the
first columns in compound column index.
:param column_or_constraint:
SQLAlchemy Column object or SA ForeignKeyConstraint object
.. versionadded: 0.26.2
.. versionchanged: 0.30.18
Added support for foreign key constaints.
::
from sqlalchemy_utils import has_index
class Article(Base):
__tablename__ = 'article'
id = sa.Column(sa.Integer, primary_key=True)
title = sa.Column(sa.String(100))
is_published = sa.Column(sa.Boolean, index=True)
is_deleted = sa.Column(sa.Boolean)
is_archived = sa.Column(sa.Boolean)
__table_args__ = (
sa.Index('my_index', is_deleted, is_archived),
)
table = Article.__table__
has_index(table.c.is_published) # True
has_index(table.c.is_deleted) # True
has_index(table.c.is_archived) # False
Also supports primary key indexes
::
from sqlalchemy_utils import has_index
class ArticleTranslation(Base):
__tablename__ = 'article_translation'
id = sa.Column(sa.Integer, primary_key=True)
locale = sa.Column(sa.String(10), primary_key=True)
title = sa.Column(sa.String(100))
table = ArticleTranslation.__table__
has_index(table.c.locale) # False
has_index(table.c.id) # True
This function supports foreign key constraints as well
::
class User(Base):
__tablename__ = 'user'
first_name = sa.Column(sa.Unicode(255), primary_key=True)
last_name = sa.Column(sa.Unicode(255), primary_key=True)
class Article(Base):
__tablename__ = 'article'
id = sa.Column(sa.Integer, primary_key=True)
author_first_name = sa.Column(sa.Unicode(255))
author_last_name = sa.Column(sa.Unicode(255))
__table_args__ = (
sa.ForeignKeyConstraint(
[author_first_name, author_last_name],
[User.first_name, User.last_name]
),
sa.Index(
'my_index',
author_first_name,
author_last_name
)
)
table = Article.__table__
constraint = list(table.foreign_keys)[0].constraint
has_index(constraint) # True
"""
table = column_or_constraint.table
if not isinstance(table, sa.Table):
raise TypeError(
'Only columns belonging to Table objects are supported. Given '
'column belongs to %r.' % table
)
primary_keys = table.primary_key.columns.values()
if isinstance(column_or_constraint, sa.ForeignKeyConstraint):
columns = list(column_or_constraint.columns.values())
else:
columns = [column_or_constraint]
return (
(primary_keys and starts_with(primary_keys, columns)) or
any(
starts_with(index.columns.values(), columns)
for index in table.indexes
)
)
def has_unique_index(column_or_constraint):
"""
Return whether or not given column or given foreign key constraint has a
unique index.
A column has a unique index if it has a single column primary key index or
it has a single column UniqueConstraint.
A foreign key constraint has a unique index if the columns of the
constraint are the same as the columns of table primary key or the coluns
of any unique index or any unique constraint of the given table.
:param column: SQLAlchemy Column object
.. versionadded: 0.27.1
.. versionchanged: 0.30.18
Added support for foreign key constaints.
Fixed support for unique indexes (previously only worked for unique
constraints)
::
from sqlalchemy_utils import has_unique_index
class Article(Base):
__tablename__ = 'article'
id = sa.Column(sa.Integer, primary_key=True)
title = sa.Column(sa.String(100))
is_published = sa.Column(sa.Boolean, unique=True)
is_deleted = sa.Column(sa.Boolean)
is_archived = sa.Column(sa.Boolean)
table = Article.__table__
has_unique_index(table.c.is_published) # True
has_unique_index(table.c.is_deleted) # False
has_unique_index(table.c.id) # True
This function supports foreign key constraints as well
::
class User(Base):
__tablename__ = 'user'
first_name = sa.Column(sa.Unicode(255), primary_key=True)
last_name = sa.Column(sa.Unicode(255), primary_key=True)
class Article(Base):
__tablename__ = 'article'
id = sa.Column(sa.Integer, primary_key=True)
author_first_name = sa.Column(sa.Unicode(255))
author_last_name = sa.Column(sa.Unicode(255))
__table_args__ = (
sa.ForeignKeyConstraint(
[author_first_name, author_last_name],
[User.first_name, User.last_name]
),
sa.Index(
'my_index',
author_first_name,
author_last_name,
unique=True
)
)
table = Article.__table__
constraint = list(table.foreign_keys)[0].constraint
has_unique_index(constraint) # True
:raises TypeError: if given column does not belong to a Table object
"""
table = column_or_constraint.table
if not isinstance(table, sa.Table):
raise TypeError(
'Only columns belonging to Table objects are supported. Given '
'column belongs to %r.' % table
)
primary_keys = list(table.primary_key.columns.values())
if isinstance(column_or_constraint, sa.ForeignKeyConstraint):
columns = list(column_or_constraint.columns.values())
else:
columns = [column_or_constraint]
return (
(columns == primary_keys) or
any(
columns == list(constraint.columns.values())
for constraint in table.constraints
if isinstance(constraint, sa.sql.schema.UniqueConstraint)
) or
any(
columns == list(index.columns.values())
for index in table.indexes
if index.unique
)
)
def is_auto_assigned_date_column(column):
"""
Returns whether or not given SQLAlchemy Column object's is auto assigned
DateTime or Date.
:param column: SQLAlchemy Column object
"""
return (
(
isinstance(column.type, sa.DateTime) or
isinstance(column.type, sa.Date)
) and
(
column.default or
column.server_default or
column.onupdate or
column.server_onupdate
)
)
def _set_url_database(url: sa.engine.url.URL, database):
"""Set the database of an engine URL.
:param url: A SQLAlchemy engine URL.
:param database: New database to set.
"""
if hasattr(url, '_replace'):
# Cannot use URL.set() as database may need to be set to None.
ret = url._replace(database=database)
else: # SQLAlchemy <1.4
url = copy(url)
url.database = database
ret = url
assert ret.database == database, ret
return ret
def _get_scalar_result(engine, sql):
with engine.connect() as conn:
return conn.scalar(sql)
def _sqlite_file_exists(database):
if not os.path.isfile(database) or os.path.getsize(database) < 100:
return False
with open(database, 'rb') as f:
header = f.read(100)
return header[:16] == b'SQLite format 3\x00'
def database_exists(url):
"""Check if a database exists.
:param url: A SQLAlchemy engine URL.
Performs backend-specific testing to quickly determine if a database
exists on the server. ::
database_exists('postgresql://postgres@localhost/name') #=> False
create_database('postgresql://postgres@localhost/name')
database_exists('postgresql://postgres@localhost/name') #=> True
Supports checking against a constructed URL as well. ::
engine = create_engine('postgresql://postgres@localhost/name')
database_exists(engine.url) #=> False
create_database(engine.url)
database_exists(engine.url) #=> True
"""
url = make_url(url)
database = url.database
dialect_name = url.get_dialect().name
engine = None
try:
if dialect_name == 'postgresql':
text = "SELECT 1 FROM pg_database WHERE datname='%s'" % database
for db in (database, 'postgres', 'template1', 'template0', None):
url = _set_url_database(url, database=db)
engine = sa.create_engine(url)
try:
return bool(_get_scalar_result(engine, sa.text(text)))
except (ProgrammingError, OperationalError):
pass
return False
elif dialect_name == 'mysql':
url = _set_url_database(url, database=None)
engine = sa.create_engine(url)
text = ("SELECT SCHEMA_NAME FROM INFORMATION_SCHEMA.SCHEMATA "
"WHERE SCHEMA_NAME = '%s'" % database)
return bool(_get_scalar_result(engine, sa.text(text)))
elif dialect_name == 'sqlite':
url = _set_url_database(url, database=None)
engine = sa.create_engine(url)
if database:
return database == ':memory:' or _sqlite_file_exists(database)
else:
# The default SQLAlchemy database is in memory, and :memory: is
# not required, thus we should support that use case.
return True
else:
text = 'SELECT 1'
try:
engine = sa.create_engine(url)
return bool(_get_scalar_result(engine, sa.text(text)))
except (ProgrammingError, OperationalError):
return False
finally:
if engine:
engine.dispose()
def create_database(url, encoding='utf8', template=None):
"""Issue the appropriate CREATE DATABASE statement.
:param url: A SQLAlchemy engine URL.
:param encoding: The encoding to create the database as.
:param template:
The name of the template from which to create the new database. At the
moment only supported by PostgreSQL driver.
To create a database, you can pass a simple URL that would have
been passed to ``create_engine``. ::
create_database('postgresql://postgres@localhost/name')
You may also pass the url from an existing engine. ::
create_database(engine.url)
Has full support for mysql, postgres, and sqlite. In theory,
other database engines should be supported.
"""
url = make_url(url)
database = url.database
dialect_name = url.get_dialect().name
dialect_driver = url.get_dialect().driver
if dialect_name == 'postgresql':
url = _set_url_database(url, database="postgres")
elif dialect_name == 'mssql':
url = _set_url_database(url, database="master")
elif dialect_name == 'cockroachdb':
url = _set_url_database(url, database="defaultdb")
elif not dialect_name == 'sqlite':
url = _set_url_database(url, database=None)
if (dialect_name == 'mssql' and dialect_driver in {'pymssql', 'pyodbc'}) \
or (dialect_name == 'postgresql' and dialect_driver in {
'asyncpg', 'pg8000', 'psycopg', 'psycopg2', 'psycopg2cffi'}):
engine = sa.create_engine(url, isolation_level='AUTOCOMMIT')
else:
engine = sa.create_engine(url)
if dialect_name == 'postgresql':
if not template:
template = 'template1'
with engine.begin() as conn:
text = "CREATE DATABASE {} ENCODING '{}' TEMPLATE {}".format(
quote(conn, database),
encoding,
quote(conn, template)
)
conn.execute(sa.text(text))
elif dialect_name == 'mysql':
with engine.begin() as conn:
text = "CREATE DATABASE {} CHARACTER SET = '{}'".format(
quote(conn, database),
encoding
)
conn.execute(sa.text(text))
elif dialect_name == 'sqlite' and database != ':memory:':
if database:
with engine.begin() as conn:
conn.execute(sa.text('CREATE TABLE DB(id int)'))
conn.execute(sa.text('DROP TABLE DB'))
else:
with engine.begin() as conn:
text = f'CREATE DATABASE {quote(conn, database)}'
conn.execute(sa.text(text))
engine.dispose()
def drop_database(url):
"""Issue the appropriate DROP DATABASE statement.
:param url: A SQLAlchemy engine URL.
Works similar to the :ref:`create_database` method in that both url text
and a constructed url are accepted. ::
drop_database('postgresql://postgres@localhost/name')
drop_database(engine.url)
"""
url = make_url(url)
database = url.database
dialect_name = url.get_dialect().name
dialect_driver = url.get_dialect().driver
if dialect_name == 'postgresql':
url = _set_url_database(url, database="postgres")
elif dialect_name == 'mssql':
url = _set_url_database(url, database="master")
elif dialect_name == 'cockroachdb':
url = _set_url_database(url, database="defaultdb")
elif not dialect_name == 'sqlite':
url = _set_url_database(url, database=None)
if dialect_name == 'mssql' and dialect_driver in {'pymssql', 'pyodbc'}:
engine = sa.create_engine(url, connect_args={'autocommit': True})
elif dialect_name == 'postgresql' and dialect_driver in {
'asyncpg', 'pg8000', 'psycopg', 'psycopg2', 'psycopg2cffi'}:
engine = sa.create_engine(url, isolation_level='AUTOCOMMIT')
else:
engine = sa.create_engine(url)
if dialect_name == 'sqlite' and database != ':memory:':
if database:
os.remove(database)
elif dialect_name == 'postgresql':
with engine.begin() as conn:
# Disconnect all users from the database we are dropping.
version = conn.dialect.server_version_info
pid_column = (
'pid' if (version >= (9, 2)) else 'procpid'
)
text = '''
SELECT pg_terminate_backend(pg_stat_activity.{pid_column})
FROM pg_stat_activity
WHERE pg_stat_activity.datname = '{database}'
AND {pid_column} <> pg_backend_pid();
'''.format(pid_column=pid_column, database=database)
conn.execute(sa.text(text))
# Drop the database.
text = f'DROP DATABASE {quote(conn, database)}'
conn.execute(sa.text(text))
else:
with engine.begin() as conn:
text = f'DROP DATABASE {quote(conn, database)}'
conn.execute(sa.text(text))
engine.dispose()
|