TSQL - make a literal float value
is that literal a floating point literal? Or is it really a decimal literal that gets converted later?
If my literal is not a floating point literal, what is the syntax for making a floating point literal?
The 0.867153569942739
literal in SQL Server is a decimal
type, not float
.
The engine automatically picks appropriate scale and precision to represent the given literal.
To write a literal of the float
type you should use the scientific notation, like this:
0.867153569942739E0
This is documented in Constants (Transact-SQL)
decimal constants
decimal constants are represented by a string of numbers that are not enclosed in quotation marks and contain a decimal point. The following are examples of decimal constants:
1894.1204 2.0
float and real constants
float and real constants are represented by using scientific notation. The following are examples of float or real values:
101.5E5 0.5E-2
The sp_describe_first_result_set
can tell us the types of columns
EXEC sp_describe_first_result_set N'SELECT 0.867153569942739, 0.867153569942739E0'
It returns numeric(15,15)
for the first column and float
for the second.
If your column RandomGrouping
is indexed, it is much more efficient to use a float
literal, because when you wrap RandomGrouping
in convert()
, an index can't be used.
The following query will use an index:
SELECT *
FROM MyTable
WHERE RandomGrouping = 0.867153569942739E0
The following query will not use an index:
SELECT *
FROM MyTable
WHERE convert(binary(8), RandomGrouping) = @Y