Running SQL queries

Datasette treats SQLite database files as read-only and immutable. This means it is not possible to execute INSERT or UPDATE statements using Datasette, which allows us to expose SELECT statements to the outside world without needing to worry about SQL injection attacks.

The easiest way to execute custom SQL against Datasette is through the web UI. The database index page includes a SQL editor that lets you run any SELECT query you like. You can also construct queries using the filter interface on the tables page, then click "View and edit SQL" to open that query in the custom SQL editor.

Note that this interface is only available if the execute-sql permission is allowed.

Any Datasette SQL query is reflected in the URL of the page, allowing you to bookmark them, share them with others and navigate through previous queries using your browser back button.

You can also retrieve the results of any query as JSON by adding .json to the base URL.

Named parameters

Datasette has special support for SQLite named parameters. Consider a SQL query like this:

select * from Street_Tree_List
where "PermitNotes" like :notes
and "qSpecies" = :species

If you execute this query using the custom query editor, Datasette will extract the two named parameters and use them to construct form fields for you to provide values.

You can also provide values for these fields by constructing a URL:

/mydatabase?sql=select...&species=44

SQLite string escaping rules will be applied to values passed using named parameters - they will be wrapped in quotes and their content will be correctly escaped.

Datasette disallows custom SQL containing the string PRAGMA, as SQLite pragma statements can be used to change database settings at runtime. If you need to include the string "pragma" in a query you can do so safely using a named parameter.

Views

If you want to bundle some pre-written SQL queries with your Datasette-hosted database you can do so in two ways. The first is to include SQL views in your database - Datasette will then list those views on your database index page.

The easiest way to create views is with the SQLite command-line interface:

$ sqlite3 sf-trees.db
SQLite version 3.19.3 2017-06-27 16:48:08
Enter ".help" for usage hints.
sqlite> CREATE VIEW demo_view AS select qSpecies from Street_Tree_List;
<CTRL+D>

Canned queries

As an alternative to adding views to your database, you can define canned queries inside your metadata.json file. Here's an example:

{
    "databases": {
       "sf-trees": {
           "queries": {
               "just_species": {
                   "sql": "select qSpecies from Street_Tree_List"
               }
           }
       }
    }
}

Then run Datasette like this:

datasette sf-trees.db -m metadata.json

Each canned query will be listed on the database index page, and will also get its own URL at:

/database-name/canned-query-name

For the above example, that URL would be:

/sf-trees/just_species

You can optionally include "title" and "description" keys to show a title and description on the canned query page. As with regular table metadata you can alternatively specify "description_html" to have your description rendered as HTML (rather than having HTML special characters escaped).

Canned query parameters

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 statement.

Here's an example of a canned query with a named parameter:

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 metadata (here Using YAML for metadata as metadata.yaml) it looks like this:

databases:
  fixtures:
    queries:
      neighborhood_search:
        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
        title: Search neighborhoods

Here's the equivalent using JSON (as metadata.json):

{
    "databases": {
        "fixtures": {
            "queries": {
                "neighborhood_search": {
                    "sql": "select neighborhood, facet_cities.name, state\nfrom facetable\n  join facet_cities on facetable.city_id = facet_cities.id\nwhere neighborhood like '%' || :text || '%'\norder by neighborhood",
                    "title": "Search neighborhoods"
                }
            }
        }
    }
}

Note that we are using SQLite string concatenation here - the || operator - to add wildcard % characters to the string provided by the user.

You can try this canned query out here: https://latest.datasette.io/fixtures/neighborhood_search?text=town

In this example the :text named parameter is automatically extracted from the query using a regular expression.

You can alternatively provide an explicit list of named parameters using the "params" key, like this:

databases:
  fixtures:
    queries:
      neighborhood_search:
        params:
        - text
        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
        title: Search neighborhoods

Setting a default fragment

Some plugins, such as datasette-vega, can be configured by including additional data in the fragment hash of the URL - the bit that comes after a # symbol.

You can set a default fragment hash that will be included in the link to the canned query from the database index page using the "fragment" key:

{
    "databases": {
        "fixtures": {
            "queries": {
                "neighborhood_search": {
                    "sql": "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;",
                    "fragment": "fragment-goes-here"
                }
            }
        }
    }
}

See here for a demo of this in action.

Writable canned queries

Canned queries by default are read-only. You can use the "write": true key to indicate that a canned query can write to the database.

See Controlling access to specific canned queries for details on how to add permission checks to canned queries, using the "allow" key.

{
    "databases": {
        "mydatabase": {
            "queries": {
                "add_name": {
                    "sql": "INSERT INTO names (name) VALUES (:name)",
                    "write": true
                }
            }
        }
    }
}

This configuration will create a page at /mydatabase/add_name displaying a form with a name field. Submitting that form will execute the configured INSERT query.

You can customize how Datasette represents success and errors using the following optional properties:

  • on_success_message - the message shown when a query is successful
  • on_success_redirect - the path or URL the user is redirected to on success
  • on_error_message - the message shown when a query throws an error
  • on_error_redirect - the path or URL the user is redirected to on error

For example:

{
    "databases": {
        "mydatabase": {
            "queries": {
                "add_name": {
                    "sql": "INSERT INTO names (name) VALUES (:name)",
                    "write": true,
                    "on_success_message": "Name inserted",
                    "on_success_redirect": "/mydatabase/names",
                    "on_error_message": "Name insert failed",
                    "on_error_redirect": "/mydatabase"
                }
            }
        }
    }
}

You can use "params" to explicitly list the named parameters that should be displayed as form fields - otherwise they will be automatically detected.

You can pre-populate form fields when the page first loads using a querystring, e.g. /mydatabase/add_name?name=Prepopulated. The user will have to submit the form to execute the query.

Magic parameters

Named parameters that start with an underscore are special: they can be used to automatically add values created by Datasette that are not contained in the incoming form fields or querystring.

Available magic parameters are:

_actor_* - e.g. _actor_id, _actor_name
Fields from the currently authenticated Actors.
_header_* - e.g. _header_user_agent
Header from the incoming HTTP request. The key should be in lower case and with hyphens converted to underscores e.g. _header_user_agent or _header_accept_language.
_cookie_* - e.g. _cookie_lang
The value of the incoming cookie of that name.
_now_epoch
The number of seconds since the Unix epoch.
_now_date_utc
The date in UTC, e.g. 2020-06-01
_now_datetime_utc
The ISO 8601 datetime in UTC, e.g. 2020-06-24T18:01:07Z
_random_chars_* - e.g. _random_chars_128
A random string of characters of the specified length.

Here's an example configuration (this time using metadata.yaml since that provides better support for multi-line SQL queries) that adds a message from the authenticated user, storing various pieces of additional metadata using magic parameters:

databases:
  mydatabase:
    queries:
      add_message:
        allow:
          id: "*"
        sql: |-
          INSERT INTO messages (
            user_id, ip, message, datetime
          ) VALUES (
            :_actor_id, :_request_ip, :message, :_now_datetime_utc
          )
        write: true

The form presented at /mydatabase/add_message will have just a field for message - the other parameters will be populated by the magic parameter mechanism.

Additional custom magic parameters can be added by plugins using the register_magic_parameters(datasette) hook.