Categories:

Information Schema , Table functions

QUERY_HISTORY , QUERY_HISTORY_BY_*

The QUERY_HISTORY family of table functions can be used to query Snowflake query history along various dimensions:

  • QUERY_HISTORY returns queries within a specified time range.

  • QUERY_HISTORY_BY_SESSION returns queries within a specified session and time range.

  • QUERY_HISTORY_BY_USER returns queries submitted by a specified user within a specified time range.

  • QUERY_HISTORY_BY_WAREHOUSE returns queries executed by a specified warehouse within a specified time range.

Each function is optimized for querying along the specified dimension. The results can be further filtered using SQL predicates.

See also:

QUERY_HISTORY view (Account Usage) Monitor query activity with Query History (Snowsight dashboard)

Syntax

QUERY_HISTORY(
      [ END_TIME_RANGE_START => <constant_expr> ]
      [, END_TIME_RANGE_END => <constant_expr> ]
      [, RESULT_LIMIT => <num> ] )

QUERY_HISTORY_BY_SESSION(
      [ SESSION_ID => <constant_expr> ]
      [, END_TIME_RANGE_START => <constant_expr> ]
      [, END_TIME_RANGE_END => <constant_expr> ]
      [, RESULT_LIMIT => <num> ] )

QUERY_HISTORY_BY_USER(
      [ USER_NAME => '<string>' ]
      [, END_TIME_RANGE_START => <constant_expr> ]
      [, END_TIME_RANGE_END => <constant_expr> ]
      [, RESULT_LIMIT => <num> ] )

QUERY_HISTORY_BY_WAREHOUSE(
      [ WAREHOUSE_NAME => '<string>' ]
      [, END_TIME_RANGE_START => <constant_expr> ]
      [, END_TIME_RANGE_END => <constant_expr> ]
      [, RESULT_LIMIT => <num> ] )
Copy

Arguments

All the arguments are optional.

END_TIME_RANGE_START => constant_expr , . END_TIME_RANGE_END => constant_expr

Time range (in TIMESTAMP_LTZ format), within the last 7 days, in which the query completed running:

  • If END_TIME_RANGE_END is not specified, the function returns all queries, including those that are still running.

  • If END_TIME_RANGE_END is CURRENT_TIMESTAMP, the function returns only those queries that have completed.

If the time range does not fall within the last 7 days, an error is returned.

Note

If no start or end time is specified, the most recent queries are returned, up to the specified limit.

SESSION_ID => constant_expr

Applies only to QUERY_HISTORY_BY_SESSION

The numeric identifier for a session or CURRENT_SESSION. Only queries from the specified session are returned.

Default: CURRENT_SESSION

USER_NAME => 'string'

Applies only to QUERY_HISTORY_BY_USER

A string specifying a user login name or CURRENT_USER. Only queries run by the specified user are returned. Note that the login name must be enclosed in single quotes. Also, if the login name contains any spaces, mixed-case characters, or special characters, the name must be double-quoted within the single quotes (e.g. '"User 1"' vs 'user1').

Default: CURRENT_USER

WAREHOUSE_NAME => 'string'

Applies only to QUERY_HISTORY_BY_WAREHOUSE

A string specifying a warehouse name or CURRENT_WAREHOUSE. Only queries executed by that warehouse are returned. Note that the warehouse name must be enclosed in single quotes. Also, if the warehouse name contains any spaces, mixed-case characters, or special characters, the name must be double-quoted within the single quotes (e.g. '"My Warehouse"' vs 'mywarehouse').

Default: CURRENT_WAREHOUSE

RESULT_LIMIT => num

A number specifying the maximum number of rows returned by the function:

If the number of matching rows is greater than this limit, the queries with the most recent end time (or those that are still executing) are returned, up to the specified limit.

Range: 1 to 10000

Default: 100.

Usage notes

  • Returns queries run by the current user. Also returns queries run by any user when the executing role, or a higher role in a hierarchy, has the MONITOR or OPERATE privilege on the warehouses where the queries were run. For more information, see Virtual warehouse privileges.

  • When calling an Information Schema table function, the session must have an INFORMATION_SCHEMA schema in use or the function name must be fully-qualified. For more details, see Snowflake Information Schema.

  • The values for the columns EXTERNAL_FUNCTION_TOTAL_INVOCATIONS, EXTERNAL_FUNCTION_TOTAL_SENT_ROWS, EXTERNAL_FUNCTION_TOTAL_RECEIVED_ROWS, EXTERNAL_FUNCTION_TOTAL_SENT_BYTES, and EXTERNAL_FUNCTION_TOTAL_RECEIVED_BYTES are affected by many factors, including:

    • The number of external functions in the SQL statement.

    • The number of rows per batch sent to each remote service.

    • The number of retries due to transient errors (e.g. because a response was not received within the expected time).

