SELECT Statements
A SELECT statement can consist of the following basic clauses.
SELECT
INTO
FROM
JOIN
WHERE
GROUP BY
HAVING
UNION
ORDER BY
LIMIT
SELECT Syntax
The following syntax diagram outlines the syntax supported by the SharePoint Excel Services adapter:
SELECT {
[ TOP <numeric_literal> ]
{
*
| {
<expression> [ [ AS ] <column_reference> ]
| { <table_name> | <correlation_name> } .*
} [ , ... ]
}
[ INTO csv:// [ filename= ] <file_path> [ ;delimiter=tab ] ]
{
FROM <table_reference> [ [ AS ] <identifier> ]
}
[ WHERE <search_condition> ]
[
ORDER BY
{ <column_reference> [ ASC | DESC ] } [ , ... ]
]
[
LIMIT <expression>
[
{ OFFSET | , }
<expression>
]
]
}
<expression> ::=
| <column_reference>
| @ <parameter>
| ?
| COUNT( * | { <expression> } )
| { AVG | MAX | MIN | SUM | COUNT } ( <expression> )
| <literal>
| <sql_function>
<search_condition> ::=
{
<expression> { = | > | < | >= | <= | LIKE | AND | OR } [ <expression> ]
} [ { AND | OR } ... ]
Examples
Return all columns:
SELECT * FROM Account
Rename a column:
SELECT "Name" AS MY_Name FROM Account
Search data:
SELECT * FROM Account WHERE Industry = 'Floppy Disks';
The SharePoint Excel Services APIs support the following operators in the WHERE clause: =, >, <, >=, <=, LIKE, AND, OR.
SELECT * FROM Account WHERE Industry = 'Floppy Disks';
Return the number of items matching the query criteria:
SELECT COUNT(*) AS MyCount FROM Account
Sort a result set in ascending order:
SELECT Id, Name FROM Account ORDER BY Name ASC
Predicate Functions
CEILING(value)
Returns the value rounded up to the nearest whole number (no decimal component).
expression: The value to round.
CONCAT(string_expr1, string_expr2)
Returns the string that is the concatenation of string_expr1 and string_expr2.
string_expr1: The first string to be concatenated.
string_expr2: The second string to be concatenated.
DAY(datetime_date)
Returns the integer that specifies the day component of the specified date.
datetime_date: The datetime string that specifies the date.
ENDSWITH(string_expression, string_suffix)
Returns true if string_expression ends with string_suffix, otherwise returns false.
string_expression: The string expression to search within.
string_suffix: The string suffix to search for.
FLOOR(value)
Returns the value rounded down to the nearest whole number (no decimal component).
value: The value to round.
HOUR(datetime_time)
Returns the integer that specifies the hour component of the specified time.
datetime_time: The datetime string that specifies the time.
INDEXOF(string_expression, string_search)
Returns the index location where string_search is contained within string_expression.
string_expression: The string expression to search within.
string_search: The search value to locate within string_expression.
LENGTH(string_expression)
Returns the number of characters of the specified string expression.
string_expression: The string expression.
MINUTE(datetime_time)
Returns the integer that specifies the minute component of the specified time.
datetime_time: The datetime string that specifies the time.
MONTH(datetime_date)
Returns the integer that specifies the month component of the specified date.
datetime_date: The datetime string that specifies the date.
REPLACE(string_expression, string_search, string_replace)
Returns the string after replacing any found string_search values with string_replace.
string_expression: The string expression to perform a replace on.
string_search: The string value to find within string_expression.
string_replace: The string value replace and string_search instances found.
ROUND(value)
Returns the value to the nearest whole number (no decimal component).
value: The value to round.
SECOND(datetime_time)
Returns the integer that specifies the second component of the specified time.
datetime_time: The datetime string that specifies the time.
STARTSWITH(string_expression, string_prefix)
Returns true if string_expression starts with string_prefix, otherwise returns false.
string_expression: The string expression to search within.
string_prefix: The string prefix to search for.
SUBSTRINGOF(string_expression, string_search)
Returns true if string_expression contains string_expression, otherwise returns false.
string_expression: The string expression to search within.
string_search: The value to search for.
TOLOWER(string_expression)
Returns the string_expression with the uppercase character data converted to lowercase.
string_expression: The string expression to lowercase.
TOUPPER(string_expression)
Returns the string_expression with the lowercase character data converted to uppercase.
string_expression: The string expression to uppercase.
TRIM(string_expression)
Returns the string_expression with the leading and trailing whitespace removed.
string_expression: The string expression to trim.
YEAR(datetime_date)
Returns the integer that specifies the year component of the specified date.
datetime_date: The datetime string that specifies the date.
SELECT INTO Statements
You can use the SELECT INTO statement to export formatted data to a file.
Data Export with an SQL Query
The following query exports data into a file formatted in comma-separated values (CSV):
SELECT Id, Name INTO "csv://Account.txt" FROM "Account" WHERE Industry = 'Floppy Disks'
You can specify other formats in the file URI. The possible delimiters are tab, semicolon, and comma with the default being comma. The following example exports tab-separated values:
SELECT Id, Name INTO "csv://Account.txt;delimiter=tab" FROM "Account" WHERE Industry = 'Floppy Disks'