Standard projection
Stores a collection of table data in a format that optimizes execution of certain queries on that table. For details, see Projections .
Syntax
CREATE PROJECTION [ IF NOT EXISTS ] [[database.]schema.]projection
[ (
{ projection-column | grouped-clause
[ ENCODING encoding-type ]
[ ACCESSRANK integer ] }[,...]
) ]
AS SELECT { * | { MATCH_COLUMNS('pattern') | expression [ [AS] alias ] }[,...] }
FROM [[database.]schema.]table [ [AS] alias]
[ ORDER BY column[,...] ]
[ SEGMENTED BY expression ALL NODES [ OFFSET offset ] | UNSEGMENTED ALL NODES ]
[ KSAFE [ k-num ]
[ ON PARTITION RANGE BETWEEN min-val AND max-val ] ]
Arguments
IF NOT EXISTS
If an object with the same name exists, return without creating the object. If you do not use this directive and the object already exists, Vertica returns with an error message.
The
IF NOT EXISTS
clause is useful for SQL scripts where you might not know if the object already exists. The ON ERROR STOP directive can be helpful in scripts.[
database
.]
schema
Schema for this projection and its anchor table. The value must be the same for both. If you specify a database, it must be the current database.
projection
Name of the projection to create, which must conform to Identifiers. It must also be unique among all names of sequences, tables, projections, views, and models within the same schema.
projection-column
The name of a projection column. The list of projection columns must match the SELECT list columns and expressions in number, type, and sequence.
If projection column names are omitted, Vertica uses the anchor table column names specified in the SELECT list.
grouped-clause
- See GROUPED clause.
ENCODING
encoding-type
The column encoding type, by default set to AUTO.
ACCESSRANK
integer
Overrides the default access rank for a column. Use this parameter to increase or decrease the speed at which Vertica accesses a column. For more information, see Overriding Default Column Ranking.
AS SELECT
- Columns or column expressions to select from the specified table:
-
*
(asterisk): Returns all columns in the queried tables. -
MATCH_COLUMNS('pattern'): Returns the names of all columns in the queried anchor table that match
pattern
. -
expression
[[AS]
alias
]
: Resolves to column data from the queried anchor table. You can optionally assign an alias to each column expression and reference that alias elsewhere in the SELECT statement—for example, in the ORDER BY or segmentation clause.
If you specify projection column names, the two lists of projection columns and table columns/expressions must exactly match in number and order.
-
ORDER BY
column
- Columns from the SELECT list on which to sort the projection. The ORDER BY clause can only be set to ASC (the default). Vertica always stores projection data in ascending sort order.
If you order by a column with a collection data type (ARRAY or SET), queries that use that column in an ORDER BY clause perform the sort again. This is because projections and queries perform the ordering differently.
If you omit the ORDER BY clause, Vertica uses the SELECT list to sort the projection.
SEGMENTED BY
expression
ALL NODES [ OFFSET
offset
] | UNSEGMENTED ALL NODES
-
How to distribute projection data:
-
Hash-segmentation using an expression: segment projection data evenly and distribute across cluster nodes.
If neither the anchor table nor the projection specifies segmentation, Vertica uses hash segmentation using all columns:
SEGMENTED BY HASH(column[,...]) ALL NODES OFFSET 0;
Tip
Vertica recommends segmenting large tables. -
KSAFE
k-num
Specifies K-safety for the projection. The value must be equal to or greater than database K-safety. Vertica ignores this option if set for unsegmented projections.
If you omit this clause, Vertica uses database K-safety.
For general information, see K-safety in an Enterprise Mode database.
ON PARTITION RANGE BETWEEN
min-val
AND
max-val
Limits projection data to a range of partition keys. The minimum value must be less than or equal to the maximum value.
Values can be NULL. A null minimum value indicates no lower bound and a null maximum value indicates no upper bound. If both are NULL, this statement drops the projection endpoints, producing a regular projection instead of a range projection.
For other requirements and usage details, see Partition range projections.
Privileges
Non-superusers:
-
Anchor table owner
-
CREATE privilege on the schema
Examples
See: