-
-
Notifications
You must be signed in to change notification settings - Fork 115
/
db.py
3629 lines (3278 loc) · 134 KB
/
db.py
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
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
from .utils import (
chunks,
hash_record,
sqlite3,
OperationalError,
suggest_column_types,
types_for_column_types,
column_affinity,
progressbar,
find_spatialite,
)
import binascii
from collections import namedtuple
from collections.abc import Mapping
import contextlib
import datetime
import decimal
import inspect
import itertools
import json
import os
import pathlib
import re
import secrets
from sqlite_fts4 import rank_bm25 # type: ignore
import textwrap
from typing import (
cast,
Any,
Callable,
Dict,
Generator,
Iterable,
Union,
Optional,
List,
Tuple,
)
import uuid
SQLITE_MAX_VARS = 999
_quote_fts_re = re.compile(r'\s+|(".*?")')
_virtual_table_using_re = re.compile(
r"""
^ # Start of string
\s*CREATE\s+VIRTUAL\s+TABLE\s+ # CREATE VIRTUAL TABLE
(
'(?P<squoted_table>[^']*(?:''[^']*)*)' | # single quoted name
"(?P<dquoted_table>[^"]*(?:""[^"]*)*)" | # double quoted name
`(?P<backtick_table>[^`]+)` | # `backtick` quoted name
\[(?P<squarequoted_table>[^\]]+)\] | # [...] quoted name
(?P<identifier> # SQLite non-quoted identifier
[A-Za-z_\u0080-\uffff] # \u0080-\uffff = "any character larger than u007f"
[A-Za-z_\u0080-\uffff0-9\$]* # zero-or-more alphanemuric or $
)
)
\s+(IF\s+NOT\s+EXISTS\s+)? # IF NOT EXISTS (optional)
USING\s+(?P<using>\w+) # for example USING FTS5
""",
re.VERBOSE | re.IGNORECASE,
)
try:
import pandas as pd # type: ignore
except ImportError:
pd = None # type: ignore
try:
import numpy as np # type: ignore
except ImportError:
np = None # type: ignore
Column = namedtuple(
"Column", ("cid", "name", "type", "notnull", "default_value", "is_pk")
)
Column.__doc__ = """
Describes a SQLite column returned by the :attr:`.Table.columns` property.
``cid``
Column index
``name``
Column name
``type``
Column type
``notnull``
Does the column have a ``not null`` constraint
``default_value``
Default value for this column
``is_pk``
Is this column part of the primary key
"""
ColumnDetails = namedtuple(
"ColumnDetails",
(
"table",
"column",
"total_rows",
"num_null",
"num_blank",
"num_distinct",
"most_common",
"least_common",
),
)
ColumnDetails.__doc__ = """
Summary information about a column, see :ref:`python_api_analyze_column`.
``table``
The name of the table
``column``
The name of the column
``total_rows``
The total number of rows in the table
``num_null``
The number of rows for which this column is null
``num_blank``
The number of rows for which this column is blank (the empty string)
``num_distinct``
The number of distinct values in this column
``most_common``
The ``N`` most common values as a list of ``(value, count)`` tuples, or ``None`` if the table consists entirely of distinct values
``least_common``
The ``N`` least common values as a list of ``(value, count)`` tuples, or ``None`` if the table is entirely distinct
or if the number of distinct values is less than N (since they will already have been returned in ``most_common``)
"""
ForeignKey = namedtuple(
"ForeignKey", ("table", "column", "other_table", "other_column")
)
Index = namedtuple("Index", ("seq", "name", "unique", "origin", "partial", "columns"))
XIndex = namedtuple("XIndex", ("name", "columns"))
XIndexColumn = namedtuple(
"XIndexColumn", ("seqno", "cid", "name", "desc", "coll", "key")
)
Trigger = namedtuple("Trigger", ("name", "table", "sql"))
ForeignKeysType = Union[
Iterable[str],
Iterable[ForeignKey],
Iterable[Tuple[str, str]],
Iterable[Tuple[str, str, str]],
Iterable[Tuple[str, str, str, str]],
]
class Default:
pass
DEFAULT = Default()
COLUMN_TYPE_MAPPING = {
float: "FLOAT",
int: "INTEGER",
bool: "INTEGER",
str: "TEXT",
dict: "TEXT",
tuple: "TEXT",
list: "TEXT",
bytes.__class__: "BLOB",
bytes: "BLOB",
memoryview: "BLOB",
datetime.datetime: "TEXT",
datetime.date: "TEXT",
datetime.time: "TEXT",
decimal.Decimal: "FLOAT",
None.__class__: "TEXT",
uuid.UUID: "TEXT",
# SQLite explicit types
"TEXT": "TEXT",
"INTEGER": "INTEGER",
"FLOAT": "FLOAT",
"BLOB": "BLOB",
"text": "TEXT",
"integer": "INTEGER",
"float": "FLOAT",
"blob": "BLOB",
}
# If numpy is available, add more types
if np:
COLUMN_TYPE_MAPPING.update(
{
np.int8: "INTEGER",
np.int16: "INTEGER",
np.int32: "INTEGER",
np.int64: "INTEGER",
np.uint8: "INTEGER",
np.uint16: "INTEGER",
np.uint32: "INTEGER",
np.uint64: "INTEGER",
np.float16: "FLOAT",
np.float32: "FLOAT",
np.float64: "FLOAT",
}
)
# If pandas is available, add more types
if pd:
COLUMN_TYPE_MAPPING.update({pd.Timestamp: "TEXT"}) # type: ignore
class AlterError(Exception):
"Error altering table"
pass
class NoObviousTable(Exception):
"Could not tell which table this operation refers to"
pass
class NoTable(Exception):
"Specified table does not exist"
pass
class BadPrimaryKey(Exception):
"Table does not have a single obvious primary key"
pass
class NotFoundError(Exception):
"Record not found"
pass
class PrimaryKeyRequired(Exception):
"Primary key needs to be specified"
pass
class InvalidColumns(Exception):
"Specified columns do not exist"
pass
class DescIndex(str):
pass
class BadMultiValues(Exception):
"With multi=True code must return a Python dictionary"
def __init__(self, values):
self.values = values
_COUNTS_TABLE_CREATE_SQL = """
CREATE TABLE IF NOT EXISTS [{}](
[table] TEXT PRIMARY KEY,
count INTEGER DEFAULT 0
);
""".strip()
class Database:
"""
Wrapper for a SQLite database connection that adds a variety of useful utility methods.
To create an instance::
# create data.db file, or open existing:
db = Database("data.db")
# Create an in-memory database:
dB = Database(memory=True)
:param filename_or_conn: String path to a file, or a ``pathlib.Path`` object, or a
``sqlite3`` connection
:param memory: set to ``True`` to create an in-memory database
:param memory_name: creates a named in-memory database that can be shared across multiple connections
:param recreate: set to ``True`` to delete and recreate a file database (**dangerous**)
:param recursive_triggers: defaults to ``True``, which sets ``PRAGMA recursive_triggers=on;`` -
set to ``False`` to avoid setting this pragma
:param tracer: set a tracer function (``print`` works for this) which will be called with
``sql, parameters`` every time a SQL query is executed
:param use_counts_table: set to ``True`` to use a cached counts table, if available. See
:ref:`python_api_cached_table_counts`
"""
_counts_table_name = "_counts"
use_counts_table = False
def __init__(
self,
filename_or_conn: Optional[Union[str, pathlib.Path, sqlite3.Connection]] = None,
memory: bool = False,
memory_name: Optional[str] = None,
recreate: bool = False,
recursive_triggers: bool = True,
tracer: Optional[Callable] = None,
use_counts_table: bool = False,
):
assert (filename_or_conn is not None and (not memory and not memory_name)) or (
filename_or_conn is None and (memory or memory_name)
), "Either specify a filename_or_conn or pass memory=True"
if memory_name:
uri = "file:{}?mode=memory&cache=shared".format(memory_name)
self.conn = sqlite3.connect(
uri,
uri=True,
check_same_thread=False,
)
elif memory or filename_or_conn == ":memory:":
self.conn = sqlite3.connect(":memory:")
elif isinstance(filename_or_conn, (str, pathlib.Path)):
if recreate and os.path.exists(filename_or_conn):
try:
os.remove(filename_or_conn)
except OSError:
# Avoid mypy and __repr__ errors, see:
# https://github.com/simonw/sqlite-utils/issues/503
self.conn = sqlite3.connect(":memory:")
raise
self.conn = sqlite3.connect(str(filename_or_conn))
else:
assert not recreate, "recreate cannot be used with connections, only paths"
self.conn = filename_or_conn
self._tracer = tracer
if recursive_triggers:
self.execute("PRAGMA recursive_triggers=on;")
self._registered_functions: set = set()
self.use_counts_table = use_counts_table
def close(self):
"Close the SQLite connection, and the underlying database file"
self.conn.close()
@contextlib.contextmanager
def tracer(self, tracer: Optional[Callable] = None):
"""
Context manager to temporarily set a tracer function - all executed SQL queries will
be passed to this.
The tracer function should accept two arguments: ``sql`` and ``parameters``
Example usage::
with db.tracer(print):
db["creatures"].insert({"name": "Cleo"})
See :ref:`python_api_tracing`.
:param tracer: Callable accepting ``sql`` and ``parameters`` arguments
"""
prev_tracer = self._tracer
self._tracer = tracer or print
try:
yield self
finally:
self._tracer = prev_tracer
def __getitem__(self, table_name: str) -> Union["Table", "View"]:
"""
``db[table_name]`` returns a :class:`.Table` object for the table with the specified name.
If the table does not exist yet it will be created the first time data is inserted into it.
:param table_name: The name of the table
"""
return self.table(table_name)
def __repr__(self) -> str:
return "<Database {}>".format(self.conn)
def register_function(
self,
fn: Optional[Callable] = None,
deterministic: bool = False,
replace: bool = False,
name: Optional[str] = None,
):
"""
``fn`` will be made available as a function within SQL, with the same name and number
of arguments. Can be used as a decorator::
@db.register_function
def upper(value):
return str(value).upper()
The decorator can take arguments::
@db.register_function(deterministic=True, replace=True)
def upper(value):
return str(value).upper()
See :ref:`python_api_register_function`.
:param fn: Function to register
:param deterministic: set ``True`` for functions that always returns the same output for a given input
:param replace: set ``True`` to replace an existing function with the same name - otherwise throw an error
:param name: name of the SQLite function - if not specified, the Python function name will be used
"""
def register(fn):
fn_name = name or fn.__name__
arity = len(inspect.signature(fn).parameters)
if not replace and (fn_name, arity) in self._registered_functions:
return fn
kwargs = {}
registered = False
if deterministic:
# Try this, but fall back if sqlite3.NotSupportedError
try:
self.conn.create_function(
fn_name, arity, fn, **dict(kwargs, deterministic=True)
)
registered = True
except (sqlite3.NotSupportedError, TypeError):
# TypeError is Python 3.7 "function takes at most 3 arguments"
pass
if not registered:
self.conn.create_function(fn_name, arity, fn, **kwargs)
self._registered_functions.add((fn_name, arity))
return fn
if fn is None:
return register
else:
register(fn)
def register_fts4_bm25(self):
"Register the ``rank_bm25(match_info)`` function used for calculating relevance with SQLite FTS4."
self.register_function(rank_bm25, deterministic=True)
def attach(self, alias: str, filepath: Union[str, pathlib.Path]):
"""
Attach another SQLite database file to this connection with the specified alias, equivalent to::
ATTACH DATABASE 'filepath.db' AS alias
:param alias: Alias name to use
:param filepath: Path to SQLite database file on disk
"""
attach_sql = """
ATTACH DATABASE '{}' AS [{}];
""".format(
str(pathlib.Path(filepath).resolve()), alias
).strip()
self.execute(attach_sql)
def query(
self, sql: str, params: Optional[Union[Iterable, dict]] = None
) -> Generator[dict, None, None]:
"""
Execute ``sql`` and return an iterable of dictionaries representing each row.
:param sql: SQL query to execute
:param params: Parameters to use in that query - an iterable for ``where id = ?``
parameters, or a dictionary for ``where id = :id``
"""
cursor = self.execute(sql, params or tuple())
keys = [d[0] for d in cursor.description]
for row in cursor:
yield dict(zip(keys, row))
def execute(
self, sql: str, parameters: Optional[Union[Iterable, dict]] = None
) -> sqlite3.Cursor:
"""
Execute SQL query and return a ``sqlite3.Cursor``.
:param sql: SQL query to execute
:param parameters: Parameters to use in that query - an iterable for ``where id = ?``
parameters, or a dictionary for ``where id = :id``
"""
if self._tracer:
self._tracer(sql, parameters)
if parameters is not None:
return self.conn.execute(sql, parameters)
else:
return self.conn.execute(sql)
def executescript(self, sql: str) -> sqlite3.Cursor:
"""
Execute multiple SQL statements separated by ; and return the ``sqlite3.Cursor``.
:param sql: SQL to execute
"""
if self._tracer:
self._tracer(sql, None)
return self.conn.executescript(sql)
def table(self, table_name: str, **kwargs) -> Union["Table", "View"]:
"""
Return a table object, optionally configured with default options.
See :ref:`reference_db_table` for option details.
:param table_name: Name of the table
"""
klass = View if table_name in self.view_names() else Table
return klass(self, table_name, **kwargs)
def quote(self, value: str) -> str:
"""
Apply SQLite string quoting to a value, including wrappping it in single quotes.
:param value: String to quote
"""
# Normally we would use .execute(sql, [params]) for escaping, but
# occasionally that isn't available - most notable when we need
# to include a "... DEFAULT 'value'" in a column definition.
return self.execute(
# Use SQLite itself to correctly escape this string:
"SELECT quote(:value)",
{"value": value},
).fetchone()[0]
def quote_fts(self, query: str) -> str:
"""
Escape special characters in a SQLite full-text search query.
This works by surrounding each token within the query with double
quotes, in order to avoid words like ``NOT`` and ``OR`` having
special meaning as defined by the FTS query syntax here:
https://www.sqlite.org/fts5.html#full_text_query_syntax
If the query has unbalanced ``"`` characters, adds one at end.
:param query: String to escape
"""
if query.count('"') % 2:
query += '"'
bits = _quote_fts_re.split(query)
bits = [b for b in bits if b and b != '""']
return " ".join(
'"{}"'.format(bit) if not bit.startswith('"') else bit for bit in bits
)
def table_names(self, fts4: bool = False, fts5: bool = False) -> List[str]:
"""
List of string table names in this database.
:param fts4: Only return tables that are part of FTS4 indexes
:param fts5: Only return tables that are part of FTS5 indexes
"""
where = ["type = 'table'"]
if fts4:
where.append("sql like '%USING FTS4%'")
if fts5:
where.append("sql like '%USING FTS5%'")
sql = "select name from sqlite_master where {}".format(" AND ".join(where))
return [r[0] for r in self.execute(sql).fetchall()]
def view_names(self) -> List[str]:
"List of string view names in this database."
return [
r[0]
for r in self.execute(
"select name from sqlite_master where type = 'view'"
).fetchall()
]
@property
def tables(self) -> List["Table"]:
"List of Table objects in this database."
return cast(List["Table"], [self[name] for name in self.table_names()])
@property
def views(self) -> List["View"]:
"List of View objects in this database."
return cast(List["View"], [self[name] for name in self.view_names()])
@property
def triggers(self) -> List[Trigger]:
"List of ``(name, table_name, sql)`` tuples representing triggers in this database."
return [
Trigger(*r)
for r in self.execute(
"select name, tbl_name, sql from sqlite_master where type = 'trigger'"
).fetchall()
]
@property
def triggers_dict(self) -> Dict[str, str]:
"A ``{trigger_name: sql}`` dictionary of triggers in this database."
return {trigger.name: trigger.sql for trigger in self.triggers}
@property
def schema(self) -> str:
"SQL schema for this database."
sqls = []
for row in self.execute(
"select sql from sqlite_master where sql is not null"
).fetchall():
sql = row[0]
if not sql.strip().endswith(";"):
sql += ";"
sqls.append(sql)
return "\n".join(sqls)
@property
def supports_strict(self) -> bool:
"Does this database support STRICT mode?"
try:
table_name = "t{}".format(secrets.token_hex(16))
with self.conn:
self.conn.execute(
"create table {} (name text) strict".format(table_name)
)
self.conn.execute("drop table {}".format(table_name))
return True
except Exception:
return False
@property
def sqlite_version(self) -> Tuple[int, ...]:
"Version of SQLite, as a tuple of integers for example ``(3, 36, 0)``."
row = self.execute("select sqlite_version()").fetchall()[0]
return tuple(map(int, row[0].split(".")))
@property
def journal_mode(self) -> str:
"""
Current ``journal_mode`` of this database.
https://www.sqlite.org/pragma.html#pragma_journal_mode
"""
return self.execute("PRAGMA journal_mode;").fetchone()[0]
def enable_wal(self):
"""
Sets ``journal_mode`` to ``'wal'`` to enable Write-Ahead Log mode.
"""
if self.journal_mode != "wal":
self.execute("PRAGMA journal_mode=wal;")
def disable_wal(self):
"Sets ``journal_mode`` back to ``'delete'`` to disable Write-Ahead Log mode."
if self.journal_mode != "delete":
self.execute("PRAGMA journal_mode=delete;")
def _ensure_counts_table(self):
with self.conn:
self.execute(_COUNTS_TABLE_CREATE_SQL.format(self._counts_table_name))
def enable_counts(self):
"""
Enable trigger-based count caching for every table in the database, see
:ref:`python_api_cached_table_counts`.
"""
self._ensure_counts_table()
for table in self.tables:
if (
table.virtual_table_using is None
and table.name != self._counts_table_name
):
table.enable_counts()
self.use_counts_table = True
def cached_counts(self, tables: Optional[Iterable[str]] = None) -> Dict[str, int]:
"""
Return ``{table_name: count}`` dictionary of cached counts for specified tables, or
all tables if ``tables`` not provided.
:param tables: Subset list of tables to return counts for.
"""
sql = "select [table], count from {}".format(self._counts_table_name)
if tables:
sql += " where [table] in ({})".format(", ".join("?" for table in tables))
try:
return {r[0]: r[1] for r in self.execute(sql, tables).fetchall()}
except OperationalError:
return {}
def reset_counts(self):
"Re-calculate cached counts for tables."
tables = [table for table in self.tables if table.has_counts_triggers]
with self.conn:
self._ensure_counts_table()
counts_table = self[self._counts_table_name]
counts_table.delete_where()
counts_table.insert_all(
{"table": table.name, "count": table.execute_count()}
for table in tables
)
def execute_returning_dicts(
self, sql: str, params: Optional[Union[Iterable, dict]] = None
) -> List[dict]:
return list(self.query(sql, params))
def resolve_foreign_keys(
self, name: str, foreign_keys: ForeignKeysType
) -> List[ForeignKey]:
# foreign_keys may be a list of column names, a list of ForeignKey tuples,
# a list of tuple-pairs or a list of tuple-triples. We want to turn
# it into a list of ForeignKey tuples
table = cast(Table, self[name])
if all(isinstance(fk, ForeignKey) for fk in foreign_keys):
return cast(List[ForeignKey], foreign_keys)
if all(isinstance(fk, str) for fk in foreign_keys):
# It's a list of columns
fks = []
for column in foreign_keys:
column = cast(str, column)
other_table = table.guess_foreign_table(column)
other_column = table.guess_foreign_column(other_table)
fks.append(ForeignKey(name, column, other_table, other_column))
return fks
assert all(
isinstance(fk, (tuple, list)) for fk in foreign_keys
), "foreign_keys= should be a list of tuples"
fks = []
for tuple_or_list in foreign_keys:
assert len(tuple_or_list) in (
2,
3,
), "foreign_keys= should be a list of tuple pairs or triples"
if len(tuple_or_list) == 3:
tuple_or_list = cast(Tuple[str, str, str], tuple_or_list)
fks.append(
ForeignKey(
name, tuple_or_list[0], tuple_or_list[1], tuple_or_list[2]
)
)
else:
# Guess the primary key
fks.append(
ForeignKey(
name,
tuple_or_list[0],
tuple_or_list[1],
table.guess_foreign_column(tuple_or_list[1]),
)
)
return fks
def create_table_sql(
self,
name: str,
columns: Dict[str, Any],
pk: Optional[Any] = None,
foreign_keys: Optional[ForeignKeysType] = None,
column_order: Optional[List[str]] = None,
not_null: Optional[Iterable[str]] = None,
defaults: Optional[Dict[str, Any]] = None,
hash_id: Optional[str] = None,
hash_id_columns: Optional[Iterable[str]] = None,
extracts: Optional[Union[Dict[str, str], List[str]]] = None,
if_not_exists: bool = False,
) -> str:
"""
Returns the SQL ``CREATE TABLE`` statement for creating the specified table.
:param name: Name of table
:param columns: Dictionary mapping column names to their types, for example ``{"name": str, "age": int}``
:param pk: String name of column to use as a primary key, or a tuple of strings for a compound primary key covering multiple columns
:param foreign_keys: List of foreign key definitions for this table
:param column_order: List specifying which columns should come first
:param not_null: List of columns that should be created as ``NOT NULL``
:param defaults: Dictionary specifying default values for columns
:param hash_id: Name of column to be used as a primary key containing a hash of the other columns
:param hash_id_columns: List of columns to be used when calculating the hash ID for a row
:param extracts: List or dictionary of columns to be extracted during inserts, see :ref:`python_api_extracts`
:param if_not_exists: Use ``CREATE TABLE IF NOT EXISTS``
"""
if hash_id_columns and (hash_id is None):
hash_id = "id"
foreign_keys = self.resolve_foreign_keys(name, foreign_keys or [])
foreign_keys_by_column = {fk.column: fk for fk in foreign_keys}
# any extracts will be treated as integer columns with a foreign key
extracts = resolve_extracts(extracts)
for extract_column, extract_table in extracts.items():
if isinstance(extract_column, tuple):
assert False
# Ensure other table exists
if not self[extract_table].exists():
self.create_table(extract_table, {"id": int, "value": str}, pk="id")
columns[extract_column] = int
foreign_keys_by_column[extract_column] = ForeignKey(
name, extract_column, extract_table, "id"
)
# Soundness check not_null, and defaults if provided
not_null = not_null or set()
defaults = defaults or {}
assert columns, "Tables must have at least one column"
assert all(
n in columns for n in not_null
), "not_null set {} includes items not in columns {}".format(
repr(not_null), repr(set(columns.keys()))
)
assert all(
n in columns for n in defaults
), "defaults set {} includes items not in columns {}".format(
repr(set(defaults)), repr(set(columns.keys()))
)
validate_column_names(columns.keys())
column_items = list(columns.items())
if column_order is not None:
def sort_key(p):
return column_order.index(p[0]) if p[0] in column_order else 999
column_items.sort(key=sort_key)
if hash_id:
column_items.insert(0, (hash_id, str))
pk = hash_id
# Soundness check foreign_keys point to existing tables
for fk in foreign_keys:
if not any(
c for c in self[fk.other_table].columns if c.name == fk.other_column
):
raise AlterError(
"No such column: {}.{}".format(fk.other_table, fk.other_column)
)
column_defs = []
# ensure pk is a tuple
single_pk = None
if isinstance(pk, list) and len(pk) == 1 and isinstance(pk[0], str):
pk = pk[0]
if isinstance(pk, str):
single_pk = pk
if pk not in [c[0] for c in column_items]:
column_items.insert(0, (pk, int))
for column_name, column_type in column_items:
column_extras = []
if column_name == single_pk:
column_extras.append("PRIMARY KEY")
if column_name in not_null:
column_extras.append("NOT NULL")
if column_name in defaults and defaults[column_name] is not None:
column_extras.append(
"DEFAULT {}".format(self.quote(defaults[column_name]))
)
if column_name in foreign_keys_by_column:
column_extras.append(
"REFERENCES [{other_table}]([{other_column}])".format(
other_table=foreign_keys_by_column[column_name].other_table,
other_column=foreign_keys_by_column[column_name].other_column,
)
)
column_defs.append(
" [{column_name}] {column_type}{column_extras}".format(
column_name=column_name,
column_type=COLUMN_TYPE_MAPPING[column_type],
column_extras=(" " + " ".join(column_extras))
if column_extras
else "",
)
)
extra_pk = ""
if single_pk is None and pk and len(pk) > 1:
extra_pk = ",\n PRIMARY KEY ({pks})".format(
pks=", ".join(["[{}]".format(p) for p in pk])
)
columns_sql = ",\n".join(column_defs)
sql = """CREATE TABLE {if_not_exists}[{table}] (
{columns_sql}{extra_pk}
);
""".format(
if_not_exists="IF NOT EXISTS " if if_not_exists else "",
table=name,
columns_sql=columns_sql,
extra_pk=extra_pk,
)
return sql
def create_table(
self,
name: str,
columns: Dict[str, Any],
pk: Optional[Any] = None,
foreign_keys: Optional[ForeignKeysType] = None,
column_order: Optional[List[str]] = None,
not_null: Optional[Iterable[str]] = None,
defaults: Optional[Dict[str, Any]] = None,
hash_id: Optional[str] = None,
hash_id_columns: Optional[Iterable[str]] = None,
extracts: Optional[Union[Dict[str, str], List[str]]] = None,
if_not_exists: bool = False,
transform: bool = False,
) -> "Table":
"""
Create a table with the specified name and the specified ``{column_name: type}`` columns.
See :ref:`python_api_explicit_create`.
:param name: Name of table
:param columns: Dictionary mapping column names to their types, for example ``{"name": str, "age": int}``
:param pk: String name of column to use as a primary key, or a tuple of strings for a compound primary key covering multiple columns
:param foreign_keys: List of foreign key definitions for this table
:param column_order: List specifying which columns should come first
:param not_null: List of columns that should be created as ``NOT NULL``
:param defaults: Dictionary specifying default values for columns
:param hash_id: Name of column to be used as a primary key containing a hash of the other columns
:param hash_id_columns: List of columns to be used when calculating the hash ID for a row
:param extracts: List or dictionary of columns to be extracted during inserts, see :ref:`python_api_extracts`
:param if_not_exists: Use ``CREATE TABLE IF NOT EXISTS``
:param transform: If table already exists transform it to fit the specified schema
"""
# Transform table to match the new definition if table already exists:
if transform and self[name].exists():
table = cast(Table, self[name])
should_transform = False
# First add missing columns and figure out columns to drop
existing_columns = table.columns_dict
missing_columns = dict(
(col_name, col_type)
for col_name, col_type in columns.items()
if col_name not in existing_columns
)
columns_to_drop = [
column for column in existing_columns if column not in columns
]
if missing_columns:
for col_name, col_type in missing_columns.items():
table.add_column(col_name, col_type)
if missing_columns or columns_to_drop or columns != existing_columns:
should_transform = True
# Do we need to change the column order?
if (
column_order
and list(existing_columns)[: len(column_order)] != column_order
):
should_transform = True
# Has the primary key changed?
current_pks = table.pks
desired_pk = None
if isinstance(pk, str):
desired_pk = [pk]
elif pk:
desired_pk = list(pk)
if desired_pk and current_pks != desired_pk:
should_transform = True
# Any not-null changes?
current_not_null = {c.name for c in table.columns if c.notnull}
desired_not_null = set(not_null) if not_null else set()
if current_not_null != desired_not_null:
should_transform = True
# How about defaults?
if defaults and defaults != table.default_values:
should_transform = True
# Only run .transform() if there is something to do
if should_transform:
table.transform(
types=columns,
drop=columns_to_drop,
column_order=column_order,
not_null=not_null,
defaults=defaults,
pk=pk,
)
return table
sql = self.create_table_sql(
name=name,
columns=columns,
pk=pk,
foreign_keys=foreign_keys,
column_order=column_order,
not_null=not_null,
defaults=defaults,
hash_id=hash_id,
hash_id_columns=hash_id_columns,
extracts=extracts,
if_not_exists=if_not_exists,
)
self.execute(sql)
created_table = self.table(
name,
pk=pk,
foreign_keys=foreign_keys,
column_order=column_order,
not_null=not_null,
defaults=defaults,
hash_id=hash_id,
hash_id_columns=hash_id_columns,
)
return cast(Table, created_table)
def create_view(
self, name: str, sql: str, ignore: bool = False, replace: bool = False
):
"""
Create a new SQL view with the specified name - ``sql`` should start with ``SELECT ...``.
:param name: Name of the view
:param sql: SQL ``SELECT`` query to use for this view.
:param ignore: Set to ``True`` to do nothing if a view with this name already exists
:param replace: Set to ``True`` to replace the view if one with this name already exists
"""
assert not (
ignore and replace
), "Use one or the other of ignore/replace, not both"