Sparse Join Indexes | Database Design | VantageCloud Lake - Sparse Join Indexes - Teradata Vantage

Teradata® VantageCloud Lake

Deployment
VantageCloud
Edition
Lake
Product
Teradata Vantage
Published
January 2023
ft:locale
en-US
ft:lastEdition
2024-12-11
dita:mapPath
phg1621910019905.ditamap
dita:ditavalPath
pny1626732985837.ditaval
dita:id
phg1621910019905

Any join index, whether simple or aggregate, multitable or single-table, can be sparse. A sparse join index specifies a constant expression in the WHERE clause of its definition to narrowly filter its row population. For example, the following DDL creates an aggregate join index containing only the sales records from 2000:

CREATE JOIN INDEX j1 AS
SELECT store_id, dept_id, SUM(sales_dollars) AS sum_sd
FROM sales
WHERE EXTRACT(year FROM sales_date) = 2000
GROUP BY store_id, dept_id;

This method limits the rows included in the join index to a subset of the rows in the table based on an SQL request result.

When base tables are large, you can use this feature to reduce the content of the join index to only the portion of the table that is frequently used if the typical query only references a portion of the rows.

Collect statistics on the sparse-defining column of the join index, or the Optimizer may not use the join index.

Performance Impact of Sparse Join Indexes

A sparse index can focus on the portions of the tables that are most frequently used to do the following things.
  • Make the costs for maintaining an index proportional to the percent of rows referenced in the index.
  • Make request access faster where the resulting sparse index is smaller than a standard join index.
  • Reduce the storage requirements for a join index where possible.