Query retry columns

A query might need to be retried one or more times in order to successfully complete. There can be multiple causes that result in a query retry. Some of these causes are actionable, that is, a user can make changes to reduce or eliminate query retries for a specific query. For example, if a query is retried due to an out of memory error, modifying warehouse settings might resolve the issue.

Some query retries are caused by a fault that is not actionable. That is, there is no change a user can make to prevent the query retry. For example, a network outage might result in a query retry. In this case, there is no change to the query or to the warehouse that executes it that can prevent the query retry.

The QUERY_RETRY_TIME, QUERY_RETRY_CAUSE, and FAULT_HANDLING_TIME columns can help you optimize queries that are retried and better understand fluctuations in query performance.

Output

The function returns the following columns:

Column Name

Data Type

Description

QUERY_ID

VARCHAR

The statement’s unique id.

QUERY_TEXT

VARCHAR

Text of the SQL statement.

DATABASE_NAME

VARCHAR

Database that was specified in the context of the query at compilation.

SCHEMA_NAME

VARCHAR

Schema that was specified in the context of the query at compilation.

QUERY_TYPE

VARCHAR

DML, query, etc. If the query is currently running, or the query failed, then the query type may be UNKNOWN.

SESSION_ID

NUMBER

Session that executed the statement.

USER_NAME

VARCHAR

User who issued the query.

ROLE_NAME

VARCHAR

Role that was active in the session at the time of the query.

WAREHOUSE_NAME

VARCHAR

Warehouse that the query executed on, if any.

WAREHOUSE_SIZE

VARCHAR

Size of the warehouse when this statement executed.

WAREHOUSE_TYPE

VARCHAR

Type of the warehouse when this statement executed.

CLUSTER_NUMBER

NUMBER

The cluster (in a multi-cluster warehouse) that this statement executed on.

QUERY_TAG

VARCHAR

Query tag set for this statement through the QUERY_TAG session parameter.

EXECUTION_STATUS

VARCHAR

Execution status for the query: resuming_warehouse, running, queued, blocked, success, failed_with_error, or failed_with_incident.

ERROR_CODE

NUMBER

Error code, if the query returned an error

ERROR_MESSAGE

VARCHAR

Error message, if the query returned an error

START_TIME

TIMESTAMP_LTZ

Statement start time

END_TIME

TIMESTAMP_LTZ

Statement end time. If the query is still running, the END_TIME is the UNIX epoch timestamp (“1970-01-01 00:00:00”), adjusted for the local time zone. E.g. for Pacific Standard Time, this would be “1969-12-31 16:00:00.000 -0800”.

TOTAL_ELAPSED_TIME

NUMBER

Elapsed time (in milliseconds)

BYTES_SCANNED

NUMBER

Number of bytes scanned by this statement.

ROWS_PRODUCED

NUMBER

Number of rows produced by this statement.

COMPILATION_TIME

NUMBER

Compilation time (in milliseconds)

EXECUTION_TIME

NUMBER

Execution time (in milliseconds)

QUEUED_PROVISIONING_TIME

NUMBER

Time (in milliseconds) spent in the warehouse queue, waiting for the warehouse compute resources to provision, due to warehouse creation, resume, or resize.

QUEUED_REPAIR_TIME

NUMBER

Time (in milliseconds) spent in the warehouse queue, waiting for compute resources in the warehouse to be repaired.

QUEUED_OVERLOAD_TIME

NUMBER

Time (in milliseconds) spent in the warehouse queue, due to the warehouse being overloaded by the current query workload.

TRANSACTION_BLOCKED_TIME

NUMBER

Time (in milliseconds) spent blocked by a concurrent DML.

OUTBOUND_DATA_TRANSFER_CLOUD

VARCHAR

Target cloud provider for statements that unload data to another region and/or cloud.

OUTBOUND_DATA_TRANSFER_REGION

VARCHAR

Target region for statements that unload data to another region and/or cloud.

OUTBOUND_DATA_TRANSFER_BYTES

NUMBER

Number of bytes transferred in statements that unload data to another region and/or cloud.

INBOUND_DATA_TRANSFER_CLOUD

VARCHAR

Source cloud provider for statements that load data from another region and/or cloud.

INBOUND_DATA_TRANSFER_REGION

VARCHAR

Source region for statements that load data from another region and/or cloud.

INBOUND_DATA_TRANSFER_BYTES

NUMBER

Number of bytes transferred in a replication operation from another account. The source account could be in the same region or a different region than the current account.

LIST_EXTERNAL_FILE_TIME

