kopia lustrzana https://github.com/simonw/datasette
Added ?_through= table argument, closes #355
Also added much more interesting many-to-many fixtures - roadside attractions!pull/497/head
rodzic
c902590ada
commit
172da009d8
|
|
@ -1,5 +1,6 @@
|
|||
import urllib
|
||||
import itertools
|
||||
import json
|
||||
|
||||
import jinja2
|
||||
from sanic.exceptions import NotFound
|
||||
|
|
@ -17,6 +18,7 @@ from datasette.utils import (
|
|||
escape_sqlite,
|
||||
filters_should_redirect,
|
||||
get_all_foreign_keys,
|
||||
get_outbound_foreign_keys,
|
||||
is_url,
|
||||
path_from_row_pks,
|
||||
path_with_added_args,
|
||||
|
|
@ -289,6 +291,41 @@ class TableView(RowTableShared):
|
|||
for text in request.args["_where"]
|
||||
]
|
||||
|
||||
# Support for ?_through={table, column, value}
|
||||
extra_human_descriptions = []
|
||||
if "_through" in request.args:
|
||||
for through in request.args["_through"]:
|
||||
through_data = json.loads(through)
|
||||
through_table = through_data["table"]
|
||||
other_column = through_data["column"]
|
||||
value = through_data["value"]
|
||||
outgoing_foreign_keys = await self.ds.execute_against_connection_in_thread(
|
||||
database,
|
||||
lambda conn: get_outbound_foreign_keys(conn, through_table),
|
||||
)
|
||||
try:
|
||||
fk_to_us = [
|
||||
fk for fk in outgoing_foreign_keys if fk["other_table"] == table
|
||||
][0]
|
||||
except IndexError:
|
||||
raise DatasetteError(
|
||||
"Invalid _through - could not find corresponding foreign key"
|
||||
)
|
||||
param = "p{}".format(len(params))
|
||||
where_clauses.append(
|
||||
"{our_pk} in (select {our_column} from {through_table} where {other_column} = :{param})".format(
|
||||
through_table=escape_sqlite(through_table),
|
||||
our_pk=escape_sqlite(fk_to_us["other_column"]),
|
||||
our_column=escape_sqlite(fk_to_us["column"]),
|
||||
other_column=escape_sqlite(other_column),
|
||||
param=param,
|
||||
)
|
||||
)
|
||||
params[param] = value
|
||||
extra_human_descriptions.append(
|
||||
'{}.{} = "{}"'.format(through_table, other_column, value)
|
||||
)
|
||||
|
||||
# _search support:
|
||||
fts_table = special_args.get("_fts_table")
|
||||
fts_table = fts_table or table_metadata.get("fts_table")
|
||||
|
|
@ -299,7 +336,6 @@ class TableView(RowTableShared):
|
|||
search_args = dict(
|
||||
pair for pair in special_args.items() if pair[0].startswith("_search")
|
||||
)
|
||||
search_descriptions = []
|
||||
search = ""
|
||||
if fts_table and search_args:
|
||||
if "_search" in search_args:
|
||||
|
|
@ -310,7 +346,7 @@ class TableView(RowTableShared):
|
|||
fts_table=escape_sqlite(fts_table), fts_pk=escape_sqlite(fts_pk)
|
||||
)
|
||||
)
|
||||
search_descriptions.append('search matches "{}"'.format(search))
|
||||
extra_human_descriptions.append('search matches "{}"'.format(search))
|
||||
params["search"] = search
|
||||
else:
|
||||
# More complex: search against specific columns
|
||||
|
|
@ -328,7 +364,7 @@ class TableView(RowTableShared):
|
|||
i=i,
|
||||
)
|
||||
)
|
||||
search_descriptions.append(
|
||||
extra_human_descriptions.append(
|
||||
'search column "{}" matches "{}"'.format(
|
||||
search_col, search_text
|
||||
)
|
||||
|
|
@ -637,7 +673,9 @@ class TableView(RowTableShared):
|
|||
suggested_facets.extend(await facet.suggest())
|
||||
|
||||
# human_description_en combines filters AND search, if provided
|
||||
human_description_en = filters.human_description_en(extra=search_descriptions)
|
||||
human_description_en = filters.human_description_en(
|
||||
extra=extra_human_descriptions
|
||||
)
|
||||
|
||||
if sort or sort_desc:
|
||||
sorted_by = "sorted by {}{}".format(
|
||||
|
|
|
|||
|
|
@ -293,6 +293,32 @@ Special table arguments
|
|||
* `facetable?_where=neighborhood like "%c%"&_where=city_id=3 <https://latest.datasette.io/fixtures/facetable?_where=neighborhood%20like%20%22%c%%22&_where=city_id=3>`__
|
||||
* `facetable?_where=city_id in (select id from facet_cities where name != "Detroit") <https://latest.datasette.io/fixtures/facetable?_where=city_id%20in%20(select%20id%20from%20facet_cities%20where%20name%20!=%20%22Detroit%22)>`__
|
||||
|
||||
``?_through={json}``
|
||||
This can be used to filter rows via a join against another table.
|
||||
|
||||
The JSON parameter must include three keys: ``table``, ``column`` and ``value``.
|
||||
|
||||
``table`` must be a table that the current table is related to via a foreign key relationship.
|
||||
|
||||
``column`` must be a column in that other table.
|
||||
|
||||
``value`` is the value that you want to match against.
|
||||
|
||||
For example, to filter ``roadside_attractions`` to just show the attractions that have a characteristic of "museum", you would construct this JSON::
|
||||
|
||||
{
|
||||
"table": "roadside_attraction_characteristics",
|
||||
"column": "characteristic_id",
|
||||
"value": "1"
|
||||
}
|
||||
|
||||
As a URL, that looks like this:
|
||||
|
||||
``?_through={%22table%22:%22roadside_attraction_characteristics%22,%22column%22:%22characteristic_id%22,%22value%22:%221%22}``
|
||||
|
||||
Here's `an example <https://latest.datasette.io/fixtures/roadside_attractions?_through={%22table%22:%22roadside_attraction_characteristics%22,%22column%22:%22characteristic_id%22,%22value%22:%221%22}>`__.
|
||||
|
||||
|
||||
``?_group_count=COLUMN``
|
||||
Executes a SQL query that returns a count of the number of rows matching
|
||||
each unique value in that column, with the most common ordered first.
|
||||
|
|
|
|||
|
|
@ -551,6 +551,63 @@ CREATE TABLE binary_data (
|
|||
data BLOB
|
||||
);
|
||||
|
||||
-- Many 2 Many demo: roadside attractions!
|
||||
|
||||
CREATE TABLE roadside_attractions (
|
||||
pk integer primary key,
|
||||
name text,
|
||||
address text,
|
||||
latitude real,
|
||||
longitude real
|
||||
);
|
||||
INSERT INTO roadside_attractions VALUES (
|
||||
1, "The Mystery Spot", "465 Mystery Spot Road, Santa Cruz, CA 95065",
|
||||
37.0167, -122.0024
|
||||
);
|
||||
INSERT INTO roadside_attractions VALUES (
|
||||
2, "Winchester Mystery House", "525 South Winchester Boulevard, San Jose, CA 95128",
|
||||
37.3184, -121.9511
|
||||
);
|
||||
INSERT INTO roadside_attractions VALUES (
|
||||
3, "Burlingame Museum of PEZ Memorabilia", "214 California Drive, Burlingame, CA 94010",
|
||||
37.5793, -122.3442
|
||||
);
|
||||
INSERT INTO roadside_attractions VALUES (
|
||||
4, "Bigfoot Discovery Museum", "5497 Highway 9, Felton, CA 95018",
|
||||
37.0414, -122.0725
|
||||
);
|
||||
|
||||
CREATE TABLE attraction_characteristic (
|
||||
pk integer primary key,
|
||||
name text
|
||||
);
|
||||
INSERT INTO attraction_characteristic VALUES (
|
||||
1, "Museum"
|
||||
);
|
||||
INSERT INTO attraction_characteristic VALUES (
|
||||
2, "Paranormal"
|
||||
);
|
||||
|
||||
CREATE TABLE roadside_attraction_characteristics (
|
||||
attraction_id INTEGER REFERENCES roadside_attractions(pk),
|
||||
characteristic_id INTEGER REFERENCES attraction_characteristic(pk)
|
||||
);
|
||||
INSERT INTO roadside_attraction_characteristics VALUES (
|
||||
1, 2
|
||||
);
|
||||
INSERT INTO roadside_attraction_characteristics VALUES (
|
||||
2, 2
|
||||
);
|
||||
INSERT INTO roadside_attraction_characteristics VALUES (
|
||||
4, 2
|
||||
);
|
||||
INSERT INTO roadside_attraction_characteristics VALUES (
|
||||
3, 1
|
||||
);
|
||||
INSERT INTO roadside_attraction_characteristics VALUES (
|
||||
4, 1
|
||||
);
|
||||
|
||||
INSERT INTO simple_primary_key VALUES (1, 'hello');
|
||||
INSERT INTO simple_primary_key VALUES (2, 'world');
|
||||
INSERT INTO simple_primary_key VALUES (3, '');
|
||||
|
|
|
|||
|
|
@ -25,7 +25,7 @@ def test_homepage(app_client):
|
|||
assert response.json.keys() == {"fixtures": 0}.keys()
|
||||
d = response.json["fixtures"]
|
||||
assert d["name"] == "fixtures"
|
||||
assert d["tables_count"] == 21
|
||||
assert d["tables_count"] == 24
|
||||
assert len(d["tables_and_views_truncated"]) == 5
|
||||
assert d["tables_and_views_more"] is True
|
||||
# 4 hidden FTS tables + no_primary_key (hidden in metadata)
|
||||
|
|
@ -44,9 +44,9 @@ def test_homepage_sort_by_relationships(app_client):
|
|||
assert [
|
||||
"simple_primary_key",
|
||||
"complex_foreign_keys",
|
||||
"roadside_attraction_characteristics",
|
||||
"searchable_tags",
|
||||
"foreign_key_references",
|
||||
"facetable",
|
||||
] == tables
|
||||
|
||||
|
||||
|
|
@ -56,115 +56,134 @@ def test_database_page(app_client):
|
|||
assert "fixtures" == data["database"]
|
||||
assert [
|
||||
{
|
||||
"columns": ["content"],
|
||||
"name": "123_starts_with_digits",
|
||||
"columns": ["content"],
|
||||
"primary_keys": [],
|
||||
"count": 0,
|
||||
"hidden": False,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
"fts_table": None,
|
||||
"primary_keys": [],
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
},
|
||||
{
|
||||
"columns": ["pk", "content"],
|
||||
"name": "Table With Space In Name",
|
||||
"columns": ["pk", "content"],
|
||||
"primary_keys": ["pk"],
|
||||
"count": 0,
|
||||
"hidden": False,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
"fts_table": None,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
},
|
||||
{
|
||||
"name": "attraction_characteristic",
|
||||
"columns": ["pk", "name"],
|
||||
"primary_keys": ["pk"],
|
||||
},
|
||||
{
|
||||
"columns": ["data"],
|
||||
"count": 1,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
"fts_table": None,
|
||||
"hidden": False,
|
||||
"name": "binary_data",
|
||||
"primary_keys": [],
|
||||
},
|
||||
{
|
||||
"columns": ["pk", "f1", "f2", "f3"],
|
||||
"name": "complex_foreign_keys",
|
||||
"count": 1,
|
||||
"foreign_keys": {
|
||||
"incoming": [],
|
||||
"outgoing": [
|
||||
{
|
||||
"column": "f3",
|
||||
"other_column": "id",
|
||||
"other_table": "simple_primary_key",
|
||||
},
|
||||
{
|
||||
"column": "f2",
|
||||
"other_column": "id",
|
||||
"other_table": "simple_primary_key",
|
||||
},
|
||||
{
|
||||
"column": "f1",
|
||||
"other_column": "id",
|
||||
"other_table": "simple_primary_key",
|
||||
},
|
||||
],
|
||||
},
|
||||
"count": 2,
|
||||
"hidden": False,
|
||||
"fts_table": None,
|
||||
"primary_keys": ["pk"],
|
||||
},
|
||||
{
|
||||
"columns": ["pk1", "pk2", "content"],
|
||||
"name": "compound_primary_key",
|
||||
"count": 1,
|
||||
"hidden": False,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
"fts_table": None,
|
||||
"primary_keys": ["pk1", "pk2"],
|
||||
},
|
||||
{
|
||||
"columns": ["pk1", "pk2", "pk3", "content"],
|
||||
"name": "compound_three_primary_keys",
|
||||
"count": 1001,
|
||||
"hidden": False,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
"fts_table": None,
|
||||
"primary_keys": ["pk1", "pk2", "pk3"],
|
||||
},
|
||||
{
|
||||
"columns": ["pk", "foreign_key_with_custom_label"],
|
||||
"name": "custom_foreign_key_label",
|
||||
"count": 1,
|
||||
"hidden": False,
|
||||
"foreign_keys": {
|
||||
"incoming": [],
|
||||
"outgoing": [
|
||||
{
|
||||
"column": "foreign_key_with_custom_label",
|
||||
"other_column": "id",
|
||||
"other_table": "primary_key_multiple_columns_explicit_label",
|
||||
}
|
||||
],
|
||||
},
|
||||
"fts_table": None,
|
||||
"primary_keys": ["pk"],
|
||||
},
|
||||
{
|
||||
"columns": ["id", "name"],
|
||||
"name": "facet_cities",
|
||||
"count": 4,
|
||||
"foreign_keys": {
|
||||
"incoming": [
|
||||
{
|
||||
"column": "id",
|
||||
"other_column": "city_id",
|
||||
"other_table": "facetable",
|
||||
"other_table": "roadside_attraction_characteristics",
|
||||
"column": "pk",
|
||||
"other_column": "characteristic_id",
|
||||
}
|
||||
],
|
||||
"outgoing": [],
|
||||
},
|
||||
"fts_table": None,
|
||||
"hidden": False,
|
||||
"primary_keys": ["id"],
|
||||
},
|
||||
{
|
||||
"name": "binary_data",
|
||||
"columns": ["data"],
|
||||
"primary_keys": [],
|
||||
"count": 1,
|
||||
"hidden": False,
|
||||
"fts_table": None,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
},
|
||||
{
|
||||
"name": "complex_foreign_keys",
|
||||
"columns": ["pk", "f1", "f2", "f3"],
|
||||
"primary_keys": ["pk"],
|
||||
"count": 1,
|
||||
"hidden": False,
|
||||
"fts_table": None,
|
||||
"foreign_keys": {
|
||||
"incoming": [],
|
||||
"outgoing": [
|
||||
{
|
||||
"other_table": "simple_primary_key",
|
||||
"column": "f3",
|
||||
"other_column": "id",
|
||||
},
|
||||
{
|
||||
"other_table": "simple_primary_key",
|
||||
"column": "f2",
|
||||
"other_column": "id",
|
||||
},
|
||||
{
|
||||
"other_table": "simple_primary_key",
|
||||
"column": "f1",
|
||||
"other_column": "id",
|
||||
},
|
||||
],
|
||||
},
|
||||
},
|
||||
{
|
||||
"name": "compound_primary_key",
|
||||
"columns": ["pk1", "pk2", "content"],
|
||||
"primary_keys": ["pk1", "pk2"],
|
||||
"count": 1,
|
||||
"hidden": False,
|
||||
"fts_table": None,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
},
|
||||
{
|
||||
"name": "compound_three_primary_keys",
|
||||
"columns": ["pk1", "pk2", "pk3", "content"],
|
||||
"primary_keys": ["pk1", "pk2", "pk3"],
|
||||
"count": 1001,
|
||||
"hidden": False,
|
||||
"fts_table": None,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
},
|
||||
{
|
||||
"name": "custom_foreign_key_label",
|
||||
"columns": ["pk", "foreign_key_with_custom_label"],
|
||||
"primary_keys": ["pk"],
|
||||
"count": 1,
|
||||
"hidden": False,
|
||||
"fts_table": None,
|
||||
"foreign_keys": {
|
||||
"incoming": [],
|
||||
"outgoing": [
|
||||
{
|
||||
"other_table": "primary_key_multiple_columns_explicit_label",
|
||||
"column": "foreign_key_with_custom_label",
|
||||
"other_column": "id",
|
||||
}
|
||||
],
|
||||
},
|
||||
},
|
||||
{
|
||||
"name": "facet_cities",
|
||||
"columns": ["id", "name"],
|
||||
"primary_keys": ["id"],
|
||||
"count": 4,
|
||||
"hidden": False,
|
||||
"fts_table": None,
|
||||
"foreign_keys": {
|
||||
"incoming": [
|
||||
{
|
||||
"other_table": "facetable",
|
||||
"column": "id",
|
||||
"other_column": "city_id",
|
||||
}
|
||||
],
|
||||
"outgoing": [],
|
||||
},
|
||||
},
|
||||
{
|
||||
"name": "facetable",
|
||||
"columns": [
|
||||
"pk",
|
||||
"created",
|
||||
|
|
@ -175,94 +194,137 @@ def test_database_page(app_client):
|
|||
"neighborhood",
|
||||
"tags",
|
||||
],
|
||||
"name": "facetable",
|
||||
"primary_keys": ["pk"],
|
||||
"count": 15,
|
||||
"hidden": False,
|
||||
"fts_table": None,
|
||||
"foreign_keys": {
|
||||
"incoming": [],
|
||||
"outgoing": [
|
||||
{
|
||||
"other_table": "facet_cities",
|
||||
"column": "city_id",
|
||||
"other_column": "id",
|
||||
"other_table": "facet_cities",
|
||||
}
|
||||
],
|
||||
},
|
||||
"fts_table": None,
|
||||
"hidden": False,
|
||||
"primary_keys": ["pk"],
|
||||
},
|
||||
{
|
||||
"columns": ["pk", "foreign_key_with_label", "foreign_key_with_no_label"],
|
||||
"name": "foreign_key_references",
|
||||
"columns": ["pk", "foreign_key_with_label", "foreign_key_with_no_label"],
|
||||
"primary_keys": ["pk"],
|
||||
"count": 1,
|
||||
"hidden": False,
|
||||
"fts_table": None,
|
||||
"foreign_keys": {
|
||||
"incoming": [],
|
||||
"outgoing": [
|
||||
{
|
||||
"other_table": "primary_key_multiple_columns",
|
||||
"column": "foreign_key_with_no_label",
|
||||
"other_column": "id",
|
||||
"other_table": "primary_key_multiple_columns",
|
||||
},
|
||||
{
|
||||
"other_table": "simple_primary_key",
|
||||
"column": "foreign_key_with_label",
|
||||
"other_column": "id",
|
||||
"other_table": "simple_primary_key",
|
||||
},
|
||||
],
|
||||
},
|
||||
"fts_table": None,
|
||||
"primary_keys": ["pk"],
|
||||
},
|
||||
{
|
||||
"name": "infinity",
|
||||
"columns": ["value"],
|
||||
"count": 3,
|
||||
"primary_keys": [],
|
||||
"count": 3,
|
||||
"hidden": False,
|
||||
"fts_table": None,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
},
|
||||
{
|
||||
"columns": ["id", "content", "content2"],
|
||||
"name": "primary_key_multiple_columns",
|
||||
"columns": ["id", "content", "content2"],
|
||||
"primary_keys": ["id"],
|
||||
"count": 1,
|
||||
"hidden": False,
|
||||
"fts_table": None,
|
||||
"foreign_keys": {
|
||||
"incoming": [
|
||||
{
|
||||
"other_table": "foreign_key_references",
|
||||
"column": "id",
|
||||
"other_column": "foreign_key_with_no_label",
|
||||
"other_table": "foreign_key_references",
|
||||
}
|
||||
],
|
||||
"outgoing": [],
|
||||
},
|
||||
"hidden": False,
|
||||
"fts_table": None,
|
||||
"primary_keys": ["id"],
|
||||
},
|
||||
{
|
||||
"columns": ["id", "content", "content2"],
|
||||
"name": "primary_key_multiple_columns_explicit_label",
|
||||
"columns": ["id", "content", "content2"],
|
||||
"primary_keys": ["id"],
|
||||
"count": 1,
|
||||
"hidden": False,
|
||||
"fts_table": None,
|
||||
"foreign_keys": {
|
||||
"incoming": [
|
||||
{
|
||||
"other_table": "custom_foreign_key_label",
|
||||
"column": "id",
|
||||
"other_column": "foreign_key_with_custom_label",
|
||||
"other_table": "custom_foreign_key_label",
|
||||
}
|
||||
],
|
||||
"outgoing": [],
|
||||
},
|
||||
"hidden": False,
|
||||
"fts_table": None,
|
||||
"primary_keys": ["id"],
|
||||
},
|
||||
{
|
||||
"columns": ["pk", "text1", "text2", "name with . and spaces"],
|
||||
"name": "roadside_attraction_characteristics",
|
||||
"columns": ["attraction_id", "characteristic_id"],
|
||||
"primary_keys": [],
|
||||
"count": 5,
|
||||
"hidden": False,
|
||||
"fts_table": None,
|
||||
"foreign_keys": {
|
||||
"incoming": [],
|
||||
"outgoing": [
|
||||
{
|
||||
"other_table": "attraction_characteristic",
|
||||
"column": "characteristic_id",
|
||||
"other_column": "pk",
|
||||
},
|
||||
{
|
||||
"other_table": "roadside_attractions",
|
||||
"column": "attraction_id",
|
||||
"other_column": "pk",
|
||||
},
|
||||
],
|
||||
},
|
||||
},
|
||||
{
|
||||
"name": "roadside_attractions",
|
||||
"columns": ["pk", "name", "address", "latitude", "longitude"],
|
||||
"primary_keys": ["pk"],
|
||||
"count": 4,
|
||||
"hidden": False,
|
||||
"fts_table": None,
|
||||
"foreign_keys": {
|
||||
"incoming": [
|
||||
{
|
||||
"other_table": "roadside_attraction_characteristics",
|
||||
"column": "pk",
|
||||
"other_column": "attraction_id",
|
||||
}
|
||||
],
|
||||
"outgoing": [],
|
||||
},
|
||||
},
|
||||
{
|
||||
"name": "searchable",
|
||||
"columns": ["pk", "text1", "text2", "name with . and spaces"],
|
||||
"primary_keys": ["pk"],
|
||||
"count": 2,
|
||||
"hidden": False,
|
||||
"fts_table": "searchable_fts",
|
||||
"foreign_keys": {
|
||||
"incoming": [
|
||||
{
|
||||
|
|
@ -273,9 +335,6 @@ def test_database_page(app_client):
|
|||
],
|
||||
"outgoing": [],
|
||||
},
|
||||
"fts_table": "searchable_fts",
|
||||
"hidden": False,
|
||||
"primary_keys": ["pk"],
|
||||
},
|
||||
{
|
||||
"name": "searchable_tags",
|
||||
|
|
@ -297,48 +356,49 @@ def test_database_page(app_client):
|
|||
},
|
||||
},
|
||||
{
|
||||
"columns": ["group", "having", "and", "json"],
|
||||
"name": "select",
|
||||
"columns": ["group", "having", "and", "json"],
|
||||
"primary_keys": [],
|
||||
"count": 1,
|
||||
"hidden": False,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
"fts_table": None,
|
||||
"primary_keys": [],
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
},
|
||||
{
|
||||
"columns": ["id", "content"],
|
||||
"name": "simple_primary_key",
|
||||
"columns": ["id", "content"],
|
||||
"primary_keys": ["id"],
|
||||
"count": 4,
|
||||
"hidden": False,
|
||||
"fts_table": None,
|
||||
"foreign_keys": {
|
||||
"incoming": [
|
||||
{
|
||||
"other_table": "foreign_key_references",
|
||||
"column": "id",
|
||||
"other_column": "foreign_key_with_label",
|
||||
"other_table": "foreign_key_references",
|
||||
},
|
||||
{
|
||||
"other_table": "complex_foreign_keys",
|
||||
"column": "id",
|
||||
"other_column": "f3",
|
||||
"other_table": "complex_foreign_keys",
|
||||
},
|
||||
{
|
||||
"other_table": "complex_foreign_keys",
|
||||
"column": "id",
|
||||
"other_column": "f2",
|
||||
"other_table": "complex_foreign_keys",
|
||||
},
|
||||
{
|
||||
"other_table": "complex_foreign_keys",
|
||||
"column": "id",
|
||||
"other_column": "f1",
|
||||
"other_table": "complex_foreign_keys",
|
||||
},
|
||||
],
|
||||
"outgoing": [],
|
||||
},
|
||||
"fts_table": None,
|
||||
"primary_keys": ["id"],
|
||||
},
|
||||
{
|
||||
"name": "sortable",
|
||||
"columns": [
|
||||
"pk1",
|
||||
"pk2",
|
||||
|
|
@ -348,21 +408,20 @@ def test_database_page(app_client):
|
|||
"sortable_with_nulls_2",
|
||||
"text",
|
||||
],
|
||||
"name": "sortable",
|
||||
"primary_keys": ["pk1", "pk2"],
|
||||
"count": 201,
|
||||
"hidden": False,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
"fts_table": None,
|
||||
"primary_keys": ["pk1", "pk2"],
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
},
|
||||
{
|
||||
"columns": ["pk", "content"],
|
||||
"name": "table/with/slashes.csv",
|
||||
"columns": ["pk", "content"],
|
||||
"primary_keys": ["pk"],
|
||||
"count": 1,
|
||||
"hidden": False,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
"fts_table": None,
|
||||
"primary_keys": ["pk"],
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
},
|
||||
{
|
||||
"name": "tags",
|
||||
|
|
@ -383,33 +442,34 @@ def test_database_page(app_client):
|
|||
},
|
||||
},
|
||||
{
|
||||
"columns": ["pk", "distance", "frequency"],
|
||||
"name": "units",
|
||||
"columns": ["pk", "distance", "frequency"],
|
||||
"primary_keys": ["pk"],
|
||||
"count": 3,
|
||||
"hidden": False,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
"fts_table": None,
|
||||
"primary_keys": ["pk"],
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
},
|
||||
{
|
||||
"columns": ["content", "a", "b", "c"],
|
||||
"name": "no_primary_key",
|
||||
"columns": ["content", "a", "b", "c"],
|
||||
"primary_keys": [],
|
||||
"count": 201,
|
||||
"hidden": True,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
"fts_table": None,
|
||||
"primary_keys": [],
|
||||
},
|
||||
{
|
||||
"columns": ["text1", "text2", "name with . and spaces", "content"],
|
||||
"count": 2,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
"fts_table": "searchable_fts",
|
||||
"hidden": True,
|
||||
"name": "searchable_fts",
|
||||
"primary_keys": [],
|
||||
},
|
||||
{
|
||||
"name": "searchable_fts",
|
||||
"columns": ["text1", "text2", "name with . and spaces", "content"],
|
||||
"primary_keys": [],
|
||||
"count": 2,
|
||||
"hidden": True,
|
||||
"fts_table": "searchable_fts",
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
},
|
||||
{
|
||||
"name": "searchable_fts_content",
|
||||
"columns": [
|
||||
"docid",
|
||||
"c0text1",
|
||||
|
|
@ -417,14 +477,14 @@ def test_database_page(app_client):
|
|||
"c2name with . and spaces",
|
||||
"c3content",
|
||||
],
|
||||
"count": 2,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
"fts_table": None,
|
||||
"hidden": True,
|
||||
"name": "searchable_fts_content",
|
||||
"primary_keys": ["docid"],
|
||||
"count": 2,
|
||||
"hidden": True,
|
||||
"fts_table": None,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
},
|
||||
{
|
||||
"name": "searchable_fts_segdir",
|
||||
"columns": [
|
||||
"level",
|
||||
"idx",
|
||||
|
|
@ -433,21 +493,20 @@ def test_database_page(app_client):
|
|||
"end_block",
|
||||
"root",
|
||||
],
|
||||
"count": 1,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
"fts_table": None,
|
||||
"hidden": True,
|
||||
"name": "searchable_fts_segdir",
|
||||
"primary_keys": ["level", "idx"],
|
||||
"count": 1,
|
||||
"hidden": True,
|
||||
"fts_table": None,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
},
|
||||
{
|
||||
"columns": ["blockid", "block"],
|
||||
"count": 0,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
"fts_table": None,
|
||||
"hidden": True,
|
||||
"name": "searchable_fts_segments",
|
||||
"columns": ["blockid", "block"],
|
||||
"primary_keys": ["blockid"],
|
||||
"count": 0,
|
||||
"hidden": True,
|
||||
"fts_table": None,
|
||||
"foreign_keys": {"incoming": [], "outgoing": []},
|
||||
},
|
||||
] == data["tables"]
|
||||
|
||||
|
|
@ -981,6 +1040,33 @@ def test_table_filter_extra_where_disabled_if_no_sql_allowed():
|
|||
assert "_where= is not allowed" == response.json["error"]
|
||||
|
||||
|
||||
def test_table_through(app_client):
|
||||
# Just the museums:
|
||||
response = app_client.get(
|
||||
'/fixtures/roadside_attractions.json?_through={"table":"roadside_attraction_characteristics","column":"characteristic_id","value":"1"}'
|
||||
)
|
||||
assert [
|
||||
[
|
||||
3,
|
||||
"Burlingame Museum of PEZ Memorabilia",
|
||||
"214 California Drive, Burlingame, CA 94010",
|
||||
37.5793,
|
||||
-122.3442,
|
||||
],
|
||||
[
|
||||
4,
|
||||
"Bigfoot Discovery Museum",
|
||||
"5497 Highway 9, Felton, CA 95018",
|
||||
37.0414,
|
||||
-122.0725,
|
||||
],
|
||||
] == response.json["rows"]
|
||||
assert (
|
||||
'where roadside_attraction_characteristics.characteristic_id = "1"'
|
||||
== response.json["human_description_en"]
|
||||
)
|
||||
|
||||
|
||||
def test_max_returned_rows(app_client):
|
||||
response = app_client.get("/fixtures.json?sql=select+content+from+no_primary_key")
|
||||
data = response.json
|
||||
|
|
|
|||
Ładowanie…
Reference in New Issue