File Geodatabase
SQL Reference
The File Geodatabase
supports a limited subset of the SQL 92 standard. This document is a
reference for the SQL clauses, functions and data types supported by the
File Geodatabase. |
Contents
SELECT
SELECT [ALL
| DISTINCT] select-list
FROM table-list
[WHERE search-condition]
[ORDER BY order_expression
[ ASC | DESC ] ]
[COLLATE [BIN | CASE | NOCASE]]
UPDATE
UPDATE tablename
SET columnname = {expression |
NULL}
[, columnname = {expression |
NULL}]...
[WHERE search-condition]
CREATE TABLE
CREATE TABLE
tablename
(column-definition [,
column-definition]...)
CREATE INDEX
CREATE
[UNIQUE] INDEX indexname ON tablename
(column [ASC | DESC] [, column [ASC | DESC]]...)
DROP TABLE
DROP TABLE tablename
DROP INDEX
DROP INDEX tablename.indexname
INSERT
INSERT INTO tablename [(columnname [, columnname]...)]
{ VALUES (value [, value]...) | sub-query }
ALTER TABLE
ALTER TABLE tablename
{ ADD [COLUMN] column-definition
| DROP [COLUMN] columnname
}
DELETE
DELETE FROM tablename [WHERE search_condition]
Subqueries
A subquery is a query nested within another query. It can be used to apply predicate or aggregate functions or to compare data with values stored in another table. This can be done with the IN or ANY keywords.
Subquery support is limited to the following:
· IN predicate. For example:
"COUNTRY_NAME" NOT
IN (SELECT "COUNTRY_NAME" FROM indep_countries)
· Scalar subqueries with comparison operators. A scalar subquery returns a single value. For example:
"GDP2006" >
(SELECT MAX("GDP2005") FROM countries)
For file geodatabases, the set functions AVG, COUNT, MIN, MAX, and SUM can only
be used within scalar subqueries.
· EXISTS predicate. For example:
EXISTS (SELECT * FROM indep_countries WHERE "COUNTRY_NAME" = 'Mexico')
Operators
The
following is the full list of supported operators.
Arithmetic operators
You use an arithmetic operator to add, subtract, multiply, and divide numeric
values.
Operator |
Description |
* |
Arithmetic operator for multiplication |
/ |
Arithmetic operator for division |
+ |
Arithmetic operator for addition |
- |
Arithmetic operator for subtraction |
Comparison operators
You use comparison operators to compare one expression to another.
Operator |
Description |
< |
Less than. Can be used with strings (comparison is based on alphabetical order), numbers, and dates. |
<= |
Less than or equal to. Can be used with strings (comparison is based on alphabetical order), numbers, and dates. |
<> |
Not equal to. Can be used with strings (comparison is based on alphabetical order), numbers, and dates. |
> |
Greater than. Can be used with strings (comparison is based on alphabetical order), numbers, and dates. |
>= |
Greater than or equal to. Can be used with strings (comparison is based on alphabetical order), numbers, and dates. For example, this query selects all the cities with names starting with the letters M to Z: "CITY_NAME"
>= 'M' |
[NOT] BETWEEN x AND y |
Selects a record if it has a value greater than or equal to x and less than or equal to y. When preceded by NOT, it selects a record if it has a value outside the specified range. For example, this expression selects all records with a value greater than or equal to 1 and less than or equal to 10: "OBJECTID"
BETWEEN 1 AND 10
"OBJECTID" >=
1 AND OBJECTID <= 10
|
[NOT] EXISTS |
Returns TRUE if the subquery returns at least one record; otherwise, it returns FALSE. For example, this expression returns TRUE if the OBJECTID field contains a value of 50: EXISTS (SELECT * FROM
parcels WHERE "OBJECTID" = 50)
|
[NOT] IN |
Selects a record if it has one of several strings or values in a field. When preceded by NOT, it selects a record if it doesn't have one of several strings or values in a field. For example, this expression searches for four different state names: "STATE_NAME" IN
('Alabama', 'Alaska', 'California', 'Florida')
"STATE_NAME" IN
(SELECT "STATE_NAME" FROM states WHERE "POP" >
5000000) |
IS [NOT] NULL |
Selects a record if it has a null value for the specified field. When NULL is preceded by NOT, it selects a record if it has any value for the specified field. For example, this expression selects all records with a null value for population: "POPULATION" IS
NULL |
x [NOT] LIKE y [ESCAPE 'escape-character'] |
Use the LIKE operator (instead of the = operator) with wildcards to build a partial string search. For example, this expression selects Mississippi and Missouri among USA state names: "STATE_NAME"
LIKE 'Miss%'
"OWNER_NAME"
LIKE '_atherine Smith'
CAST
("SCORE_INT" AS VARCHAR) LIKE '8%'
"AMOUNT" LIKE
'%10$%%' ESCAPE '$'
|
Logical operators
Operator |
Description |
AND |
Combines two conditions together. Selects a record if both conditions are true. For example, the following expression selects any house with more than 1,500 square feet and a garage for more than two cars: "AREA" > 1500
AND "GARAGE" > 2 |
OR |
Combines two conditions together. Selects a record if at least one condition is true. For example, the following expression selects any house with more than 1,500 square feet or a garage for more than two cars: "AREA" > 1500
OR "GARAGE" > 2 |
NOT |
Selects a record if it doesn't match the following expression. For example, the following expression selects all states but California. NOT "STATE_NAME"
= 'California' |
The
following is the full list of supported functions.
Date functions
Function |
Description |
CURRENT_DATE |
Returns the current date. |
CURRENT_TIME |
Returns the current time. |
CURRENT_TIMESTAMP |
Returns the current date and time. |
EXTRACT(extract_field FROM extract_source) |
Returns the extract_field portion of the extract_source. The extract_source argument is a date-time expression. The extract_field argument can be one of the following keywords: YEAR, MONTH, DAY, HOUR, MINUTE, or SECOND. |
String functions
Arguments denoted as string_exp can be the name
of a column, a character-string-literal, or the result of another scalar
function where the underlying data type can be represented as a character type.
Arguments denoted as character_exp are
variable-length character strings.
Arguments denoted as start or length can be a numeric-literal or
the result of another scalar function, where the underlying data type can be
represented as a numeric type.
These string functions are 1-based; that is, the first character in the string
is character 1.
Function |
Description |
CHAR_LENGTH(string_exp) |
Returns the length in characters of the string expression. |
CONCAT(string_exp1, string_exp2) |
Returns a character string that is the result of concatenating string_exp2 to string_exp1. |
LOWER(string_exp) |
Returns a string equal to that in string_exp, with all uppercase characters converted to lowercase. |
POSITION(character_exp IN character_exp) |
Returns the position of the first character expression in the second character expression. The result is an exact numeric with an implementation-defined precision and a scale of zero. |
SUBSTRING(string_exp FROM start FOR length) |
Returns a character string that is derived from string_exp, beginning at the character position specified by start for length characters. |
TRIM(BOTH | LEADING | TRAILING trim_character FROM string_exp) |
Returns the string_exp with the trim_character removed from the leading, trailing, or both ends of the string. |
UPPER(string_exp) |
Returns a string equal to that in string_exp, with all lowercase characters converted to uppercase. |
Numeric functions
All numeric functions return a numeric value.
Arguments denoted as numeric_exp, float_exp, or integer_exp
can be the name of a column, the result of another scalar function, or a
numeric-literal, where the underlying data type could be represented as a
numeric type.
Function |
Description |
ABS(numeric_exp) |
Returns the absolute value of numeric_exp. |
ACOS(float_exp) |
Returns the arccosine of float_exp as an angle, expressed in radians. |
ASIN(float_exp) |
Returns the arcsine of float_exp as an angle, expressed in radians. |
ATAN(float_exp) |
Returns the arctangent of float_exp as an angle, expressed in radians. |
CEILING(numeric_exp) |
Returns the smallest integer greater than or equal to numeric_exp. |
COS(float_exp) |
Returns the cosine of float_exp, where float_exp is an angle expressed in radians. |
FLOOR(numeric_exp) |
Returns the largest integer less than or equal to numeric_exp. |
LOG(float_exp) |
Returns the natural logarithm of float_exp. |
LOG10(float_exp) |
Returns the base 10 logarithm of float_exp. |
MOD(integer_exp1, integer_exp2) |
Returns the remainder of integer_exp1 divided by integer_exp2. |
POWER(numeric_exp, integer_exp) |
Returns the value of numeric_exp to the power of integer_exp. |
ROUND(numeric_exp, integer_exp) |
Returns numeric_exp rounded to integer_exp places to the right of the decimal point. If integer_exp is negative, numeric_exp is rounded to |integer_exp| places to the left of the decimal point. |
SIGN(numeric_exp) |
Returns an indicator of the sign of numeric_exp. If numeric_exp is less than zero, -1 is returned. If numeric_exp equals zero, 0 is returned. If numeric_exp is greater than zero, 1 is returned. |
SIN(float_exp) |
Returns the sine of float_exp, where float_exp is an angle expressed in radians. |
TAN(float_exp) |
Returns the tangent of float_exp, where float_exp is an angle expressed in radians. |
TRUNCATE(numeric_exp, integer_exp) |
Returns numeric_exp truncated to integer_exp places to the right of the decimal point. If integer_exp is negative, numeric_exp is truncated to |integer_exp| places to the left of the decimal point. |
The CAST function
The CAST function converts a value to a specified data type. The syntax is as
follows:
CAST(exp AS data_type)
The argument exp can be the name of a
column, the result of another scalar function, or a literal. Data_type can be any of the following keywords which
can be specified in upper- or lowercase: CHAR, VARCHAR, INTEGER, SMALLINT,
REAL, DOUBLE, DATE, TIME, DATETIME, NUMERIC, or DECIMAL.
To
specify a field in a SQL expression, you only need to provide a delimiter if
the field name would otherwise be ambiguous, such as if it were the same as a
SQL reserved keyword. Since there are many reserved keywords and new ones can
be added in subsequent releases, a good practice is to always enclose a field
name with a delimiter.
You can enclose field names in double quotes:
"AREA"
Strings
Strings must always be enclosed in single quotes in queries. For example:
STATE_NAME = 'California'
Strings are case sensitive in expressions for feature classes and tables. For these feature classes and tables, you can use the UPPER or LOWER function to set the case for a selection. For example:
UPPER("STATE_NAME") =
'RHODE ISLAND'
The wildcards you use to conduct a partial string search also
depends on the data source you are querying. For example, in a file-based or
multiuser geodatabase data source, this expression would select Mississippi and
Missouri among USA state names:
"STATE_NAME" LIKE 'Miss%'
% means that anything is acceptable in its place: one character, a hundred characters,
or no character. The wildcards you use to query personal geodatabases are * for
any number of characters and ? for
one character.
String functions can be used to format strings. For instance, the LEFT function
would return a certain number of characters starting on the left of the string.
In this example, the query would return all the states starting with the letter
A:
LEFT("STATE_NAME",1) =
'A'
Numbers
The
decimal point (.) is always used as the decimal delimiter, regardless of your
regional settings. The comma cannot be used as a decimal or thousands delimiter
in an expression.
You can query numbers using the equal (=), not equal (<>), greater than
(>), less than (<), greater than or equal to (>=), less than or equal
to (<=), and BETWEEN operators. For example:
"POPULATION" >=
5000
Numeric functions can be used to format numbers. For instance, the ROUND
function would round a number to a given number of decimals in a file
geodatabase:
ROUND("SQKM",0) = 500
Dates
General
rules
Dates are stored in a date-time field supporting the storage of both date and
time information. Therefore, most of the query syntax listed below contains a
reference to the time. The time part of the query may be safely omitted when
the field is known to contain only dates.
The main purpose of the ArcMap date format is to store dates, not times. It is
possible to store only a time in the field when the underlying database
actually uses a date-time field, but it is not recommended. Querying against
time is a bit awkward; for instance, 12:30:05 p.m. will be stored as
'1899-12-30 12:30:05'.
Dates
are stored as a reference to December 30, 1899, at 00:00:00.
The purpose of this section is only to help you query against dates, not time
values. When a non-null time is stored with the dates (for instance, January
12, 1999, 04:00:00), querying against the date only will not return the record
because when you pass only a date to a date-time field, it will fill the time
with zeros and retrieve only the records where the time is 12:00:00 a.m.
Dates in are preceded with "date".
"Datefield"
= date 'yyyy-mm-dd'
File geodatabases support the use of a time in the date field, so this can be
added to the expression:
"Datefield"
= date 'yyyy-mm-dd hh:mm:ss'
INTEGER
(supported synonym: "INT")
SMALLINT
NUMERIC - must specify PRECISION. SCALE is optional
DECIMAL - must specify PRECISION. SCALE is optional
REAL
DOUBLE
PRECISION
FLOAT - can
specify optional PRECISION. SCALE not supported
CHAR (supported
synonym: "CHARACTER") - must specify
LENGTH
VARCHAR - must specify LENGTH
DATE
TIME
TIMESTAMP
OBJECTID
VARBINARY
(supported synonym: "BINARY")
GUID
GLOBALID
XML
BNF Notation
Things in “( )” are required; those in “[ ]”
are optional.
data-type ::= character-string-type
| exact-numeric-type
| approximate-numeric-type
| datetime-type
| binary-type
character-string-type ::= CHAR ( length )
| VARCHAR (
length )
exact-numeric-type ::= INTEGER | INT
| SMALLINT
| NUMERIC ( precision [, scale] )
| DECIMAL ( precision [, scale] )
approximate-numeric-type ::= REAL | DOUBLE PRECISION |
FLOAT [( precision )]
datetime-type ::= DATE |
TIME | TIMESTAMP
binary-type
::= BINARY | VARBINARY
SQL Data Type |
Mapping |
INTEGER,
INT |
Long
Integer |
SMALLINT |
Short
Integer |
NUMERIC |
Float, Double
depending on scale |
DECIMAL |
Float,
Double depending on scale |
REAL |
Float |
DOUBLE
PRECISION |
Double |
FLOAT |
Float,
Double depending on scale |
CHAR,
CHARACTER |
Text |
VARCHAR |
Text |
DATE |
Date |
TIME |
Date |
TIMESTAMP |
Date |
OBJECTID |
Object ID |
VARBINARY,
BINARY |
Blob |
GUID |
Guid |
GLOBALID
Global ID |
|
XML |
XML |
Note
that a syntactic construct enclosed by "{" and "}"
indicates a required
element, while the use of "[" and "]" indicates
an optional element.
SQL Statements
statement ::= alter-table-statement
| create-index-statement
| create-table-statement
| delete-statement
| drop-index-statement
| drop-table-statement
| insert-statement
| select-statement
| update-statement
alter-table-statement ::= ALTER TABLE tablename
{ ADD [COLUMN] column-definition
| DROP [COLUMN] columnname
}
create-index-statement ::= CREATE [UNIQUE] INDEX indexname ON tablename
(column [ASC | DESC] [, column [ASC | DESC]]...)
create-table-statement ::= CREATE TABLE tablename
(column-definition [, column-definition]...)
delete-statement ::= DELETE FROM tablename
[WHERE search_condition]
drop-index-statement ::= DROP INDEX tablename.indexname
drop-table-statement ::= DROP TABLE tablename
insert-statement ::= INSERT INTO tablename
[(columnname [, columnname]...)]
{ VALUES (value [, value]...) | sub-query }
select-statement ::= SELECT [ALL | DISTINCT]
select-list
FROM table-list
[WHERE search-condition]
[ORDER BY columnname [, columnname]...]
update-statement ::= UPDATE tablename
SET
columnname = {expression | NULL}
[, columnname = {expression | NULL}]...
[WHERE search-condition]
Elements used in SQL Statements
table ::= tablename [[AS] correlationname]
where ::= search-condition
search-condition ::= boolean-term
| boolean-term OR search-condition
boolean-term
::= boolean-factor | boolean-factor
AND boolean-term
boolean-factor
::= [NOT] boolean-primary
boolean-primary ::=
predicate | ( search-condition )
predicate ::= colref IS [NOT] NULL |
expression [NOT] LIKE pattern [ESCAPE
'escape-character'] |
expression [NOT] IN ( value [, value]... ) |
expression [NOT] IN ( sub-query ) |
expression comparison-operator expression |
expression [NOT] BETWEEN expression AND expression |
EXISTS ( sub-query )
comparison-operator ::= = | <> | < | > |
<= | >=
expression ::= term | expression { + | - } term
term ::= factor |
term { * | / } factor
factor ::= [ + | - ] primary
primary ::= ( expression ) | colref | literal | function | ( sub-query ) | parameter
function ::= functionname
( expression [, expression]... )
literal ::= character-string-literal
| numeric-literal | date-time-literal
null ::= NULL
parameter ::= ?
column ::= [qualifier.] columnname
valuelist ::= value [,
value]...
select-list ::= * | select-sublist [, select-sublist]...
select-sublist ::= expression [[AS] column-alias] | {table-name |
correlation-name}.*
orderby
::= ORDER BY sort_specification [, sort_specification]...
sort_specification ::= column-name [ASC | DESC]
character-string-literal ::= '{character}...'
numeric-literal
::=
date-time-literal
::= DATE 'yyyy-mm-dd hh:mm:ss.ss'
identifier ::=
keyword ::=
column-definition ::= column-name data-type [DEFAULT
default-value] [[NOT] NULL]
data-type ::= character-string-type
| exact-numeric-type
| approximate-numeric-type
| datetime-type
| binary-type
character-string-type ::= CHAR ( length )
| VARCHAR ( length )
exact-numeric-type ::= INTEGER | INT
| SMALLINT
| NUMERIC ( precision [, scale] )
| DECIMAL ( precision [, scale] )
approximate-numeric-type ::= REAL | DOUBLE PRECISION | FLOAT [( precision )]
datetime-type ::= DATE | TIME |
TIMESTAMP
binary-type ::= BINARY | VARBINARY
default-value ::= literal | NULL
Order By
SELECT State_name FROM States ORDER BY State_name
Order By using Collate
BINARY
SELECT Names FROM States ORDER BY
Names COLLATE BINARY
CASESENSITIVE
SELECT Names FROM States ORDER BY
Names COLLATE CASESENSITIVE
NOCASESENSITIVE
SELECT Names FROM States ORDER BY
Names COLLATE NOCASESENSITIVE
Operators
BETWEEN
SELECT
Names FROM States WHERE OBJECTID BETWEEN 1 AND 10
Functions
CAST
SELECT State_name
FROM States CAST (STATE_FIPS AS INTEGER) = 27