Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register todayThis browser is no longer supported.
Upgrade to Microsoft Edge to take advantage of the latest features, security updates, and technical support.
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
SQL database in Microsoft Fabric
A combination of symbols and operators that the SQL Server Database Engine evaluates to obtain a single data value. Simple expressions can be a single constant, variable, column, or scalar function. Operators can be used to join two or more simple expressions into a complex expression.
Transact-SQL syntax conventions
Syntax for SQL Server and Azure SQL Database.
{ constant | scalar_function | [ table_name. ] column | variable
| ( expression ) | ( scalar_subquery )
| { unary_operator } expression
| expression { binary_operator } expression
| ranking_windowed_function | aggregate_windowed_function
}
Syntax for Azure Synapse Analytics and Parallel Data Warehouse.
-- Expression in a SELECT statement
<expression> ::=
{
constant
| scalar_function
| column
| variable
| ( expression )
| { unary_operator } expression
| expression { binary_operator } expression
}
[ COLLATE Windows_collation_name ]
-- Scalar Expression in a DECLARE , SET , IF...ELSE , or WHILE statement
<scalar_expression> ::=
{
constant
| scalar_function
| variable
| ( expression )
| (scalar_subquery )
| { unary_operator } expression
| expression { binary_operator } expression
}
[ COLLATE [ Windows_collation_name ] ]
A symbol that represents a single, specific data value. For more information, see Constants.
A unit of Transact-SQL syntax that provides a specific service and returns a single value. scalar_function can be built-in scalar functions, such as the SUM
, GETDATE()
, or CAST
functions, or scalar user-defined functions.
The name or alias of a table.
The name of a column. Only the name of the column is allowed in an expression.
The name of a variable, or parameter. For more information, see DECLARE @local_variable.
Any valid expression as defined in this article. The parentheses are grouping operators that make sure that all the operators in the expression within the parentheses are evaluated before the resulting expression is combined with another.
A subquery that returns one value. For example:
SELECT MAX(UnitPrice)
FROM Products;
Unary operators can be applied only to expressions that evaluate to any one of the data types of the numeric data type category. Is an operator that has only one numeric operand:
+
indicates a positive number-
indicates a negative number~
indicates the one's complement operatorAn operator that defines the way two expressions are combined to yield a single result. binary_operator can be an arithmetic operator, the assignment operator (=
), a bitwise operator, a comparison operator, a logical operator, the string concatenation operator (+
), or a unary operator. For more information about operators, see Operators.
Any Transact-SQL ranking function. For more information, see Ranking Functions.
Any Transact-SQL aggregate function with the OVER clause. For more information, see SELECT - OVER clause.
For a simple expression made up of a single constant, variable, scalar function, or column name: the data type, collation, precision, scale, and value of the expression is the data type, collation, precision, scale, and value of the referenced element.
When two expressions are combined by using comparison or logical operators, the resulting data type is Boolean and the value is either: TRUE
, FALSE
, or UNKNOWN
. For more information about Boolean data types, see Comparison Operators.
When two expressions are combined by using arithmetic, bitwise, or string operators, the operator determines the resulting data type.
Complex expressions made up of many symbols and operators evaluate to a single-valued result. The data type, collation, precision, and value of the resulting expression is determined by combining the component expressions, two at a time, until a final result is reached. The sequence in which the expressions are combined is defined by the precedence of the operators in the expression.
Two expressions can be combined by an operator if they both have data types supported by the operator, and at least one of these conditions is true:
The expressions have the same data type.
The data type with the lower precedence can be implicitly converted to the data type with the higher data type precedence.
If the expressions don't meet these conditions, the CAST
or CONVERT
functions can be used. Use CAST
or CONVERT
to explicitly convert the data type with the lower precedence to either the data type with the higher precedence or to an intermediate data type that can be implicitly converted to the data type with the higher precedence.
If there's no supported implicit or explicit conversion, the two expressions can't be combined.
The collation of any expression that evaluates to a character string is set by following the rules of collation precedence. For more information, see Collation precedence.
In a programming language such as C or Microsoft Visual Basic, an expression always evaluates to a single result. Expressions in a Transact-SQL select list follow a variation on this rule: The expression is evaluated individually for each row in the result set. A single expression can have a different value in each row of the result set, but each row has only one value for the expression. For example, in the following SELECT
statement both the reference to ProductID
and the term 1+2
in the select list are expressions:
USE AdventureWorks2022;
GO
SELECT ProductID, 1 + 2
FROM Production.Product;
GO
The expression 1+2
evaluates to 3
in each row in the result set. Although the expression ProductID
generates a unique value in each result set row, each row only has one value for ProductID
.
DELETE
FROM dbo.MyTable
WHERE (c1 = '0000001' AND c2 = 'A000001')
OR (c1 = '0000002' AND c2 = 'A000002')
OR (c1 = '0000003' AND c2 = 'A000003')
/* ... additional, similar expressions omitted for simplicity */
Change this query to:
DELETE FROM dbo.MyTable WHERE (c1 = '0000001' AND c2 = 'A000001');
DELETE FROM dbo.MyTable WHERE (c1 = '0000002' AND c2 = 'A000002');
DELETE FROM dbo.MyTable WHERE (c1 = '0000003' AND c2 = 'A000003');
/* ... refactored, individual DELETE statements omitted for simplicity */
Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register today