CREATE … CLONE | Snowflake Documentation (original) (raw)

Creates a copy of an existing object in the system. This command is primarily used for creatingzero-copy clones of databases, schemas, and tables. You can also use this command to create clones of other schema objects, including external stages, file formats, sequences, and database roles.

The command is a variation of the object-specific CREATE commands with the addition of the CLONE keyword.

Clone objects using Time Travel

For databases, schemas, and non-temporary tables, CLONE supports an additional AT | BEFORE clause for cloning usingTime Travel.

For databases and schemas:

Syntax

Databases, schemas

CREATE [ OR REPLACE ] { DATABASE | SCHEMA } [ IF NOT EXISTS ] CLONE [ { AT | BEFORE } ( { TIMESTAMP => | OFFSET => | STATEMENT => } ) ] [ IGNORE TABLES WITH INSUFFICIENT DATA RETENTION ] [ IGNORE HYBRID TABLES ] [ INCLUDE INTERNAL STAGES ] ...

Tables

CREATE [ OR REPLACE ] TABLE [ IF NOT EXISTS ] CLONE [ { AT | BEFORE } ( { TIMESTAMP => | OFFSET => | STATEMENT => } ) ] ...

Dynamic tables

CREATE [ OR REPLACE ] DYNAMIC TABLE CLONE [ { AT | BEFORE } ( { TIMESTAMP => | OFFSET => | STATEMENT => } ) ] [ TARGET_LAG = { ' { seconds | minutes | hours | days }' | DOWNSTREAM } WAREHOUSE = ]

Event tables

CREATE [ OR REPLACE ] EVENT TABLE CLONE [ { AT | BEFORE } ( { TIMESTAMP => | OFFSET => | STATEMENT => } ) ]

Apache Iceberg™ tables

CREATE [ OR REPLACE ] ICEBERG TABLE [ IF NOT EXISTS ] CLONE [ { AT | BEFORE } ( { TIMESTAMP => | OFFSET => | STATEMENT => } ) ] [ COPY GRANTS ] ...

Database roles

CREATE [ OR REPLACE ] DATABASE ROLE [ IF NOT EXISTS ] CLONE

Other schema objects

CREATE [ OR REPLACE ] { ALERT | FILE FORMAT | SEQUENCE | STAGE | STREAM | TASK } [ IF NOT EXISTS ] CLONE ...

Time Travel parameters

{ AT | BEFORE } ( { TIMESTAMP => _timestamp_ | OFFSET => _timedifference_ | STATEMENT => _id_ } )

The AT | BEFORE clause accepts one of the following parameters:

TIMESTAMP => _timestamp_

Specifies an exact date and time to use for Time Travel. The value must be explicitly cast to a TIMESTAMP, TIMESTAMP_LTZ, TIMESTAMP_NTZ, or TIMESTAMP_TZ data type.

If no explicit cast is specified, the timestamp in the AT clause is treated as a timestamp with the UTC time zone (equivalent to TIMESTAMP_NTZ). Using the TIMESTAMP data type for an explicit cast may also result in the value being treated as a TIMESTAMP_NTZ value. For details, see Date & time data types.

OFFSET => _timedifference_

Specifies the difference in seconds from the current time to use for Time Travel, in the form -N where Ncan be an integer or arithmetic expression (e.g. -120 is 120 seconds, -30*60 is 1800 seconds or 30 minutes).

STATEMENT => _id_

Specifies the query ID of a statement to use as the reference point for Time Travel. This parameter supports any statement of one of the following types:

The query ID must reference a query that has been executed within the last 14 days. If the query ID references a query over 14 days old, the following error is returned:

Error: statement not found

To work around this limitation, use the timestamp for the referenced query.

IGNORE TABLES WITH INSUFFICIENT DATA RETENTION

Ignore tables that no longer have historical data available in Time Travel to clone. If the time in the past specified in the AT | BEFORE clause is beyond the data retention period for any child table in a database or schema, skip the cloning operation for the child table. For more information, seeChild Objects and Data Retention Time.

Hybrid tables parameters

IGNORE HYBRID TABLES

