Table functions¶
A table function returns a set of rows for each input row. The returned set can contain zero, one, or more rows. Each row can contain one or more columns.
Table functions are sometimes called “tabular functions”.
What are table functions?¶
Table functions are typically used when a function returns multiple rows for each individual input.
Each time that a table function is called, it can return a different number of rows. For example, a function
record_high_temperatures_for_date()
, which returns a list of record high temperatures for a specified date, might
return 0 rows on April 10, 1 row on June 10, and 40 rows on August 20.
Simple examples of table functions¶
The following are appropriate as table functions:
A function that accepts an account number and a date, and returns all charges billed to that account on that date. (More than one charge might have been billed on a particular date.)
A function that accepts a user ID and returns the database roles assigned to that user. (A user might have multiple roles, including “sysadmin” and “useradmin”.)
Functions in which each output row depends upon multiple input rows¶
Table functions can be grouped into two categories based on the number of input rows that affect each output row:
1-to-N
M-to-N
The functions described earlier are 1-to-N table functions: each output row depends upon only one input row. For example, a
function record_high_temperatures_for_date()
might produce multiple output rows (one for each city that hit a record on
that date). Each output row for a specific input date depends only on that date; each output row is independent of the rows for
every other date.
Snowflake also supports M-to-N table functions: each output row can depend upon multiple input rows. For example, if a function generates a moving average of stock prices, that function uses stock prices from multiple input rows (multiple dates) to generate each output row.
More generally, in an M-to-N function, a group of M input rows produces a group of N output rows. M can be one or more rows. N can be zero, one, or more rows.
For example, in a 10-day moving average, M is 10. N is 1 because each group of 10 input rows produces one average price.
Built-in table functions vs user-defined table functions¶
Snowflake provides hundreds of built-in functions, many of which are table functions. Built-in table functions are listed in System-Defined Table Functions.
Users can also write their own functions, called user-defined functions or “UDFs”. Some UDFs are scalar; some are tabular. User-defined table functions are called “UDTFs”. For information about UDFs (including UDTFs), refer to User-defined functions overview.
Built-in table functions and user-defined table functions generally follow the same rules; for example, they are called the same way from SQL statements.
Using a table function¶
Using a table function in the FROM clause¶
A table contains a set of rows. Similarly, a table function returns a set of rows. Both tables and table functions are used in contexts that expect a set of rows. Specifically, table functions are used in the FROM clause of a SQL statement.
To help the SQL compiler recognize a table function as a source of rows, Snowflake requires that the table function call be
wrapped by the TABLE()
keyword.
For example, the following statement calls a table function named record_high_temperatures_for_date()
, which takes a DATE
value as an argument:
SELECT city_name, temperature FROM TABLE(record_high_temperatures_for_date('2021-06-27'::DATE)) ORDER BY city_name;
For more information about the syntax of TABLE()
, refer to Table literals.
Table functions, like functions in general, can accept zero, one, or multiple input arguments in each invocation. Each argument must be a scalar expression.
For more details about the syntax of table function calls, refer to Syntax (in this topic).
Using a table as input to a table function¶
The argument to a table function can be a literal or an expression, such as a column of a table. For example, the SELECT statement below passes values from a table as arguments to a table function:
CREATE OR REPLACE table dates_of_interest (event_date DATE);
INSERT INTO dates_of_interest (event_date) VALUES
('2021-06-21'::DATE),
('2022-06-21'::DATE);
CREATE OR REPLACE FUNCTION record_high_temperatures_for_date(d DATE)
RETURNS TABLE (event_date DATE, city VARCHAR, temperature NUMBER)
as
$$
SELECT d, 'New York', 65.0
UNION ALL
SELECT d, 'Los Angeles', 69.0
$$;
SELECT
doi.event_date as "Date",
record_temperatures.city,
record_temperatures.temperature
FROM dates_of_interest AS doi,
TABLE(record_high_temperatures_for_date(doi.event_date)) AS record_temperatures
ORDER BY doi.event_date, city;
+------------+-------------+-------------+
| Date | CITY | TEMPERATURE |
|------------+-------------+-------------|
| 2021-06-21 | Los Angeles | 69 |
| 2021-06-21 | New York | 65 |
| 2022-06-21 | Los Angeles | 69 |
| 2022-06-21 | New York | 65 |
+------------+-------------+-------------+
The arguments to a table function can come from other table-like sources, including views and other table functions.
List of system-defined table functions¶
Snowflake provides the following system-defined (i.e. built-in) table functions:
Sub-category |
Function |
Notes |
---|---|---|
Data Loading |
For more information, refer to Load data into Snowflake. |
|
Data Generation |
||
Data Conversion |
||
Differential Privacy |
||
Object Modeling |
||
Parameterized Queries |
||
Semi-structured Queries |
For more information, refer to Querying Semi-structured Data. |
|
Query Results |
Can be used to perform SQL operations on the output from another SQL operation (e.g. SHOW). |
|
Query Profile |
||
Historical & Usage Information |
Includes: |
|
User Login
|
||
Queries
|
||
For more information, refer to Using the Query Acceleration Service. |
||
Warehouse & Storage Usage
|
||
Column-level & Row-level Security
|
||
Object Tagging
|
Information Schema table function. |
|
Information Schema table function. |
||
Account Usage table function. |
||
Account Replication
|
For more information, refer to Introduction to replication and failover across multiple accounts |
|
REPLICATION_GROUP_REFRESH_PROGRESS, REPLICATION_GROUP_REFRESH_PROGRESS_BY_JOB |
||
Alerts
|
For more information, refer to Setting up alerts based on data in Snowflake. |
|
Database Replication
|
For more information, refer to Replicating databases across multiple accounts. |
|
DATABASE_REFRESH_PROGRESS , DATABASE_REFRESH_PROGRESS_BY_JOB |
||
Data Loading & Transfer
|
||
Data Clustering (within Tables)
|
For more information, refer to Automatic Clustering. |
|
Dynamic Tables
|
For more information, refer to Working with dynamic tables. |
|
External Functions
|
For more information, refer to Writing external functions. |
|
External Tables
|
For more information, refer to Working with external tables. |
|
Listings
|
||
Materialized Views Maintenance
|
For more information, refer to Working with Materialized Views. |
|
Notifications
|
For more information, refer to Using SYSTEM$SEND_EMAIL to send email notifications. |
|
SCIM Maintenance
|
For more information, refer to Auditing SCIM API requests |
|
Search Optimization Maintenance
|
For more information, refer to Search Optimization Service. |
|
Streams
|
For more information, refer to Introduction to Streams. |
|
Tasks
|
For more information, refer to Introduction to tasks. |
|
Network rules |
Information Schema table function. For details, see Network rules. |
|
Data Quality Monitoring |
For more information, see Introduction to Data Quality and data metric functions. |
|
Data Lineage |
For more information, refer to Data Lineage in Snowsight. |
|
Cortex Search |
For more information, refer to Cortex Search. |
Syntax¶
SELECT ...
FROM [ <input_table> [ [AS] <alias_1> ] ,
[ LATERAL ]
]
TABLE( <table_function>( [ <arg_1> [, ... ] ] ) ) [ [ AS ] <alias_2> ];
For function-specific syntax, refer to the documentation for the individual system-defined table functions.
Usage notes¶
Table functions can also be applied to a set of rows using the LATERAL construct.
To enable using table expressions, Snowflake supports ANSI/ISO standard syntax for table expressions in the FROM clause of queries and subqueries. This syntax is used to indicate that an expression returns a collection of rows instead of a single row.
This ANSI/ISO syntax is valid only in the FROM clause of the SELECT list. You cannot omit these keywords and parentheses from a collection subquery specification in any other context.