About managing dynamic tables¶
Managing dynamic tables typically involves the following tasks:
Task |
Description |
---|---|
List dynamic tables and view information about a dynamic table. |
|
Dropping dynamic tables. |
|
Use the ALTER DYNAMIC TABLE command to alter existing dynamic tables:
|
|
Manually suspend or resume dynamic tables using Snowsight or the ALTER DYNAMIC TABLE … SUSPEND | RESUME command. Learn more about how automatic suspension works. |
|
Manually refresh a dynamic table to get the most current data. |
List and view information about dynamic tables¶
To list the dynamic tables in a schema and view information about those dynamic tables, you can use either the following SQL commands or Snowsight, as long as you use a role that has the MONITOR privilege on the dynamic tables.
For more information, see Privileges to view a dynamic table’s metadata.
To list the dynamic tables in the current database (or in the account, if no database is currently in use), use the SHOW DYNAMIC TABLES command.
For example, to list the dynamic tables with names that start with product_
in the database mydb
and schema myschema
, execute
the following SQL statement:
SHOW DYNAMIC TABLES LIKE 'product_%' IN SCHEMA mydb.myschema;
+-------------------+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| created_on | name | database_name | schema_name | cluster_by | rows | bytes | owner | target_lag | refresh_mode | refresh_mode_reason | warehouse | comment | text | automatic_clustering | scheduling_state | last_suspended_on | is_clone | is_replica | is_iceberg | data_timestamp | owner_role_type |
|-------------------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------|
|2025-01-01 16:32:28 +0000 | product_dt | my_db | my_schema | | 2 | 2048 | ORGADMIN | DOWNSTREAM | INCREMENTAL | null | mywh | | create or replace dynamic table | OFF | ACTIVE | null | false | false | false |2025-01-01 16:32:28 +0000 | ROLE |
| product dt ... | | |
+-------------------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
To output information about the columns in a dynamic table, use the DESCRIBE DYNAMIC TABLE command.
For example, to list the columns in my_dynamic_table
, execute the following SQL statement:
DESC DYNAMIC TABLE my_dynamic_table;
+-------------------+--------------------------------------------------------------------------------------------------------------------------+
| name | type | kind | null? | default | primary key | unique key | check | expression | comment | policy name | privacy domain |
|-------------------+------------------------------------------------------------------------------------------------------------------------|
| AMOUNT | NUMBER(38,0) | COLUMN | Y | null | N | N | null | null | null | null | null | | |
+-------------------+------------------------------------------------------------------------------------------------------------------------+
Dynamic tables are also included in the results of the TABLES view.
To list the dynamic tables in a schema and view information about a specific dynamic table, do the following:
Sign in to Snowsight.
Select Data » Databases.
Select a database and schema.
Select the Dynamic Tables tab or expand Dynamic Tables in the database object explorer.
To view information about a specific dynamic table, select the dynamic table from the list of dynamic tables in the Dynamic Tables tab or from the database object explorer.
The tabs in this page provide the following details about your selected dynamic table:
Table Details: Displays basic information about the dynamic table, including:
The scheduling state of your dynamic table.
The last refresh status of your dynamic table. For failed refreshes, you can see more information about the error if you hover over the status.
The current and target lag for your dynamic table.
Whether incremental refreshes or full refreshes are used to update the table.
The definition of the dynamic table.
The tags for the dynamic table.
The privileges granted for working with the dynamic table.
Columns: Information about the columns in the dynamic table.
Data Preview: A preview of up to 100 rows of the data in the dynamic table.
Graph: Displays the directed acyclic graph (DAG) that includes this dynamic table.
Refresh History: Displays the history of refreshes and the lag metrics.
Drop a dynamic table¶
To drop a dynamic table, you can use either Snowsight or SQL commands.
- Snowsight:
In Snowsight, open the dynamic table details page (instructions).
On the More menu in the upper-right corner of the page, select Drop.
- SQL:
Use the DROP DYNAMIC TABLE command.
For example, to drop the dynamic table named
product
:
DROP DYNAMIC TABLE product;
Alter existing dynamic tables¶
This section describes making changes to existing dynamic tables using the ALTER DYNAMIC TABLE command.
Change the warehouse or target lag for dynamic tables¶
You might want to adjust the warehouse for a dynamic table for cost efficiency or performance boost. For more information, see Compute cost and How warehouse configurations affect dynamic table performance.
You might want to adjust the target lag for a dynamic table for any of the following reasons:
You need more up-to-date data. Reducing the target lag ensures the dynamic table refreshes more frequently, providing fresher data closer to real time.
You want to optimize resources. Increasing the target lag can reduce the frequency of refreshes, saving compute resources, which is useful for workloads that don’t need constant updates or where data changes infrequently. For example, if a dynamic table refreshes every 20 minutes but only needs to be within one hour of the source tables, setting a one-hour target lag can lower costs.
You want the target lag to align with the data pipeline. If your dynamic table depends on other tables that have longer refresh intervals, adjusting the target lag ensures it aligns with dependencies.
For more information, see Understanding target lag.
To change the warehouse or target lag for a dynamic table, use the ALTER DYNAMIC TABLE command. For example:
-- Change the warehouse for my_dynamic_table to my_other_wh:
ALTER DYNAMIC TABLE my_dynamic_table SET
WAREHOUSE = my_other_wh;
-- Specify the downstream target lag for a dynamic table:
ALTER DYNAMIC TABLE my_dynamic_table SET
TARGET_LAG = DOWNSTREAM;
For additional details and examples of using downstream target lag, see Understanding target lag.
Rename dynamic tables¶
Renaming a dynamic table can be useful in scenarios where you have scripts or applications that rely on a specific table name, and you want to update the dynamic table without changing your existing script. For example, if you have a script that references a specific dynamic table name, renaming the table allows you to swap out the underlying table while keeping the script unchanged. This ensures continuity and avoids the hassle of updating multiple references across scripts or processes.
To rename a dynamic table, use the ALTER DYNAMIC TABLE … RENAME TO command. For example:
ALTER DYNAMIC TABLE my_dynamic_table RENAME TO my_new_dynamic_table;
Swap dynamic tables¶
Swapping dynamic tables allows for a seamless transition between datasets or table versions without disrupting workflows or modifying dependent scripts. For example, if you’re developing a new version of a table but want to keep the same name for ongoing processes, swapping lets you replace the old table with the new one. This approach ensures continuity while enabling updates, testing, or upgrades with minimal downtime or disruption.
To swap a dynamic table, use the ALTER DYNAMIC TABLE … SWAP WITH command. Note that you can only swap a dynamic table with another dynamic table.
For example:
-- Swap my_dynamic_table with the my_new_dynamic_table:
ALTER DYNAMIC TABLE my_dynamic_table SWAP WITH my_new_dynamic_table;
Cluster dynamic tables¶
Clustering dynamic tables can enhance performance by improving query efficiency and refresh operations:
Query efficiency: Clustering dynamic tables can help speed up queries, just like with regular tables, by clustering on common join keys or filter columns.
Refresh operations: Clustering can also help make refreshes faster if the clustering keys align with frequent change patterns; for example, clustering by user ID can be effective when you have updates where a handful of users change.
Clustering keys can be specified for a dynamic table with incremental or full refresh mode. In full refresh, the clustering is performed during the refresh and background reclustering isn’t needed.
To cluster a dynamic table, use the ALTER DYNAMIC TABLE … CLUSTER BY command:
ALTER DYNAMIC TABLE my_dynamic_table CLUSTER BY (date);
Determine the optimal target lag for a dynamic table¶
To determine the optimal target lag time for a dynamic table, you can use either Snowsight or SQL commands.
- Snowsight:
On the dynamic table details page, select the Refresh History tab.
Check the maximum actual lag time, which is displayed at the top of the tab. This metric is based on the actual lag time for each refresh.
- SQL:
Use the DYNAMIC_TABLE_REFRESH_HISTORY table function in INFORMATION_SCHEMA. This function returns information about each refresh of a dynamic table, including the time taken for the refresh and which refreshes were skipped.
The lag time that you choose can affect the refresh schedule determined by the automated refresh process. The automated refresh process chooses a schedule that best meets the lag times of the dynamic tables.
Determine whether an incremental or full refresh is used¶
To determine whether an incremental or full refresh is used to update a dynamic table, you can use either Snowsight or SQL commands.
- Snowsight:
Go to the dynamic table details page.
The basic details at the top of the page indicate whether incremental or full refreshes are used for that table.
- SQL:
Use the SHOW DYNAMIC TABLES command, and check the value of the
REFRESH_MODE
column in the output.REFRESH_MODE_REASON contains additional details on the choice of REFRESH_MODE.
Understanding the effects of changes to columns in base tables¶
The columns in the base tables, views, and underlying dynamic tables can change over time. Some changes can affect the dynamic table itself; others may have limited or no impact.
When the underlying objects associated with a dynamic table change, the following behaviors apply:
Change |
Impact |
---|---|
|
None. If a new column is added to the base table or an unused column is deleted, no action occurs and refreshes continue as before. |
|
Full refresh/reinitialize: During the next refresh cycle, a full refresh is done to ensure that no incorrect or stale data is in the dynamic table. |
|
The state of the dynamic table changes to FAILED. The dynamic table must be recreated to respond to the change. |
Suspend or resume dynamic tables¶
You can manually suspend a dynamic table or your dynamic tables might automatically suspend. To resume your dynamic tables, use Snowsight or the ALTER DYNAMIC TABLE … RESUME command.
Manually suspend dynamic tables¶
Manually suspend a dynamic table when you don’t need it now but want to avoid refresh costs without dropping it, keeping it available for future use. Suspension can also give you better control over refresh frequency, for example if skips occur and you need time for troubleshooting.
If you want to ensure refreshes at a specific time or occurrence, you can use a task or script that runs regularly to execute a manual refresh because dynamic tables don’t guarantee exact refresh timing. This allows precise control over when your table refreshes.
You can use either the ALTER DYNAMIC TABLE … SUSPEND command or Snowsight to manually suspend dynamic tables, with the following limitations:
Suspending a dynamic table also suspends the dynamic tables that are downstream from it.
Suspending a dynamic table with incremental refresh beyond the Time Travel retention period of its base tables will cause it to fail on the next refresh after the dynamic table resumes.
ALTER DYNAMIC TABLE my_dynamic_table SUSPEND;
Sign in to Snowsight.
In the navigation, go to Monitoring » Dynamic Tables.
Select your dynamic table.
In the popup, confirm that you want to suspend your dynamic table.
Automatic dynamic table suspension¶
Dynamic tables are automatically suspended after five consecutive scheduled refresh errors. A successful refresh, including a manual refresh, resets the error count to zero. For example, if a table fails two consecutive scheduled refreshes, then succeeds on the next, the error count resets to zero.
Errors from manually triggered refreshes don’t count toward this limit.
Any dynamic tables dependent on a suspended table are also suspended.
You can view the current state (ACTIVE or SUSPENDED) of your dynamic tables using one of the following options:
Execute the DYNAMIC_TABLE_GRAPH_HISTORY table function:
SELECT name, scheduling_state
FROM TABLE (INFORMATION_SCHEMA.DYNAMIC_TABLE_GRAPH_HISTORY());
In the output, the SCHEDULING_STATE
column shows the state of your dynamic table (ACTIVE or SUSPENDED):
+-------------------+---------------------------------------------------------------------------------+
| NAME | SCHEDULING_STATE |
|-------------------+---------------------------------------------------------------------------------|
| DTSIMPLE | { |
| | "reason_code": "SUSPENDED_DUE_TO_ERRORS", |
| | "reason_message": "The DT was suspended due to 5 consecutive refresh errors", |
| | "state": "SUSPENDED", |
| | "suspended_on": "2023-06-06 19:27:29.142 -0700" |
| | } |
| DT_TEST | { |
| | "state": "ACTIVE" |
| | } |
+-------------------+---------------------------------------------------------------------------------+
To view the state of your dynamic tables, sign in to Snowsight. In the navigation menu, select Monitoring » Dynamic Tables.
You can view the state and last refresh status for your dynamic tables on this page. You can also filter by database or schema to narrow the results.
Manually refresh a dynamic table¶
To get the latest data, manually refresh a dynamic table before its next scheduled refresh. This is useful for large target lags or one-time freshness needs. For example, if a dynamic table is configured with a large target lag and its next refresh is hours away, a manual refresh ensures up-to-date data.
Manual refreshes are never skipped but they can cause scheduled refreshes to skip, especially if you perform frequent manual refreshes on a dynamic table. Doing so can prevent downstream dynamic tables from refreshing. For this reason, Snowflake recommends that you avoid frequently performing manual refreshes on a dynamic table with downstream dynamic tables that are expected to refresh according to target lag.
You can manually refresh a dynamic table using the ALTER DYNAMIC TABLE … REFRESH command or using Snowsight.
ALTER DYNAMIC TABLE my_dynamic_table REFRESH
Sign in to Snowsight.
Select Monitoring » Dynamic Tables.
Find your dynamic table in the list and then select
» Refresh Manually.