NUMBER

Time (in milliseconds) spent listing external files.

CREDITS_USED_CLOUD_SERVICES

NUMBER

Number of credits used for cloud services.

RELEASE_VERSION

VARCHAR

Release version in the format of major_release.minor_release.patch_release.

EXTERNAL_FUNCTION_TOTAL_INVOCATIONS

NUMBER

The aggregate number of times that this query called remote services. For important details, see the Usage Notes.

EXTERNAL_FUNCTION_TOTAL_SENT_ROWS

NUMBER

The total number of rows that this query sent in all calls to all remote services.

EXTERNAL_FUNCTION_TOTAL_RECEIVED_ROWS

NUMBER

The total number of rows that this query received from all calls to all remote services.

EXTERNAL_FUNCTION_TOTAL_SENT_BYTES

NUMBER

The total number of bytes that this query sent in all calls to all remote services.

EXTERNAL_FUNCTION_TOTAL_RECEIVED_BYTES

NUMBER

The total number of bytes that this query received from all calls to all remote services.

IS_CLIENT_GENERATED_STATEMENT

BOOLEAN

Indicates whether the query was client-generated.

QUERY_HASH

VARCHAR

The hash value computed based on the canonicalized SQL text.

QUERY_HASH_VERSION

NUMBER

The version of the logic used to compute QUERY_HASH.

QUERY_PARAMETERIZED_HASH

VARCHAR

The hash value computed based on the parameterized query.

QUERY_PARAMETERIZED_HASH_VERSION

NUMBER

The version of the logic used to compute QUERY_PARAMETERIZED_HASH.

TRANSACTION_ID

NUMBER

ID of the transaction that contains the statement or 0 if the statement is not executed within a transaction.

QUERY_ACCELERATION_BYTES_SCANNED

NUMBER

Number of bytes scanned by the query acceleration service.

QUERY_ACCELERATION_PARTITIONS_SCANNED

NUMBER

Number of partitions scanned by the query acceleration service.

QUERY_ACCELERATION_UPPER_LIMIT_SCALE_FACTOR

NUMBER

Upper limit scale factor that a query would have benefited from.

BYTES_WRITTEN_TO_RESULT

NUMBER

Number of bytes written to a result object. For example, select * from ... would produce a set of results in tabular format representing each field in the selection. . . In general, the results object represents whatever is produced as a result of the query, and BYTES_WRITTEN_TO_RESULT represents the size of the returned result.

ROWS_WRITTEN_TO_RESULT

NUMBER

Number of rows written to a result object. For CREATE TABLE AS SELECT (CTAS) and all DML operations, this result is 1.

ROWS_INSERTED

NUMBER

Number of rows inserted by the query.

QUERY_RETRY_TIME

NUMBER

Total execution time (in milliseconds) for query retries caused by actionable errors. For more information, see Query retry columns.

QUERY_RETRY_CAUSE

VARIANT

Array of error messages for actionable errors. The array contains one error message for each query retry. If there is no query retry, the array is empty. For more information, see Query retry columns.

FAULT_HANDLING_TIME

NUMBER

Total execution time (in milliseconds) for query retries caused by errors that are not actionable. For more information, see Query retry columns.

The potential values for the QUERY_TYPE column include:

  • CREATE_USER

  • CREATE_ROLE

  • CREATE_NETWORK_POLICY

  • ALTER_ROLE

  • ALTER_NETWORK_POLICY

  • ALTER_ACCOUNT

  • DROP_SEQUENCE

  • DROP_USER

  • DROP_ROLE

  • DROP_NETWORK_POLICY

  • RENAME_NETWORK_POLICY

  • REVOKE

Examples

Retrieve up to the last 100 queries run in the current session:

select *
from table(information_schema.query_history_by_session())
order by start_time;
Copy

Retrieve up to the last 100 queries run by the current user (or run by any user on any warehouse on which the current user has the MONITOR privilege):

select *
from table(information_schema.query_history())
order by start_time;
Copy

Retrieve up to the last 100 queries run in the past hour by the current user (or run by any user on any warehouse on which the current user has the MONITOR privilege):

select *
from table(information_schema.query_history(dateadd('hours',-1,current_timestamp()),current_timestamp()))
order by start_time;
Copy

Retrieve all queries run by the current user (or run by any user on any warehouse on which the current user has the MONITOR privilege) within a specified 30 minute block of time within the past 7 days:

select *
  from table(information_schema.query_history(
    END_TIME_RANGE_START=>to_timestamp_ltz('2017-12-4 12:00:00.000 -0700'),
    END_TIME_RANGE_END=>to_timestamp_ltz('2017-12-4 12:30:00.000 -0700')));
Copy