Implicit data type conversions are possible in SQL implementations. For example, if a smallint is compared to an int in T-SQL, the smallint is implicitly converted to int before the comparison proceeds. See BOL for details about implicit and explicit conversions in MS SQL Server.
Example. Find the average price of laptops with the prefix text "Average price = ".
If you run the query
SELECT 'Average price = ' + AVG(price) FROM laptop; |
SELECT 'Average price = ' + CAST(AVG(price) AS CHAR(15)) FROM laptop; |
Average price = 1410.44 |
CAST(<expression> AS <data type>)
Firstly, it should be noted that some data type conversions are not supported.
(SQL-92 Standard involves the table of allowed conversions). Secondly, NULL-value is converted into
NULL-value also.
Let us consider another example: Define the average launching year
from the Ships table. The query
SELECT AVG(launched) FROM ships; |
SELECT CAST(AVG(launched) AS NUMERIC(6,2)) FROM ships; |
SELECT AVG(CAST(launched AS NUMERIC(6,2))) FROM ships; |
SELECT CAST(AVG(CAST(launched AS NUMERIC(6,2))) AS NUMERIC(6,2)) FROM ships; |
SELECT CAST(AVG(launched*1.0) AS NUMERIC(6,2)) FROM ships; |
SELECT CONVERT(NUMERIC(6,2),AVG(launched*1.0)) FROM ships; |
CONVERT (<data type>[(<length>)], <expression> [, <style>])
The main distinction of the CONVERT function from the CAST statement is that the first allows formatting data (for example, temporal data of datetime type) when converting them to character data and specifying the format when converting character data to datetime. The values of integer optional argument style correspond to different formats. Let us consider the following example
SELECT CONVERT(char(25),CONVERT(datetime,'20030722')); |
Jul 22 2003 12:00AM |
style | format |
1 | 07/22/03 |
11 | 03/07/22 |
3 | 22/07/03 |
121 | 2003-07-22 00:00:00.000 |
Let the list of all the models of PC is required along with their prices.
Besides that, if the model is not on sale (not in PC table), in the place of price
must be the text "Not available".
The list of all the PC models with its prices we can obtain running the query:
SELECT DISTINCT product.model, price FROM product LEFT JOIN pc c
ON product.model=c.model WHERE product.type='pc'; |
model | price |
1121 | 850 |
1232 | 350 |
1232 | 400 |
1232 | 600 |
1233 | 600 |
1233 | 950 |
1233 | 980 |
1260 | 350 |
2111 | NULL |
2112 | NULL |
SELECT DISTINCT product.model,
CASE WHEN price IS NULL THEN 'Not available' ELSE CAST(price AS CHAR(20)) END price FROM product LEFT JOIN pc c ON product.model=c.model WHERE product.type='pc' |
model | price |
1121 | 850 |
1232 | 350 |
1232 | 400 |
1232 | 600 |
1233 | 600 |
1233 | 950 |
1233 | 980 |
1260 | 350 |
2111 | Not available |
2112 | Not available |
The CASE statement may be used in one of two syntax forms:
The first form
CASE <input expression>
WHEN <when expression 1>
THEN <return expression 1>
WHEN <when expression N>
THEN <return expression N>
[ELSE <return expression>]
END
Second form
CASE
WHEN <predicate 1>
THEN <return expression 1>
WHEN <predicate N>
THEN <return expression N>
[ELSE <return expression>]
END
All WHEN clauses must be in the same syntax form, i.e. first and second forms
cannot be mixed. When using the first syntax form, the WHEN
condition is satisfied as soon as the value of when expression will
be equal to the value of input expression. When using the second
syntax form, the WHEN condition is satisfied as soon as the predicate
evaluates to TRUE. When satisfying condition, the CASE statement returns
the return expression from the corresponding THEN clause.
If no WHEN expression is satisfied,
the return expression from the ELSE clause will be used.
If no ELSE clause is specified, a NULL value will be returned.
If more than one condition are satisfied, the first return expression
from them will be returned.
The above example uses the second form of the CASE statement.
It should be noted that checking for NULL could also be made using the
standard function COALESCE, which is simpler.
This function has arbitrary number of arguments and returns the first not-NULL
expression among them.
In the case of two arguments, COALESCE(A, B) is equivalent to the following
CASE statement:
CASE WHEN A IS NOT NULL THEN A ELSE B END
When using the COALESCE function, the solution to the above example may be rewritten as followsSELECT DISTINCT product.model,
COALESCE(CAST(price as CHAR(20)),'Not available') price FROM product LEFT JOIN pc c ON product.model=c.model WHERE product.type='pc'; |
SELECT DISTINCT model, price,
CASE price WHEN (SELECT MAX(price) FROM pc) THEN 'Most expensive' WHEN (SELECT MIN(price) FROM pc) THEN 'Most cheap' ELSE 'Mean price' END comment FROM pc ORDER BY price; |
model | price | comment |
1232 | 350 | Most cheap |
1260 | 350 | Most cheap |
1232 | 400 | Mean price |
1233 | 400 | Mean price |
1233 | 600 | Mean price |
1121 | 850 | Mean price |
1233 | 950 | Mean price |
1233 | 980 | Most expensive |
Home | SELECT exercises (rating stages) | DML exercises | Developers |