For InnoDB
and MyISAM
tables, MySQL can create spatial indexes using syntax similar to
that for creating regular indexes, but using the
SPATIAL
keyword. Columns in spatial indexes
must be declared NOT NULL
. The following
examples demonstrate how to create spatial indexes:
With
CREATE TABLE
:Press CTRL+C to copyCREATE TABLE geom (g GEOMETRY NOT NULL, SPATIAL INDEX(g));
With
ALTER TABLE
:Press CTRL+C to copyCREATE TABLE geom (g GEOMETRY NOT NULL); ALTER TABLE geom ADD SPATIAL INDEX(g);
With
CREATE INDEX
:Press CTRL+C to copyCREATE TABLE geom (g GEOMETRY NOT NULL); CREATE SPATIAL INDEX g ON geom (g);
SPATIAL INDEX
creates an R-tree index. For
storage engines that support nonspatial indexing of spatial
columns, the engine creates a B-tree index. A B-tree index on
spatial values is useful for exact-value lookups, but not for
range scans.
For more information on indexing spatial columns, see Section 13.1.14, “CREATE INDEX Statement”.
To drop spatial indexes, use ALTER
TABLE
or DROP INDEX
:
With
ALTER TABLE
:Press CTRL+C to copyALTER TABLE geom DROP INDEX g;
With
DROP INDEX
:Press CTRL+C to copyDROP INDEX g ON geom;
Example: Suppose that a table geom
contains
more than 32,000 geometries, which are stored in the column
g
of type GEOMETRY
. The
table also has an AUTO_INCREMENT
column
fid
for storing object ID values.
Press CTRL+C to copymysql> DESCRIBE geom; +-------+----------+------+-----+---------+----------------+ | Field | Type | Null | Key | Default | Extra | +-------+----------+------+-----+---------+----------------+ | fid | int(11) | | PRI | NULL | auto_increment | | g | geometry | | | | | +-------+----------+------+-----+---------+----------------+ 2 rows in set (0.00 sec) mysql> SELECT COUNT(*) FROM geom; +----------+ | count(*) | +----------+ | 32376 | +----------+ 1 row in set (0.00 sec)
To add a spatial index on the column g
, use
this statement:
Press CTRL+C to copymysql> ALTER TABLE geom ADD SPATIAL INDEX(g); Query OK, 32376 rows affected (4.05 sec) Records: 32376 Duplicates: 0 Warnings: 0