From 3683a6b626b2e79f4dc9600d45853ca4ae8de11a Mon Sep 17 00:00:00 2001 From: Simon Willison Date: Wed, 20 Jun 2018 21:54:36 -0700 Subject: [PATCH] Docs + example of canned SQL query using || concatenation Closes #321 --- docs/sql_queries.rst | 36 +++++++++++++++++++++++++++++++++--- tests/fixtures.py | 9 ++++++++- tests/test_api.py | 14 ++++++++++++++ 3 files changed, 55 insertions(+), 4 deletions(-) diff --git a/docs/sql_queries.rst b/docs/sql_queries.rst index cfff8136..80d74574 100644 --- a/docs/sql_queries.rst +++ b/docs/sql_queries.rst @@ -23,7 +23,9 @@ Named parameters ---------------- Datasette has special support for SQLite named parameters. Consider a SQL query -like this:: +like this: + +.. code-block:: sql select * from Street_Tree_List where "PermitNotes" like :notes @@ -93,7 +95,33 @@ For the above example, that URL would be:: Canned queries support named parameters, so if you include those in the SQL you will then be able to enter them using the form fields on the canned query page or by adding them to the URL. This means canned queries can be used to create -custom JSON APIs based on a carefully designed SQL. +custom JSON APIs based on a carefully designed SQL statement. + +Here's an example of a canned query with a named parameter: + +.. code-block:: sql + + select neighborhood, facet_cities.name, state + from facetable join facet_cities on facetable.city_id = facet_cities.id + where neighborhood like '%' || :text || '%' order by neighborhood; + +In the canned query JSON it looks like this:: + + { + "databases": { + "fixtures": { + "queries": { + "neighborhood_search": "select neighborhood, facet_cities.name, state\nfrom facetable join facet_cities on facetable.city_id = facet_cities.id\nwhere neighborhood like '%' || :text || '%' order by neighborhood;" + } + } + } + } + +You can try this canned query out here: +https://latest.datasette.io/fixtures/neighborhood_search?text=town + +Note that we are using SQLite string concatenation here - the ``||`` operator - +to add wildcard ``%`` characters to the string provided by the user. .. _pagination: @@ -107,7 +135,9 @@ scan through every preceding row to find the correct offset. When paginating through tables, Datasette instead orders the rows in the table by their primary key and performs a WHERE clause against the last seen primary -key for the previous page. For example:: +key for the previous page. For example: + +.. code-block:: sql select rowid, * from Tree_List where rowid > 200 order by rowid limit 101 diff --git a/tests/fixtures.py b/tests/fixtures.py index 600e4aad..db57b140 100644 --- a/tests/fixtures.py +++ b/tests/fixtures.py @@ -143,7 +143,14 @@ METADATA = { }, }, 'queries': { - 'pragma_cache_size': 'PRAGMA cache_size;' + 'pragma_cache_size': 'PRAGMA cache_size;', + 'neighborhood_search': ''' + select neighborhood, facet_cities.name, state + from facetable + join facet_cities on facetable.city_id = facet_cities.id + where neighborhood like '%' || :text || '%' + order by neighborhood; + ''' } }, } diff --git a/tests/test_api.py b/tests/test_api.py index eb6175a8..2d6170d4 100644 --- a/tests/test_api.py +++ b/tests/test_api.py @@ -330,6 +330,20 @@ def test_custom_sql(app_client): assert not data['truncated'] +def test_canned_query_with_named_parameter(app_client): + response = app_client.get( + "/fixtures/neighborhood_search.json?text=town" + ) + assert [ + ["Corktown", "Detroit", "MI"], + ["Downtown", "Los Angeles", "CA"], + ["Downtown", "Detroit", "MI"], + ["Greektown", "Detroit", "MI"], + ["Koreatown", "Los Angeles", "CA"], + ["Mexicantown", "Detroit", "MI"], + ] == response.json["rows"] + + def test_sql_time_limit(app_client_shorter_time_limit): response = app_client_shorter_time_limit.get( '/fixtures.json?sql=select+sleep(0.5)'