From ccf2191f8c38b2213bffea74abc6b1c31d79ce71 Mon Sep 17 00:00:00 2001 From: kasiafi <30203062+kasiafi@users.noreply.github.com> Date: Fri, 29 Mar 2024 14:06:09 +0100 Subject: [PATCH] Document HTTP functions --- .../Functions-and-operators/http.md | 130 ++++++++++++++++++ .../Functions-and-operators/index.md | 1 + .../Functions-and-operators/list-by-topic.md | 7 + .../Functions-and-operators/list.md | 2 + 4 files changed, 140 insertions(+) create mode 100644 docs/query/DuneSQL-reference/Functions-and-operators/http.md diff --git a/docs/query/DuneSQL-reference/Functions-and-operators/http.md b/docs/query/DuneSQL-reference/Functions-and-operators/http.md new file mode 100644 index 00000000..086dcd78 --- /dev/null +++ b/docs/query/DuneSQL-reference/Functions-and-operators/http.md @@ -0,0 +1,130 @@ +--- +title: HTTP functions +--- + +The HTTP functions send HTTP requests to a specified URL. +Using the HTTP functions, you can interact with HTTP servers directly in SQL queries. +They allow to fetch data from external APIs, as well as invoke remote procedure calls. + + +### Functions + +#### http_get() +**``http_get(url: varchar)``** → varchar + +**``http_get(url: varchar, headers: array(varchar))``** → varchar + +The function sends an HTTP GET request to the given URL, optionally including the provided headers, +and returns the response body as `varchar`. + +Often, the response is a JSON document. You can process it further with [JSON-processing SQL functions](json.md). +Other response formats, like html, are also supported. + +#### http_post() +**``http_post(url: varchar, body: varchar)``** → varchar + +**``http_post(url: varchar, body: varchar, headers: array(varchar))``** → varchar + +The function sends an HTTP POST request to the given URL, including the provided data in the request body, +and optionally including the headers. It returns the response body as `varchar`. + +The type of the body argument is `varchar`. It gives you flexibility to send JSON data as well as text. + + +### Access + +The HTTP functions are currently in closed Beta. They are available to a group of individual users +and teams approved by Dune. Soon they will be Generally Available free of charge to all Dune paying customers. + + +### API support and credentials + +There are no limits to the supported APIs. The URL can point to any public or private API. + +If you need to pass credentials for the API, you can include them in the headers. +For example, you can use the `Authorization` header to pass a token. +If you choose to hardcode the credentials in the query, please make sure to keep the query private. +Optionally, you can use a query parameter as a placeholder: + +```sql +SELECT http_get( + 'https://api.blastscan.io/api?module=block&action=getblocknobytime×tamp=1711712564&closest=before&apikey={{api_key}}' +); +``` + +### Limits + +***Call timeout:*** A call issued by an HTTP function times out after 5 seconds. + +***Throttling:*** Requests from each query execution are limited to ten requests per second per proxy. +There are currently 3 proxies configured per clusterset. The rate limit is shared between all HTTP function calls +made within the query. + +***Response size limit:*** Maximum accepted response body size is 1_000_000 bytes. + +***Data size limit:*** Maximum accepted request body size for `http_post()` is 1_000_000 bytes. + + +### Examples + +#### Single HTTP GET request to list coins from CoinGecko + +```sql +SELECT http_get('https://api.coingecko.com/api/v3/coins/list'); +``` + +#### Multiple HTTP GET requests parametrized with Dune data + +```sql +SELECT + http_get(concat('https://coins.llama.fi/prices/current/ethereum:', CAST(contract_address AS varchar))) +FROM tokens_ethereum.stablecoins; +``` + +#### JSON processing with http_get() + +```sql +SELECT + contract_address, + json_query( + http_get(concat('https://coins.llama.fi/prices/current/ethereum:', CAST(contract_address AS varchar))), + 'lax $.coins.*?(@.decimals==18).keyvalue()?(@.name=="symbol" || @.name=="price" || @.name=="decimals").value' + WITH ARRAY WRAPPER + EMPTY ARRAY ON EMPTY +) as coin_data +FROM tokens_ethereum.stablecoins; +``` + +#### Using http_get() in a subquery as a static filter +By wrapping the `http_get()` function in a subquery, you can use it as a static filter in the main query. +It helps to avoid repeating the same HTTP request multiple times. + +```sql +SELECT * +FROM + ethereum.transactions t1, + (SELECT from_hex(json_extract_scalar(http_get('https://api.ensideas.com/ens/resolve/vitalik.eth'),'$.address'))) t2(x) +WHERE t1."from" = t2.x; +``` + +#### RPC call with http_post() + +```sql +SELECT http_post( + 'https://docs-demo.quiknode.pro', + '{"method":"eth_chainId","params":[],"id":1,"jsonrpc":"2.0"}', + ARRAY['Content-Type: application/json']); +``` + +#### Handling quotation marks +If your payload contains the `'` character, you need to quote it properly because it is the bounding character of `varchar`. +Each `'` character should be doubled, and the query engine will unwrap them. + +```sql +SELECT json_value( + http_post( + 'https://httpbin.org/post', + 'foo', + ARRAY['MyHeader : Use two '' quotes']), + 'lax $.headers.Myheader'); +``` diff --git a/docs/query/DuneSQL-reference/Functions-and-operators/index.md b/docs/query/DuneSQL-reference/Functions-and-operators/index.md index 878d329e..5cf2a4d9 100644 --- a/docs/query/DuneSQL-reference/Functions-and-operators/index.md +++ b/docs/query/DuneSQL-reference/Functions-and-operators/index.md @@ -12,6 +12,7 @@ Using ``SHOW FUNCTIONS`` in the query editor returns a list of all available fun - [Varbinary datatypes](varbinary.md) - [Base58](base58.md) - [Chain Utility Functions](chain-utility-functions.md) +- [HTTP Functions](http.md) - [Varchar Utility Functions](varchar-utility-functions.md) ### Trino Base Functions: - [Aggregate](aggregate.md) diff --git a/docs/query/DuneSQL-reference/Functions-and-operators/list-by-topic.md b/docs/query/DuneSQL-reference/Functions-and-operators/list-by-topic.md index a6862ae8..9819aa97 100644 --- a/docs/query/DuneSQL-reference/Functions-and-operators/list-by-topic.md +++ b/docs/query/DuneSQL-reference/Functions-and-operators/list-by-topic.md @@ -289,6 +289,13 @@ For more details, see `geospatial`{.interpreted-text role="doc"} - `to_geometry`{.interpreted-text role="func"} - `to_spherical_geography`{.interpreted-text role="func"} +# HTTP + +For more details, see `http`{.interpreted-text role="doc"} + +- `http_get`{.interpreted-text role="func"} +- `http_post`{.interpreted-text role="func"} + # HyperLogLog For more details, see `hyperloglog`{.interpreted-text role="doc"} diff --git a/docs/query/DuneSQL-reference/Functions-and-operators/list.md b/docs/query/DuneSQL-reference/Functions-and-operators/list.md index 3835cf45..8b9ff26a 100644 --- a/docs/query/DuneSQL-reference/Functions-and-operators/list.md +++ b/docs/query/DuneSQL-reference/Functions-and-operators/list.md @@ -211,6 +211,8 @@ title: List of functions and operators - `hmac_sha256`{.interpreted-text role="func"} - `hmac_sha512`{.interpreted-text role="func"} - `hour`{.interpreted-text role="func"} +- `http_get`{.interpreted-text role="func"} +- `http_post`{.interpreted-text role="func"} - `human_readable_seconds`{.interpreted-text role="func"} # I