Skip to content

Commit 79f6255

Browse files
committed
expand index documentation.
1 parent 241968e commit 79f6255

File tree

2 files changed

+152
-0
lines changed

2 files changed

+152
-0
lines changed

docs/sphinx/source/reference/Indexes.rst

Lines changed: 151 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -64,6 +64,152 @@ In each case, the fact that index entries are ordered by `fname` is leveraged, e
6464
the scan to a smaller range of index entries. The `lname` field can then be returned to the user without having to
6565
perform an additional lookup of the underlying row.
6666

67+
Index Syntax Alternatives
68+
##########################
69+
70+
The Relational Layer supports two equivalent syntaxes for creating indexes:
71+
72+
1. **INDEX AS SELECT** - A query-based syntax (shown above) inspired by materialized views
73+
2. **INDEX ON** - A traditional columnar syntax that creates indexes on tables or views
74+
75+
Both syntaxes produce identical index structures and have the same capabilities. The choice between them is primarily
76+
a matter of style and organizational preference.
77+
78+
INDEX ON Syntax
79+
***************
80+
81+
The ``INDEX ON`` syntax provides a more traditional approach to index creation, specifying columns directly rather
82+
than through a SELECT query:
83+
84+
.. code-block:: sql
85+
86+
CREATE INDEX <indexName> ON <source>(<columns>) [INCLUDE(<valueColumns>)] [OPTIONS(...)]
87+
88+
Where:
89+
90+
* :sql:`indexName` is the name of the index
91+
* :sql:`source` is a table or view name
92+
* :sql:`columns` specifies the index key columns with optional ordering
93+
* :sql:`INCLUDE` clause (optional) adds covered columns stored as values
94+
* :sql:`OPTIONS` clause (optional) specifies index-specific options
95+
96+
Using the same employee table from above, we can create an equivalent index using the INDEX ON syntax:
97+
98+
.. code-block:: sql
99+
100+
CREATE INDEX fnameIdx ON employee(fname) INCLUDE(lname)
101+
102+
This creates the same index structure as the INDEX AS SELECT example - a VALUE index with ``fname`` in the key
103+
and ``lname`` as a covered value.
104+
105+
Syntax Comparison
106+
*****************
107+
108+
These two approaches create identical indexes:
109+
110+
**INDEX AS SELECT:**
111+
112+
.. code-block:: sql
113+
114+
CREATE INDEX fnameIdx AS
115+
SELECT fname, lname
116+
FROM employee
117+
ORDER BY fname
118+
119+
**INDEX ON:**
120+
121+
.. code-block:: sql
122+
123+
CREATE INDEX fnameIdx ON employee(fname) INCLUDE(lname)
124+
125+
Column Ordering and NULL Handling
126+
##################################
127+
128+
When creating indexes using either syntax, you can control how values are sorted in the index through ordering
129+
clauses and NULL semantics.
130+
131+
Sorting Criteria
132+
****************
133+
134+
Each key column in an INDEX ON definition supports explicit sort order:
135+
136+
* :sql:`ASC` (ascending) - Values sorted from smallest to largest (default if not specified)
137+
* :sql:`DESC` (descending) - Values sorted from largest to smallest
138+
139+
For INDEX AS SELECT, the sort order is specified in the ORDER BY clause.
140+
141+
NULL Semantics
142+
**************
143+
144+
You can control where NULL values appear in the sort order:
145+
146+
* :sql:`NULLS FIRST` - NULL values appear before non-NULL values
147+
* :sql:`NULLS LAST` - NULL values appear after non-NULL values
148+
149+
**Default NULL behavior:**
150+
151+
* For ``ASC`` ordering: ``NULLS FIRST`` is the default
152+
* For ``DESC`` ordering: ``NULLS LAST`` is the default
153+
154+
Ordering Syntax Examples
155+
*************************
156+
157+
The ordering clause for each column in INDEX ON can take several forms:
158+
159+
1. Sort order only: ``columnName ASC`` or ``columnName DESC``
160+
2. Sort order with null semantics: ``columnName ASC NULLS LAST`` or ``columnName DESC NULLS FIRST``
161+
3. Null semantics only: ``columnName NULLS FIRST`` (uses default ASC ordering)
162+
163+
Examples:
164+
165+
.. code-block:: sql
166+
167+
-- Ascending order with nulls last
168+
CREATE INDEX idx_rating ON products(rating ASC NULLS LAST)
169+
170+
-- Descending order with nulls first
171+
CREATE INDEX idx_price ON products(price DESC NULLS FIRST)
172+
173+
-- Specify only null semantics (ascending is implicit)
174+
CREATE INDEX idx_stock ON products(stock NULLS LAST)
175+
176+
-- Mixed ordering across multiple columns
177+
CREATE INDEX idx_complex ON products(
178+
category ASC NULLS FIRST,
179+
price DESC NULLS LAST,
180+
name ASC
181+
)
182+
183+
For INDEX AS SELECT syntax, the same ordering is specified in the ORDER BY clause:
184+
185+
.. code-block:: sql
186+
187+
CREATE INDEX idx_rating AS
188+
SELECT rating
189+
FROM products
190+
ORDER BY rating ASC NULLS LAST
191+
192+
Partitioning for Vector Indexes
193+
################################
194+
195+
Vector indexes support an optional ``PARTITION BY`` clause that allows organizing vectors by category or tenant.
196+
This clause is **only applicable to vector indexes** created with the ``VECTOR INDEX`` syntax and is not supported
197+
for regular value indexes.
198+
199+
Partitioning helps improve query performance for vector similarity searches by limiting the search space to relevant
200+
partitions:
201+
202+
.. code-block:: sql
203+
204+
CREATE VECTOR INDEX idx_embedding USING HNSW ON products(embedding)
205+
PARTITION BY(category)
206+
207+
In this example, vectors are partitioned by product category, so similarity searches can be scoped to specific
208+
categories for better performance.
209+
210+
**Important:** The ``PARTITION BY`` clause cannot be used with regular (non-vector) indexes created using either
211+
the INDEX AS SELECT or INDEX ON syntax.
212+
67213
Indexes on nested fields
68214
########################
69215

@@ -128,3 +274,8 @@ that resembles the structure of the SQL statement:
128274
* Projected fields :sql:`f1`, :sql:`f2`, ... :sql:`fn` in (sub)queries maps to a :sql:`concat(field(f1), field(f2), ... field(fn))`.
129275
* Projected nested fields (:sql:`f1`, :sql:`f2`, ... :sql:`fn`) from a repeated field :sql:`rf`, i.e. :sql:`select f1, f2, ... fn, ... from FOO.rf`
130276
maps to :sql:`field(rf, FAN_OUT).nest(field(f1), (field(f2), ..., field(fn)))`.
277+
278+
See Also
279+
########
280+
281+
* :doc:`CREATE INDEX <sql_commands/DDL/CREATE/INDEX>` - Complete CREATE INDEX command reference with detailed syntax and examples

docs/sphinx/source/reference/sql_commands/DDL/CREATE/INDEX.rst

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -530,6 +530,7 @@ RabitQ is a quantization technique that reduces memory usage for high-dimensiona
530530
CREATE VECTOR INDEX idx_embedding USING HNSW ON products(embedding)
531531
PARTITION BY(category)
532532
OPTIONS (
533+
USE_RABITQ = true,
533534
SAMPLE_VECTOR_STATS_PROBABILITY = 0.05
534535
)
535536

0 commit comments

Comments
 (0)