= (Equals) (Transact-SQL)
Compares the equality of two expressions (a comparison operator) in SQL Server 2012.
Transact-SQL Syntax Conventions
Syntax
expression = expression
Arguments
- expression
Is any valid expression. If the expressions are not of the same data type, the data type for one expression must be implicitly convertible to the data type of the other. The conversion is based on the rules of data type precedence.
Result Types
Boolean
Remarks
When you compare two NULL expressions, the result depends on the ANSI_NULLS setting:
If ANSI_NULLS is set to ON, the result is NULL, following the ANSI convention that a NULL (or unknown) value is not equal to another NULL or unknown value.
If ANSI_NULLS is set to OFF, the result of NULL compared to NULL is TRUE.
Comparing NULL to a non-NULL value always results in FALSE. For more information, see SET ANSI_NULLS (Transact-SQL).
Examples
A. Using = in a simple query
The following example uses the Equals operator to return all rows in the HumanResources.Department table in which the value in the GroupName column is equal to the word 'Manufacturing'.
USE AdventureWorks2012;
GO
SELECT DepartmentID, Name
FROM HumanResources.Department
WHERE GroupName = 'Manufacturing';
Here is the result set.
DepartmentID Name
------------ --------------------------------------------------
7 Production
8 Production Control
(2 row(s) affected)
B. Comparing NULL and non-NULL values
The following example uses the Equals (=) and Not Equal To (<>) comparison operators to make comparisons with NULL and nonnull values in a table. The example also shows that IS NULL is not affected by the SET ANSI_NULLS setting.
-- Create table t1 and insert 3 rows.
CREATE TABLE dbo.t1 (a INT NULL);
INSERT INTO dbo.t1 VALUES (NULL),(0),(1);
GO
-- Print message and perform SELECT statements.
PRINT 'Testing default setting';
DECLARE @varname int;
SET @varname = NULL;
SELECT a
FROM t1
WHERE a = @varname;
SELECT a
FROM t1
WHERE a <> @varname;
SELECT a
FROM t1
WHERE a IS NULL;
GO
-- SET ANSI_NULLS to ON and test.
PRINT 'Testing ANSI_NULLS ON';
SET ANSI_NULLS ON;
GO
DECLARE @varname int;
SET @varname = NULL
SELECT a
FROM t1
WHERE a = @varname;
SELECT a
FROM t1
WHERE a <> @varname;
SELECT a
FROM t1
WHERE a IS NULL;
GO
-- SET ANSI_NULLS to OFF and test.
PRINT 'Testing SET ANSI_NULLS OFF';
SET ANSI_NULLS OFF;
GO
DECLARE @varname int;
SET @varname = NULL;
SELECT a
FROM t1
WHERE a = @varname;
SELECT a
FROM t1
WHERE a <> @varname;
SELECT a
FROM t1
WHERE a IS NULL;
GO
-- Drop table t1.
DROP TABLE dbo.t1;
Here is the result set.
Testing default setting
a
-----------
NULL
(1 row(s) affected)
a
-----------
0
1
(2 row(s) affected)
a
-----------
NULL
(1 row(s) affected)
Testing ANSI_NULLS ON
a
-----------
(0 row(s) affected)
a
-----------
(0 row(s) affected)
a
-----------
NULL
(1 row(s) affected)
Testing SET ANSI_NULLS OFF
a
-----------
NULL
(1 row(s) affected)
a
-----------
0
1
(2 row(s) affected)
a
-----------
NULL
(1 row(s) affected)