Skip to content

Commit

Permalink
New column_order= parameter for setting column order
Browse files Browse the repository at this point in the history
  • Loading branch information
Simon Willison committed Aug 8, 2018
1 parent 72644b6 commit 9eacd30
Show file tree
Hide file tree
Showing 3 changed files with 96 additions and 15 deletions.
16 changes: 16 additions & 0 deletions docs/table.rst
Original file line number Diff line number Diff line change
Expand Up @@ -74,6 +74,22 @@ You can also specify a primary key by passing the ``pk=`` parameter to the ``.in
"is_good_dog": True,
}, pk="id")
The order of the columns in the table will be derived from the order of the keys in the dictionary, provided you are using Python 3.6 or later.

If you want to explicitly set the order of the columns you can do so using the ``column_order=`` parameter:

.. code-block:: python
dogs.insert({
"id": 1,
"name": "Cleo",
"twitter": "cleopaws",
"age": 3,
"is_good_dog": True,
}, pk="id", column_order=("id", "twitter", "name"))
You don't need to pass all of the columns to the ``column_order`` parameter. If you only pass a subset of the columns the remaining columns will be ordered based on the key order of the dictionary.

Creating views
==============

Expand Down
72 changes: 57 additions & 15 deletions sqlite_utils/db.py
Original file line number Diff line number Diff line change
Expand Up @@ -42,12 +42,19 @@ def execute_returning_dicts(self, sql, params=None):
keys = [d[0] for d in cursor.description]
return [dict(zip(keys, row)) for row in cursor.fetchall()]

def create_table(self, name, columns, pk=None, foreign_keys=None):
def create_table(
self, name, columns, pk=None, foreign_keys=None, column_order=None
):
foreign_keys = foreign_keys or []
foreign_keys_by_name = {fk[0]: fk for fk in foreign_keys}
column_items = list(columns.items())
if column_order is not None:
column_items.sort(
key=lambda p: column_order.index(p[0]) if p[0] in column_order else 999
)
extra = ""
columns_sql = ",\n".join(
" {col_name} {col_type} {primary_key} {references}".format(
" [{col_name}] {col_type} {primary_key} {references}".format(
col_name=col_name,
col_type={
float: "FLOAT",
Expand All @@ -66,9 +73,9 @@ def create_table(self, name, columns, pk=None, foreign_keys=None):
else ""
),
)
for col_name, col_type in columns.items()
for col_name, col_type in column_items
)
sql = """CREATE TABLE {table} (
sql = """CREATE TABLE [{table}] (
{columns_sql}
){extra};
""".format(
Expand Down Expand Up @@ -160,9 +167,15 @@ def indexes(self):
indexes.append(Index(**row))
return indexes

def create(self, columns, pk=None, foreign_keys=None):
def create(self, columns, pk=None, foreign_keys=None, column_order=None):
columns = {name: value for (name, value) in columns.items()}
self.db.create_table(self.name, columns, pk=pk, foreign_keys=foreign_keys)
self.db.create_table(
self.name,
columns,
pk=pk,
foreign_keys=foreign_keys,
column_order=column_order,
)
self.exists = True
return self

Expand Down Expand Up @@ -256,28 +269,45 @@ def search(self, q):
)
return self.db.conn.execute(sql, (q,)).fetchall()

def insert(self, record, pk=None, foreign_keys=None, upsert=False):
def insert(
self, record, pk=None, foreign_keys=None, upsert=False, column_order=None
):
return self.insert_all(
[record], pk=pk, foreign_keys=foreign_keys, upsert=upsert
[record],
pk=pk,
foreign_keys=foreign_keys,
upsert=upsert,
column_order=column_order,
)

def insert_all(
self, records, pk=None, foreign_keys=None, upsert=False, batch_size=100
self,
records,
pk=None,
foreign_keys=None,
upsert=False,
batch_size=100,
column_order=None,
):
"""
Like .insert() but takes a list of records and ensures that the table
that it creates (if table does not exist) has columns for ALL of that
data
"""
if not self.exists:
self.create(self.detect_column_types(records), pk, foreign_keys)
self.create(
self.detect_column_types(records),
pk,
foreign_keys,
column_order=column_order,
)
all_columns = set()
for record in records:
all_columns.update(record.keys())
all_columns = list(sorted(all_columns))
for chunk in chunks(records, batch_size):
sql = """
INSERT {upsert} INTO {table} ({columns}) VALUES {rows};
INSERT {upsert} INTO [{table}] ({columns}) VALUES {rows};
""".format(
upsert="OR REPLACE" if upsert else "",
table=self.name,
Expand All @@ -301,11 +331,23 @@ def insert_all(
self.last_id = result.lastrowid
return self

def upsert(self, record, pk=None, foreign_keys=None):
return self.insert(record, pk=pk, foreign_keys=foreign_keys, upsert=True)
def upsert(self, record, pk=None, foreign_keys=None, column_order=None):
return self.insert(
record,
pk=pk,
foreign_keys=foreign_keys,
upsert=True,
column_order=column_order,
)

def upsert_all(self, records, pk=None, foreign_keys=None):
return self.insert_all(records, pk=pk, foreign_keys=foreign_keys, upsert=True)
def upsert_all(self, records, pk=None, foreign_keys=None, column_order=None):
return self.insert_all(
records,
pk=pk,
foreign_keys=foreign_keys,
upsert=True,
column_order=column_order,
)


def chunks(sequence, size):
Expand Down
23 changes: 23 additions & 0 deletions tests/test_create.py
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
from .fixtures import fresh_db
from sqlite_utils.db import Index
import collections
import pytest
import json

Expand Down Expand Up @@ -36,6 +37,28 @@ def test_create_table_from_example(fresh_db, example, expected_columns):
]


def test_create_table_column_order(fresh_db):
fresh_db["table"].insert(
collections.OrderedDict(
(
("zzz", "third"),
("abc", "first"),
("ccc", "second"),
("bbb", "second-to-last"),
("aaa", "last"),
)
),
column_order=("abc", "ccc", "zzz"),
)
assert [
{"name": "abc", "type": "TEXT"},
{"name": "ccc", "type": "TEXT"},
{"name": "zzz", "type": "TEXT"},
{"name": "bbb", "type": "TEXT"},
{"name": "aaa", "type": "TEXT"},
] == [{"name": col.name, "type": col.type} for col in fresh_db["table"].columns]


def test_create_table_works_for_m2m_with_only_foreign_keys(fresh_db):
fresh_db["one"].insert({"id": 1}, pk="id")
fresh_db["two"].insert({"id": 1}, pk="id")
Expand Down

0 comments on commit 9eacd30

Please sign in to comment.