Ignore hybrid tables when cloning a database or schema. The cloned database or schema includes other objects but skips hybrid tables. For more information, see Clone databases that contain hybrid tables.

Internal stage parameters

INCLUDE INTERNAL STAGES

Include named internal stages when cloning a database or schema.

For more information, see the usage notes.

Access control requirements

To create a clone, your current role must have the following privilege(s) on the source object:

Databases:

USAGE on the database.

Database roles:

OWNERSHIP on the database role and the CREATE DATABASE ROLE privilege on the target database.

Schemas:

If you specify the WITH MANAGED ACCESS clause, the required privileges depend on whether the source schema is a managed or unmanaged schema. For details, see CREATE SCHEMA privileges.

Tables:

SELECT

Alerts, Pipes, Streams, Tasks:

OWNERSHIP

Other objects:

USAGE

In addition, to clone a schema or an object within a schema, your current role must have required privileges on the container object(s) for both the source and the clone.

For information about privilege inheritance for cloned objects, see Cloning considerations.

General usage notes

Additional rules that apply to cloning objects

Metadata:

An object clone inherits the name and structure of the source object current at the time the CREATE CLONE statement is executed or at a specified time/point in the past using Time Travel. An object clone inherits any other metadata, such as comments or table clustering keys, that is current in the source object at the time the statement is executed, regardless of whether Time Travel is used.

Child objects:

A database or schema clone includes all child objects active at the time the statement is executed or at the specified time/point in the past. A snapshot of the table data represents the state of the source data when the statement is executed or at the specified time/point in the past. Child objects inherit the name and structure of the source child objects at the time the statement is executed.

Not cloned:

Cloning a database or schema does not clone external tables in the database or schema.

Hybrid tables can be cloned for databases but not for schemas.

Pipes:

A database or schema clone includes only pipe objects that reference external (Amazon S3, Google Cloud Storage, or Microsoft Azure) stages; internal (Snowflake) pipes are not cloned.

The default state of a pipe clone is as follows:

A pipe clone in either state can be resumed by executing an ALTER PIPE … SET PIPE_EXECUTION_PAUSED = false statement.

Tags:

Cloning a database or schema affects tags in that database or schema as follows:

Java UDF:

A Java UDF can be cloned when the database or schema containing the Java UDF is cloned. To be cloned, the Java UDF must meet certain conditions. For more information, see Limitations on cloning.

Data metric functions:

Cloning does not result in DMF assignments on the target object. If you clone a database or schema that contains DMFs, the DMFs are cloned to the target database or schema.

Table data:

When cloning a database, schema, or table, a snapshot of the data in each table is taken and made available to the clone. The snapshot represents the state of the source data either at the time the statement is executed or at the specified time/point in the past (usingTime Travel).

Object references:

Objects such as views, streams, and tasks include object references in their definition. For example:

When one of these objects is cloned, either in a cloned database or schema or as an individual object, for those object types that support cloning, the clone inherits references to other objects from the definition of the source object. For example, a clone of a view inherits the stored query from the source view, including the table references in the query.

Pay close attention to whether any object names in the definition of a source object are fully or partially qualified. A fully-qualified name includes the database and schema names. Any clone of the source object includes these parts in its own definition.

For example:

-- Create a schema to serve as the source for a cloned schema. CREATE SCHEMA source;

-- Create a table. CREATE TABLE mytable (col1 string, col2 string);

-- Create a view that references the table with a fully-qualified name. CREATE VIEW myview AS SELECT col1 FROM source.mytable;

-- Retrieve the DDL for the source schema. SELECT GET_DDL ('schema', 'source', true);

+--------------------------------------------------------------------------+

GET_DDL('SCHEMA', 'SOURCE', TRUE)
create or replace schema MPETERS_DB.SOURCE;
create or replace TABLE MPETERS_DB.SOURCE.MYTABLE (
COL1 VARCHAR(16777216),
COL2 VARCHAR(16777216)
);
create view MPETERS_DB.SOURCE.MYVIEW as select col1 from SOURCE.MYTABLE;
+--------------------------------------------------------------------------+

-- Clone the source schema. CREATE SCHEMA source_clone CLONE source;

