Search condition (Transact-SQL)
Applies to: SQL Server Azure SQL Database Azure SQL Managed Instance Azure Synapse Analytics Analytics Platform System (PDW) SQL analytics endpoint in Microsoft Fabric Warehouse in Microsoft Fabric
A combination of one or more predicates that use the logical operators AND
, OR
, and NOT
.
Transact-SQL syntax conventions
Syntax
Syntax for SQL Server, Azure SQL Database, and Azure SQL Managed Instance.
<search_condition> ::=
MATCH (<graph_search_pattern>) | <search_condition_without_match> | <search_condition> AND <search_condition>
<search_condition_without_match> ::=
{ [ NOT ] <predicate> | ( <search_condition_without_match> ) }
[ { AND | OR } [ NOT ] { <predicate> | ( <search_condition_without_match> ) } ]
[ ...n ]
<predicate> ::=
{ expression { = | <> | != | > | >= | !> | < | <= | !< } expression
| string_expression [ NOT ] LIKE string_expression
[ ESCAPE 'escape_character' ]
| expression [ NOT ] BETWEEN expression AND expression
| expression IS [ NOT ] NULL
| expression IS [ NOT ] DISTINCT FROM
| CONTAINS
( { column | * } , '<contains_search_condition>' )
| FREETEXT ( { column | * } , 'freetext_string' )
| expression [ NOT ] IN ( subquery | expression [ , ...n ] )
| expression { = | < > | != | > | >= | ! > | < | <= | ! < }
{ ALL | SOME | ANY } ( subquery )
| EXISTS ( subquery ) }
<graph_search_pattern> ::=
{ <node_alias> {
{ <-( <edge_alias> )- }
| { -( <edge_alias> )-> }
<node_alias>
}
}
<node_alias> ::=
node_table_name | node_table_alias
<edge_alias> ::=
edge_table_name | edge_table_alias
Syntax for Azure Synapse Analytics and Parallel Data Warehouse.
< search_condition > ::=
{ [ NOT ] <predicate> | ( <search_condition> ) }
[ { AND | OR } [ NOT ] { <predicate> | ( <search_condition> ) } ]
[ ...n ]
<predicate> ::=
{ expression { = | <> | != | > | >= | < | <= } expression
| string_expression [ NOT ] LIKE string_expression
| expression [ NOT ] BETWEEN expression AND expression
| expression IS [ NOT ] NULL
| expression [ NOT ] IN (subquery | expression [ , ...n ] )
| expression [ NOT ] EXISTS (subquery)
}
Arguments
<search_condition>
Specifies the conditions for the rows returned in the result set for a SELECT
statement, query expression, or subquery. For an UPDATE
statement, specifies the rows to be updated. For a DELETE
statement, specifies the rows to be deleted. There's no limit to the number of predicates that can be included in a Transact-SQL statement search condition.
<graph_search_pattern>
Specifies the graph match pattern. For more information about the arguments for this clause, see MATCH
NOT
Negates the Boolean expression specified by the predicate. For more information, see NOT.
AND
Combines two conditions and evaluates to TRUE
when both of the conditions are TRUE
. For more information, see AND.
OR
Combines two conditions and evaluates to TRUE
when either condition is TRUE
. For more information, see OR.
<predicate>
An expression that returns TRUE
, FALSE
, or UNKNOWN
. For more information, see Predicates.
expression
Specifies a column name, a constant, a function, a variable, a scalar subquery, or any combination of column names, constants, and functions connected by an operator or operators, or a subquery. The expression can also contain the CASE
expression.
Non-Unicode string constants and variables use the code page that corresponds to the default collation of the database. Code page conversions can occur when working with only non-Unicode character data and referencing the non-Unicode character data types char, varchar, and text. SQL Server converts non-Unicode string constants and variables to the code page that corresponds to the collation of the referenced column or specified using COLLATE
, if that code page is different than the code page that corresponds to the default collation of the database. Any characters not found in the new code page are translated to a similar character if a best-fit mapping can be found, or else are converted to the default replacement character of ?
.
When you work with multiple code pages, character constants can be prefixed with the uppercase letter N
, and Unicode variables can be used, to avoid code page conversions.
=
operator
The operator used to test the equality between two expressions.
<>
operator
The operator used to test the condition of two expressions not being equal to each other.
!=
operator
The operator used to test the condition of two expressions not being equal to each other.
>
operator
The operator used to test the condition of one expression being greater than the other.
>=
operator
The operator used to test the condition of one expression being greater than or equal to the other expression.
!>
operator
The operator used to test the condition of one expression not being greater than the other expression.
<
operator
The operator used to test the condition of one expression being less than the other.
<=
operator
The operator used to test the condition of one expression being less than or equal to the other expression.
!<
operator
The operator used to test the condition of one expression not being less than the other expression.
string_expression
A string of characters and wildcard characters.
[ NOT ] LIKE
Indicates that the subsequent character string is to be used with pattern matching. For more information, see LIKE.
ESCAPE 'escape_ character'
Allows for a wildcard character to be searched for in a character string instead of functioning as a wildcard. escape_character is the character that is put in front of the wildcard character to indicate this special use.
[ NOT ] BETWEEN
Specifies an inclusive range of values. Use AND
to separate the starting and ending values. For more information, see BETWEEN.
IS [ NOT ] NULL
Specifies a search for null values, or for values that aren't null, depending on the keywords used. An expression with a bitwise or arithmetic operator evaluates to NULL
if any one of the operands is NULL
.
IS [ NOT ] DISTINCT FROM
Compares the equality of two expressions and guarantees a true or false result, even if one or both operands are NULL
. For more information, see IS [NOT] DISTINCT FROM (Transact-SQL).
CONTAINS
Searches columns that contain character-based data for precise or less precise (fuzzy) matches to single words and phrases, the proximity of words within a certain distance of one another, and weighted matches. This option can only be used with SELECT
statements. For more information, see CONTAINS.
FREETEXT
Provides a simple form of natural language query by searching columns that contain character-based data for values that match the meaning instead of the exact words in the predicate. This option can only be used with SELECT
statements. For more information, see FREETEXT.
[ NOT ] IN
Specifies the search for an expression, based on whether the expression is included in or excluded from a list. The search expression can be a constant or a column name, and the list can be a set of constants or, more typically, a subquery. Enclose the list of values in parentheses. For more information, see IN.
subquery
Can be considered a restricted SELECT
statement and is similar to <query_expression>
in the SELECT
statement. The ORDER BY
clause and the INTO
keyword aren't allowed. For more information, see SELECT.
ALL
Used with a comparison operator and a subquery. Returns TRUE
for <predicate>
when all values retrieved for the subquery satisfy the comparison operation, or FALSE
when not all values satisfy the comparison or when the subquery returns no rows to the outer statement. For more information, see ALL.
{ SOME | ANY }
Used with a comparison operator and a subquery. Returns TRUE
for <predicate>
when any value retrieved for the subquery satisfies the comparison operation, or FALSE
when no values in the subquery satisfy the comparison or when the subquery returns no rows to the outer statement. Otherwise, the expression is UNKNOWN
. For more information, see SOME | ANY.
EXISTS
Used with a subquery to test for the existence of rows returned by the subquery. For more information, see EXISTS.
Remarks
The order of precedence for the logical operators is NOT
(highest), followed by AND
, followed by OR
. Parentheses can be used to override this precedence in a search condition. The order of evaluation of logical operators can vary depending on choices made by the query optimizer. For more information about how the logical operators operate on logic values, see AND, OR, and NOT.
Examples
The Transact-SQL code samples in this article use the AdventureWorks2022
or AdventureWorksDW2022
sample database, which you can download from the Microsoft SQL Server Samples and Community Projects home page.
A. Use WHERE with LIKE and ESCAPE syntax
The following example searches for the rows in which the LargePhotoFileName
column has the characters green_
, and uses the ESCAPE
option because _
is a wildcard character. If you don't specify the ESCAPE
option, the query searches for any description values that contain the word green
followed by any single character other than the _
character.
USE AdventureWorks2022;
GO
SELECT *
FROM Production.ProductPhoto
WHERE LargePhotoFileName LIKE '%greena_%' ESCAPE 'a';
B. Use WHERE and LIKE syntax with Unicode data
The following example uses the WHERE
clause to retrieve the mailing address for any company that is outside the United States (US
) and in a city whose name starts with Pa
.
USE AdventureWorks2022;
GO
SELECT AddressLine1,
AddressLine2,
City,
PostalCode,
CountryRegionCode
FROM Person.Address AS a
INNER JOIN Person.StateProvince AS s
ON a.StateProvinceID = s.StateProvinceID
WHERE CountryRegionCode NOT IN ('US')
AND City LIKE N'Pa%';
Examples: Azure Synapse Analytics and Analytics Platform System (PDW)
C. Use WHERE with LIKE
The following example searches for the rows in which the LastName
column has the characters and
.
-- Uses AdventureWorks
SELECT EmployeeKey,
LastName
FROM DimEmployee
WHERE LastName LIKE '%and%';
D. Use WHERE and LIKE syntax with Unicode data
The following example uses the WHERE
clause to perform a Unicode search on the LastName
column.
-- Uses AdventureWorks
SELECT EmployeeKey,
LastName
FROM DimEmployee
WHERE LastName LIKE N'%and%';