MySQL can create spatial indexes using syntax similar to that
for creating regular indexes, but extended with the
SPATIAL
keyword. Currently, columns in
spatial indexes must be declared NOT NULL
.
The following examples demonstrate how to create spatial
indexes:
With CREATE TABLE
:
CREATE TABLE geom (g GEOMETRY NOT NULL, SPATIAL INDEX(g));
With ALTER TABLE
:
ALTER TABLE geom ADD SPATIAL INDEX(g);
With CREATE INDEX
:
CREATE SPATIAL INDEX sp_index ON geom (g);
For MyISAM
tables, SPATIAL
INDEX
creates an R-tree index. For nonspatial indexing
of spatial columns, MyISAM
tables creates a
B-tree index. A B-tree index on spatial values will be useful
for exact-value lookups, but not for range scans.
For more information on indexing spatial columns, see
Section 12.1.4, “CREATE INDEX
Syntax”.
To drop spatial indexes, use ALTER
TABLE
or DROP INDEX
:
With ALTER TABLE
:
ALTER TABLE geom DROP INDEX g;
With DROP INDEX
:
DROP INDEX sp_index 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.
mysql>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:
mysql> ALTER TABLE geom ADD SPATIAL INDEX(g);
Query OK, 32376 rows affected (4.05 sec)
Records: 32376 Duplicates: 0 Warnings: 0
User Comments
Creating spatial indexes returns an error if the data base type is innodb:
ERROR 1464 (HY000): The used table type doesn't support SPATIAL indexes
You can change the database type to myisam and this example will work by doing the following:
alter table geom engine=myisam;
Add your own comment.