Creates an index on a specified table, or pair of tables. Once an index is created, it is never referenced in an SQL statement again except to delete it using the DROP INDEX statement.
CREATE [ UNIQUE ] [ index-type ] INDEX [ IF NOT EXISTS ] index-name …ON [ owner.]table-name … ( column-name [ , column-name ] …) …[ { IN | ON } dbspace-name ] …[ NOTIFY integer ] …[ DELIMITED BY 'separators-string‘ ] …[ LIMIT maxwordsize-integer ] index-type { CMP | HG | HNG | LF | WD | DATE | TIME | DTTM }
To create an index on the relationship between two columns in an IQ main store table, you can specify an index-type of CMP (Compare). Columns must be of identical data type, precision and scale. For a CHAR, VARCHAR, BINARY or VARBINARY column, precision means that both columns have the same width.
You can specify multiple indexes on a column of an IQ main store table, but these must be of different index types. CREATE INDEX does not let you add a duplicate index type. SAP Sybase IQ chooses the fastest index available for the current query or portion of the query. However, each additional index type might significantly add to the space requirements of that table.
If you omit the UNIQUE clause, you can specify only an HG index. Foreign keys require nonunique indexes and composite foreign keys require nonunique composite HG indexes. The multicolumn composite key for both unique and nonunique HG indexes has a maximum width of 5300 bytes. CHAR or VARCHAR data cannot be more than 255 bytes when it is part of a composite key or single-column HG, LF, HNG, DATE, TIME, or DTTM indexes.
SAP Sybase IQ allows the use of NULL in data values on a user created unique multicolumn HG index, if the column definition allows for NULL values and a constraint (primary key or unique) is not being enforced. See “Multicolumn indexes” in Notes for more information.
The cat is on the mat
and the database was created with the CASE IGNORE setting using default separators, these words are stored in the WD index from this string:
cat is mat on the
If you specify multiple DELIMITED BY and LIMIT clauses, no error is returned, but only the last clause of each type is used.
To specify tab as a delimiter, you can either type a <TAB> character within the separator string, or use the hexadecimal ASCII code of the tab character, \x09. “\t” specifies two separators, \ and the letter t. To specify newline as a delimiter, you can type a <RETURN> character or the hexadecimal ASCII code \x0a.
For example, the clause DELIMITED BY ' :;.\/t' specifies these seven separators: space : ; . \ / t
Delimiter | Separator Sstring for the DELIMITED BY Clause |
---|---|
tab | ' ' (type <TAB>)or
'\x09' |
newline | ' ' (type <RETURN>) or '\x0a' |
CREATE CMP INDEX proj_curr_cmp ON sales_data ( projected_earnings, current_earnings )
CREATE HG INDEX id_hg ON SalesOrderItems ( ID ) IN Dsp5
CREATE HG INDEX item_prod_hg ON Sales_OrderItems ( ProductID)
CREATE LF INDEX item_prod ON SalesOrderItems ( ProductID) NOTIFY 0
CREATE WD INDEX earnings_wd ON earnings_report_table(varchar) DELIMITED BY ‘ :;.’ LIMIT 25
CREATE DTTM INDEX order_dttm ON SalesOrders ( OrderDate )
‘Concord’ ‘Farms ’
Suppose that a user entered this query:
SELECT COUNT(*)FROM Customers WHERE CompanyName contains (‘Farms’)
The parser determines that the string contains:
‘Farms ’
instead of:
‘Farms’
and returns 0 instead of 1. You can avoid this problem by using VARCHAR instead of CHAR columns.
HG and CMP are the only types of indexes that can have multiple columns. You cannot create a unique HNG or LF index with more than one column, and you cannot create a DATE, TIME, or DTTM index with more than one column.
The maximum width of a multicolumn concatenated key is 5KB (5300 bytes). The number of columns allowed depends on how many columns can fit into 5KB. CHAR or VARCHAR data greater than 255 bytes are not allowed as part of a composite key in single-column HG, LF, HNG, DATE, TIME, or DTTM indexes.
An INSERT on a multicolumn index must include all columns of the index.
Queries with a single column in the ORDER BY clause run faster using multicolumn HG indexes. For example:
SELECT abs (x) from t1 ORDER BY x
In the above example, the HG index vertically projects x in sorted order.
To enhance query performance, use multicolumn HG indexes to run ORDER BY operations on more than one column (that can also include ROWID) in the SELECT or ORDER BY clause with these conditions:
If more than one multicolumn HG index satisfies these conditions, the index with the lowest distinct counts is used.
If a query has an ORDER BY clause, and the ORDER BY column list is a prefix of a multicolumn index where all columns referenced in the SELECT list are present in a multicolumn index, then the multicolumn index performs vertical projection; for example:
SELECT x,z,y FROM T ORDER BY x,y
If expressions exist on base columns in the SELECT list, and all the columns referenced in all the expressions are present in the multicolumn index, then the query will use a multicolumn index; for example:
SELECT power(x,2), x+y, sin(z) FROM T ORDER BY x,y
In addition to the two previous examples, if the ROWID() function is in the SELECT list expressions, multicolumn indexes will be used. For example:
SELECT rowid()+x, z FROM T ORDER BY x,y,z
In addition to the three previous examples, if ROWID() is present at the end of an ORDER BY list, and if the columns of that list—except for ROWID()—use multicolumn indexes in the exact order, multicolumn indexes will be used for the query. For example:
SELECT z,y FROM T ORDER BY x,y,z,ROWID()
SAP Sybase IQ allows the use of NULL in data values on a user created unique multicolumn HG index, if the column definition allows for NULL values and a constraint (primary key or unique) is not being enforced. The rules for this feature are as follows:
These examples illustrate these rules. Given the table table1:
CREATE TABLE table1 (c1 INT NULL, c2 INT NULL, c3 INT NOT NULL);
Create a unique single column HG index on a column that allows NULLs:
CREATE UNIQUE HG INDEX c1_hg1 ON table1 (c1);
According to rule 1 above, you can insert a NULL value into an index column in multiple rows:
INSERT INTO table1(c1,c2,c3) VALUES (NULL,1,1); INSERT INTO table1(c1,c2,c3) VALUES (NULL,2,2);
Create a unique multicolumn HG index on a columns that allows NULLs:
CREATE UNIQUE HG INDEX c1c2_hg2 ON table1(c1,c2);
According to rule 2 above, you must guarantee uniqueness in the index. The following INSERT does not succeed, since the multicolumn index c1c2_hg2 on row 1 and row 3 has the same value:
INSERT INTO table1(c1,c2,c3) VALUES (NULL,1,3);
These INSERT operations are successful, however, according to rules 1 and 3:
INSERT INTO table1(c1,c2,c3) VALUES (NULL,NULL,3); INSERT INTO table1(c1,c2,c3) VALUES (NULL,NULL,4);
Uniqueness is preserved in the multicolumn index.
This UPDATE operation is successful, as rule 3 allows multiple rows with NULL values in all columns in the multicolumn index:
UPDATE table1 SET c2=NULL WHERE c3=1
When a multicolumn HG index is governed by a unique constraint, a NULL value is not allowed in any column participating in the index.
Adaptive Server indexes can be either clustered or nonclustered. A clustered index almost always retrieves data faster than a nonclustered index. Only one clustered index is permitted per table.
SAP Sybase IQ does not support clustered indexes. The CLUSTERED and NONCLUSTERED keywords are allowed by SQL Anywhere, but are ignored by SAP Sybase IQ. If no index-type is specified, SAP Sybase IQ creates an HG index on the specified column(s).
SAP Sybase IQ does not permit the DESC keyword.
Index names must be unique on a given table for both SAP Sybase IQ and Adaptive Server.