-- Retrieve the DDL for the clone of the source schema. -- The clone of the view references the source table with the same fully-qualified name -- as in the view in the source schema. SELECT GET_DDL ('schema', 'source_clone', true);

+--------------------------------------------------------------------------------+

GET_DDL('SCHEMA', 'SOURCE_CLONE', TRUE)
create or replace schema MPETERS_DB.SOURCE_CLONE;
create or replace TABLE MPETERS_DB.SOURCE_CLONE.MYTABLE (
COL1 VARCHAR(16777216),
COL2 VARCHAR(16777216)
);
create view MPETERS_DB.SOURCE_CLONE.MYVIEW as select col1 from SOURCE.MYTABLE;
+--------------------------------------------------------------------------------+

If you intend to point a view to tables with the same names in other databases or schemas, we suggest creating a new view rather than cloning an existing view. This guidance also pertains to other objects that reference objects in their definition.

Note

For more information about this and other use cases that might affect your cloning operations, see Cloning considerations.

Notes for cloning with Time Travel

If you don’t specify a point in time, the clone defaults to the state of the object as of now (the CURRENT_TIMESTAMP value).

For more information, see Understanding & using Time Travel.

Troubleshoot cloning objects using Time Travel

The following scenarios can help you troubleshoot issues that can occur when cloning an object using Time Travel.

Error 000707 (02000): Time travel data is not available for <object_type> <object_name>. The requested time is either beyond the allowed time travel period or before the object creation time.

This error can be returned for the following reasons:

Cause The time in the past specified by the AT | BEFORE clause is beyond the data retention period for the object.
Solution Verify the data retention period for the object using the appropriate SHOW command and theretention_time column. Update the CREATE … CLONE statement to use a time in the past that is within the data retention period for the object.
Cause The cloning operation for a database or schema fails if the historical data for any child object has moved out of Time Travel.
Solution To skip child tables that no longer have historical data available in Time Travel, execute the cloning statement using theIGNORE TABLES WITH INSUFFICIENT DATA RETENTIONparameter to skip these tables.
Cause In some cases, this is caused by using a string where a timestamp is expected.
Solution Cast the string to a timestamp. ... AT(TIMESTAMP => '2023-12-31 12:00:00') -- fails ... AT(TIMESTAMP => '2023-12-31 12:00:00'::TIMESTAMP) -- succeeds Copy

Examples

Clone a database and all objects within the database at its current state:

CREATE DATABASE mytestdb_clone CLONE mytestdb;

Clone a schema and all objects within the schema at its current state:

CREATE SCHEMA mytestschema_clone CLONE testschema;

Clone a table at its current state:

CREATE TABLE orders_clone CLONE orders;

Clone a schema as it existed before the date and time in the specified timestamp:

CREATE SCHEMA mytestschema_clone_restore CLONE testschema BEFORE (TIMESTAMP => TO_TIMESTAMP(4036586400));

Clone a table as it existed exactly at the date and time of the specified timestamp:

CREATE TABLE orders_clone_restore CLONE orders AT (TIMESTAMP => TO_TIMESTAMP_TZ('04/05/2013 01:02:03', 'mm/dd/yyyy hh24:mi:ss'));

Clone a table as it existed immediately before the execution of the specified statement. Replace the query ID for the STATEMENT parameter in the example and execute the following CREATE TABLE statement:

CREATE TABLE orders_clone_restore CLONE orders BEFORE (STATEMENT => '8e5d0ca9-005e-44e6-b858-a8f5b37c5726');

Clone a database and all its objects as they existed four days ago and skip any tables that have a data retention period of less than four days:

CREATE DATABASE restored_db CLONE my_db AT (TIMESTAMP => DATEADD(days, -4, current_timestamp)::timestamp_tz) IGNORE TABLES WITH INSUFFICIENT DATA RETENTION;

Clone a schema that contains a mixture of standard tables and hybrid tables:

CREATE OR REPLACE SCHEMA clone_ht_schema CLONE ht_schema IGNORE HYBRID TABLES;

The new schema will only contain the standard tables from the original schema. If IGNORE HYBRID TABLES is not specified in this example, the command fails with an error because schemas that contain hybrid tables can’t be cloned.