Skip to content
You're viewing the beta version. Looking for legacy docs? Click here.

Use liquid clustering for Delta tables

Liquid clustering improves the existing partitioning and ZORDER techniques by simplifying data layout decisions in order to optimize query performance. Liquid clustering provides flexibility to redefine clustering columns without rewriting existing data, allowing data layout to evolve alongside analytic needs over time.

The following are examples of scenarios that benefit from clustering:

  • Tables often filtered by high cardinality columns.
  • Tables with significant skew in data distribution.
  • Tables that grow quickly and require maintenance and tuning effort.
  • Tables with access patterns that change over time.
  • Tables where a typical partition column could leave the table with too many or too few partitions.

You can enable liquid clustering on an existing table or during table creation. Clustering is not compatible with partitioning or ZORDER. Once enabled, run OPTIMIZE jobs as usual to incrementally cluster data. See How to trigger clustering.

To enable liquid clustering, add the CLUSTER BY phrase to a table creation statement, as in the examples below:

-- Create an empty table
CREATE TABLE table1(col0 int, col1 string) USING DELTA CLUSTER BY (col0);
-- Using a CTAS statement (Delta 3.3+)
CREATE EXTERNAL TABLE table2 CLUSTER BY (col0) -- specify clustering after table name, not in subquery
LOCATION 'table_location'
AS SELECT * FROM table1;

In Delta Lake 3.3 and above you can enable liquid clustering on an existing unpartitioned Delta table using the following syntax:

ALTER TABLE <table_name>
CLUSTER BY (<clustering_columns>)

Clustering columns can be defined in any order. If two columns are correlated, you only need to add one of them as a clustering column.

If you’re converting an existing table, consider the following recommendations:

Current data optimization techniqueRecommendation for clustering columns
Hive-style partitioningUse partition columns as clustering columns.
Z-order indexingUse the ZORDER BY columns as clustering columns.
Hive-style partitioning and Z-orderUse both partition columns and ZORDER BY columns as clustering columns.
Generated columns to reduce cardinality (for example, date for a timestamp)Use the original column as a clustering column, and don’t create a generated column.

You must use a Delta writer client that supports Clustering and DomainMetadata table features.

Use the OPTIMIZE command on your table, as in the following example:

sql OPTIMIZE table_name;

Liquid clustering is incremental, meaning that data is only rewritten as necessary to accommodate data that needs to be clustered. Already clustered data files with different clustering columns are not rewritten.

In Delta Lake 3.3 and above, you can force reclustering of all records in a table with the following syntax:

sql OPTIMIZE table_name FULL;

Run OPTIMIZE FULL when you change clustering columns. If you have previously run OPTIMIZE FULL and there has been no change to clustering columns, OPTIMIZE FULL runs the same as OPTIMIZE. Always use OPTIMIZE FULL to ensure that data layout reflects the current clustering columns.

You can read data in a clustered table using any Delta Lake client. For best query results, include clustering columns in your query filters, as in the following example:

You can change clustering columns for a table at any time by running an ALTER TABLE command, as in the following example:

sql ALTER TABLE table_name CLUSTER BY (new_column1, new_column2);

When you change clustering columns, subsequent OPTIMIZE and write operations use the new clustering approach, but existing data is not rewritten.

You can also turn off clustering by setting the columns to NONE, as in the following example:

sql ALTER TABLE table_name CLUSTER BY NONE;

Setting cluster columns to NONE does not rewrite data that has already been clustered, but prevents future OPTIMIZE operations from using clustering columns.

You can use DESCRIBE DETAIL commands to see the clustering columns for a table, as in the following examples:

sql DESCRIBE DETAIL table_name;

The following limitations exist:

  • You can only specify columns with statistics collected for clustering columns. By default, the first 32 columns in a Delta table have statistics collected.
  • You can specify up to 4 clustering columns.