Skip to content

Commit

Permalink
New ?tags__arraycontains=tag lookup against JSON fields
Browse files Browse the repository at this point in the history
Part one of supporting facet-by-JSON-array, refs #359
  • Loading branch information
simonw committed Apr 10, 2019
1 parent 3a208a4 commit 78e45ea
Show file tree
Hide file tree
Showing 6 changed files with 74 additions and 41 deletions.
25 changes: 21 additions & 4 deletions datasette/utils.py
Original file line number Original file line Diff line number Diff line change
Expand Up @@ -565,6 +565,16 @@ def detect_fts_sql(table):
'''.format(table=table) '''.format(table=table)




def detect_json1(conn=None):
if conn is None:
conn = sqlite3.connect(":memory:")
try:
conn.execute("SELECT json('{}')")
return True
except Exception:
return False


def table_columns(conn, table): def table_columns(conn, table):
return [ return [
r[1] r[1]
Expand All @@ -584,7 +594,7 @@ def __init__(self, key, display, sql_template, human_template, format='{}', nume
self.numeric = numeric self.numeric = numeric
self.no_argument = no_argument self.no_argument = no_argument


def where_clause(self, column, value, param_counter): def where_clause(self, table, column, value, param_counter):
converted = self.format.format(value) converted = self.format.format(value)
if self.numeric and converted.isdigit(): if self.numeric and converted.isdigit():
converted = int(converted) converted = int(converted)
Expand All @@ -597,6 +607,7 @@ def where_clause(self, column, value, param_counter):
kwargs = { kwargs = {
'c': column, 'c': column,
'p': 'p{}'.format(param_counter), 'p': 'p{}'.format(param_counter),
't': table,
} }
return self.sql_template.format(**kwargs), converted return self.sql_template.format(**kwargs), converted


Expand All @@ -613,6 +624,7 @@ def human_clause(self, column, value):


class Filters: class Filters:
_filters = [ _filters = [
# key, display, sql_template, human_template, format=, numeric=, no_argument=
Filter('exact', '=', '"{c}" = :{p}', lambda c, v: '{c} = {v}' if v.isdigit() else '{c} = "{v}"'), Filter('exact', '=', '"{c}" = :{p}', lambda c, v: '{c} = {v}' if v.isdigit() else '{c} = "{v}"'),
Filter('not', '!=', '"{c}" != :{p}', lambda c, v: '{c} != {v}' if v.isdigit() else '{c} != "{v}"'), Filter('not', '!=', '"{c}" != :{p}', lambda c, v: '{c} != {v}' if v.isdigit() else '{c} != "{v}"'),
Filter('contains', 'contains', '"{c}" like :{p}', '{c} contains "{v}"', format='%{}%'), Filter('contains', 'contains', '"{c}" like :{p}', '{c} contains "{v}"', format='%{}%'),
Expand All @@ -624,6 +636,11 @@ class Filters:
Filter('lte', '\u2264', '"{c}" <= :{p}', '{c} \u2264 {v}', numeric=True), Filter('lte', '\u2264', '"{c}" <= :{p}', '{c} \u2264 {v}', numeric=True),
Filter('glob', 'glob', '"{c}" glob :{p}', '{c} glob "{v}"'), Filter('glob', 'glob', '"{c}" glob :{p}', '{c} glob "{v}"'),
Filter('like', 'like', '"{c}" like :{p}', '{c} like "{v}"'), Filter('like', 'like', '"{c}" like :{p}', '{c} like "{v}"'),
] + ([Filter('arraycontains', 'array contains', """rowid in (
select {t}.rowid from {t}, json_each({t}.{c}) j
where j.value = :{p}
)""", '{c} contains "{v}"')
] if detect_json1() else []) + [
Filter('isnull', 'is null', '"{c}" is null', '{c} is null', no_argument=True), Filter('isnull', 'is null', '"{c}" is null', '{c} is null', no_argument=True),
Filter('notnull', 'is not null', '"{c}" is not null', '{c} is not null', no_argument=True), Filter('notnull', 'is not null', '"{c}" is not null', '{c} is not null', no_argument=True),
Filter('isblank', 'is blank', '("{c}" is null or "{c}" = "")', '{c} is blank', no_argument=True), Filter('isblank', 'is blank', '("{c}" is null or "{c}" = "")', '{c} is blank', no_argument=True),
Expand Down Expand Up @@ -677,7 +694,7 @@ def has_selections(self):
return bool(self.pairs) return bool(self.pairs)


def convert_unit(self, column, value): def convert_unit(self, column, value):
"If the user has provided a unit in the quey, convert it into the column unit, if present." "If the user has provided a unit in the query, convert it into the column unit, if present."
if column not in self.units: if column not in self.units:
return value return value


Expand All @@ -690,13 +707,13 @@ def convert_unit(self, column, value):
column_unit = self.ureg(self.units[column]) column_unit = self.ureg(self.units[column])
return value.to(column_unit).magnitude return value.to(column_unit).magnitude


def build_where_clauses(self): def build_where_clauses(self, table):
sql_bits = [] sql_bits = []
params = {} params = {}
for i, (column, lookup, value) in enumerate(self.selections()): for i, (column, lookup, value) in enumerate(self.selections()):
filter = self._filters_by_key.get(lookup, None) filter = self._filters_by_key.get(lookup, None)
if filter: if filter:
sql_bit, param = filter.where_clause(column, self.convert_unit(column, value), i) sql_bit, param = filter.where_clause(table, column, self.convert_unit(column, value), i)
sql_bits.append(sql_bit) sql_bits.append(sql_bit)
if param is not None: if param is not None:
param_id = 'p{}'.format(i) param_id = 'p{}'.format(i)
Expand Down
2 changes: 1 addition & 1 deletion datasette/views/table.py
Original file line number Original file line Diff line number Diff line change
Expand Up @@ -293,7 +293,7 @@ async def data(self, request, database, hash, table, default_labels=False, _nex
table_metadata = self.ds.table_metadata(database, table) table_metadata = self.ds.table_metadata(database, table)
units = table_metadata.get("units", {}) units = table_metadata.get("units", {})
filters = Filters(sorted(other_args.items()), units, ureg) filters = Filters(sorted(other_args.items()), units, ureg)
where_clauses, params = filters.build_where_clauses() where_clauses, params = filters.build_where_clauses(table)


# _search support: # _search support:
fts_table = await self.ds.execute_against_connection_in_thread( fts_table = await self.ds.execute_against_connection_in_thread(
Expand Down
33 changes: 17 additions & 16 deletions tests/fixtures.py
Original file line number Original file line Diff line number Diff line change
Expand Up @@ -523,26 +523,27 @@ def render_cell(value, database):
state text, state text,
city_id integer, city_id integer,
neighborhood text, neighborhood text,
tags text,
FOREIGN KEY ("city_id") REFERENCES [facet_cities](id) FOREIGN KEY ("city_id") REFERENCES [facet_cities](id)
); );
INSERT INTO facetable INSERT INTO facetable
(planet_int, on_earth, state, city_id, neighborhood) (planet_int, on_earth, state, city_id, neighborhood, tags)
VALUES VALUES
(1, 1, 'CA', 1, 'Mission'), (1, 1, 'CA', 1, 'Mission', '["tag1", "tag2"]'),
(1, 1, 'CA', 1, 'Dogpatch'), (1, 1, 'CA', 1, 'Dogpatch', '["tag1", "tag3"]'),
(1, 1, 'CA', 1, 'SOMA'), (1, 1, 'CA', 1, 'SOMA', '[]'),
(1, 1, 'CA', 1, 'Tenderloin'), (1, 1, 'CA', 1, 'Tenderloin', '[]'),
(1, 1, 'CA', 1, 'Bernal Heights'), (1, 1, 'CA', 1, 'Bernal Heights', '[]'),
(1, 1, 'CA', 1, 'Hayes Valley'), (1, 1, 'CA', 1, 'Hayes Valley', '[]'),
(1, 1, 'CA', 2, 'Hollywood'), (1, 1, 'CA', 2, 'Hollywood', '[]'),
(1, 1, 'CA', 2, 'Downtown'), (1, 1, 'CA', 2, 'Downtown', '[]'),
(1, 1, 'CA', 2, 'Los Feliz'), (1, 1, 'CA', 2, 'Los Feliz', '[]'),
(1, 1, 'CA', 2, 'Koreatown'), (1, 1, 'CA', 2, 'Koreatown', '[]'),
(1, 1, 'MI', 3, 'Downtown'), (1, 1, 'MI', 3, 'Downtown', '[]'),
(1, 1, 'MI', 3, 'Greektown'), (1, 1, 'MI', 3, 'Greektown', '[]'),
(1, 1, 'MI', 3, 'Corktown'), (1, 1, 'MI', 3, 'Corktown', '[]'),
(1, 1, 'MI', 3, 'Mexicantown'), (1, 1, 'MI', 3, 'Mexicantown', '[]'),
(2, 0, 'MC', 4, 'Arcadia Planitia') (2, 0, 'MC', 4, 'Arcadia Planitia', '[]')
; ;
INSERT INTO simple_primary_key VALUES (1, 'hello'); INSERT INTO simple_primary_key VALUES (1, 'hello');
Expand Down
21 changes: 18 additions & 3 deletions tests/test_api.py
Original file line number Original file line Diff line number Diff line change
@@ -1,3 +1,4 @@
from datasette.utils import detect_json1
from .fixtures import ( # noqa from .fixtures import ( # noqa
app_client, app_client,
app_client_no_files, app_client_no_files,
Expand Down Expand Up @@ -115,7 +116,7 @@ def test_database_page(app_client):
'hidden': False, 'hidden': False,
'primary_keys': ['id'], 'primary_keys': ['id'],
}, { }, {
'columns': ['pk', 'planet_int', 'on_earth', 'state', 'city_id', 'neighborhood'], 'columns': ['pk', 'planet_int', 'on_earth', 'state', 'city_id', 'neighborhood', 'tags'],
'name': 'facetable', 'name': 'facetable',
'count': 15, 'count': 15,
'foreign_keys': { 'foreign_keys': {
Expand Down Expand Up @@ -882,6 +883,18 @@ def test_table_filter_queries(app_client, path, expected_rows):
assert expected_rows == response.json['rows'] assert expected_rows == response.json['rows']




@pytest.mark.skipif(
not detect_json1(),
reason="Requires the SQLite json1 module"
)
def test_table_filter_json_arraycontains(app_client):
response = app_client.get("/fixtures/facetable.json?tags__arraycontains=tag1")
assert [
[1, 1, 1, 'CA', 1, 'Mission', '["tag1", "tag2"]'],
[2, 1, 1, 'CA', 1, 'Dogpatch', '["tag1", "tag3"]']
] == response.json['rows']


def test_max_returned_rows(app_client): def test_max_returned_rows(app_client):
response = app_client.get( response = app_client.get(
'/fixtures.json?sql=select+content+from+no_primary_key' '/fixtures.json?sql=select+content+from+no_primary_key'
Expand Down Expand Up @@ -1244,7 +1257,8 @@ def test_expand_labels(app_client):
"value": 1, "value": 1,
"label": "San Francisco" "label": "San Francisco"
}, },
"neighborhood": "Dogpatch" "neighborhood": "Dogpatch",
"tags": '["tag1", "tag3"]'
}, },
"13": { "13": {
"pk": 13, "pk": 13,
Expand All @@ -1255,7 +1269,8 @@ def test_expand_labels(app_client):
"value": 3, "value": 3,
"label": "Detroit" "label": "Detroit"
}, },
"neighborhood": "Corktown" "neighborhood": "Corktown",
"tags": '[]',
} }
} == response.json } == response.json


Expand Down
32 changes: 16 additions & 16 deletions tests/test_csv.py
Original file line number Original file line Diff line number Diff line change
Expand Up @@ -17,22 +17,22 @@
'''.replace('\n', '\r\n') '''.replace('\n', '\r\n')


EXPECTED_TABLE_WITH_LABELS_CSV = ''' EXPECTED_TABLE_WITH_LABELS_CSV = '''
pk,planet_int,on_earth,state,city_id,city_id_label,neighborhood pk,planet_int,on_earth,state,city_id,city_id_label,neighborhood,tags
1,1,1,CA,1,San Francisco,Mission 1,1,1,CA,1,San Francisco,Mission,"[""tag1"", ""tag2""]"
2,1,1,CA,1,San Francisco,Dogpatch 2,1,1,CA,1,San Francisco,Dogpatch,"[""tag1"", ""tag3""]"
3,1,1,CA,1,San Francisco,SOMA 3,1,1,CA,1,San Francisco,SOMA,[]
4,1,1,CA,1,San Francisco,Tenderloin 4,1,1,CA,1,San Francisco,Tenderloin,[]
5,1,1,CA,1,San Francisco,Bernal Heights 5,1,1,CA,1,San Francisco,Bernal Heights,[]
6,1,1,CA,1,San Francisco,Hayes Valley 6,1,1,CA,1,San Francisco,Hayes Valley,[]
7,1,1,CA,2,Los Angeles,Hollywood 7,1,1,CA,2,Los Angeles,Hollywood,[]
8,1,1,CA,2,Los Angeles,Downtown 8,1,1,CA,2,Los Angeles,Downtown,[]
9,1,1,CA,2,Los Angeles,Los Feliz 9,1,1,CA,2,Los Angeles,Los Feliz,[]
10,1,1,CA,2,Los Angeles,Koreatown 10,1,1,CA,2,Los Angeles,Koreatown,[]
11,1,1,MI,3,Detroit,Downtown 11,1,1,MI,3,Detroit,Downtown,[]
12,1,1,MI,3,Detroit,Greektown 12,1,1,MI,3,Detroit,Greektown,[]
13,1,1,MI,3,Detroit,Corktown 13,1,1,MI,3,Detroit,Corktown,[]
14,1,1,MI,3,Detroit,Mexicantown 14,1,1,MI,3,Detroit,Mexicantown,[]
15,2,0,MC,4,Memnonia,Arcadia Planitia 15,2,0,MC,4,Memnonia,Arcadia Planitia,[]
'''.lstrip().replace('\n', '\r\n') '''.lstrip().replace('\n', '\r\n')




Expand Down
2 changes: 1 addition & 1 deletion tests/test_utils.py
Original file line number Original file line Diff line number Diff line change
Expand Up @@ -187,7 +187,7 @@ def test_custom_json_encoder(obj, expected):
]) ])
def test_build_where(args, expected_where, expected_params): def test_build_where(args, expected_where, expected_params):
f = utils.Filters(sorted(args.items())) f = utils.Filters(sorted(args.items()))
sql_bits, actual_params = f.build_where_clauses() sql_bits, actual_params = f.build_where_clauses("table")
assert expected_where == sql_bits assert expected_where == sql_bits
assert { assert {
'p{}'.format(i): param 'p{}'.format(i): param
Expand Down

0 comments on commit 78e45ea

Please sign in to comment.