CASE (T-SQL)

Evaluates a list of conditions and returns one of multiple possible result expressions.

CASE has two formats:

Both formats support an optional ELSE argument.

Syntax

Simple CASE function:

CASE input_expression
    WHEN when_expression THEN result_expression
        [...n]
    [
        ELSE else_result_expression
    ]
END

Searched CASE function:

CASE
    WHEN Boolean_expression THEN result_expression
        [...n]
    [
        ELSE else_result_expression
    ]
END

Arguments
input_expression
Is the expression that is evaluated when using the simple CASE format. input_expression is any valid Microsoft® SQL Server™ expression.
WHEN when_expression
Is a simple expression to which input_expression is compared when using the simple CASE format. when_expression is any valid SQL Server expression. The data types of input_expression and each when_expression must be the same or must be an implicit conversion.
n
Is a placeholder indicating that multiple WHEN when_expression THEN result_expression clauses, or multiple WHEN Boolean_expression THEN result_expression clauses can be used.
THEN result_expression
Is the expression that is returned when input_expression equals when_expression evaluates to TRUE, or Boolean_expression evaluates to TRUE. result expression is any valid SQL Server expression.
ELSE else_result_expression
Is the expression that is returned if no comparison operation evaluates to TRUE. If this argument is omitted and no comparison operation evaluates to TRUE, CASE returns NULL. else_result_expression is any valid SQL Server expression. The data types of else_result_expression and any result_expression must be the same or must be an implicit conversion.
WHEN Boolean_expression
Is the Boolean expression that is evaluated when using the searched CASE format. Boolean_expression is any valid Boolean expression.
Result Types

Returns the highest precedence type from the set of types in result_expressions and the optional else_result_expression. For more information, see Data Type Precedence.

Result Values

Simple CASE function:

Searched CASE function:

Examples
A. Use a SELECT statement with a simple CASE function

Within a SELECT statement, a simple CASE function allows only an equality check; no other comparisons are made. This example uses the CASE function to alter the display of book categories to make them more understandable.

USE pubs

GO

SELECT    Category =

        CASE type

            WHEN 'popular_comp' THEN 'Popular Computing'

            WHEN 'mod_cook' THEN 'Modern Cooking'

            WHEN 'business' THEN 'Business'

            WHEN 'psychology' THEN 'Psychology'

            WHEN 'trad_cook' THEN 'Traditional Cooking'

            ELSE 'Not yet categorized'

        END,

    CAST(title AS varchar(25)) AS 'Shortened Title',

    price AS Price

FROM titles

WHERE price IS NOT NULL

ORDER BY type, price

COMPUTE AVG(price) BY type

GO

  

Here is the result set:

Category            Shortened Title           Price                     

------------------- ------------------------- --------------------------

Business            You Can Combat Computer S 2.99                      

Business            Cooking with Computers: S 11.95                     

Business            The Busy Executive's Data 19.99                     

Business            Straight Talk About Compu 19.99                     

  

                                              avg

                                              ==========================

                                              13.73                     

  

Category            Shortened Title           Price                     

------------------- ------------------------- --------------------------

Modern Cooking      The Gourmet Microwave     2.99                      

Modern Cooking      Silicon Valley Gastronomi 19.99                     

  

                                              avg

                                              ==========================

                                              11.49                     

  

Category            Shortened Title           Price                     

------------------- ------------------------- --------------------------

Popular Computing   Secrets of Silicon Valley 20.00                     

Popular Computing   But Is It User Friendly?  22.95                     

  

                                              avg

                                              ==========================

                                              21.48                     

  

Category            Shortened Title           Price                     

------------------- ------------------------- --------------------------

Psychology          Life Without Fear         7.00                      

Psychology          Emotional Security: A New 7.99                      

Psychology          Is Anger the Enemy?       10.95                     

Psychology          Prolonged Data Deprivatio 19.99                     

Psychology          Computer Phobic AND Non-P 21.59                     

  

                                              avg

                                              ==========================

                                              13.50                     

  

Category            Shortened Title           Price                     

------------------- ------------------------- --------------------------

Traditional Cooking Fifty Years in Buckingham 11.95                     

Traditional Cooking Sushi, Anyone?            14.99                     

Traditional Cooking Onions, Leeks, and Garlic 20.95                     

  

                                              avg

                                              ==========================

                                              15.96                     

  

(21 row(s) affected)

  

B. Use a SELECT statement with simple and searched CASE function

Within a SELECT statement, the searched CASE function allows values to be replaced in the result set based on comparison values. This example displays the price (a money column) as a text comment that is based on the cost range for a book.

USE pubs

GO

SELECT     'Price Category' =

        CASE

            WHEN price IS NULL THEN 'Not yet priced'

            WHEN price < 10 THEN 'Very Reasonable Title'

            WHEN price >= 10 and price < 20 THEN 'Coffee Table Title'

            ELSE 'Expensive book!'

        END,

    CAST(title AS varchar(20)) AS 'Shortened Title'

FROM titles

ORDER BY price

GO

  

Here is the result set:

Price Category        Shortened Title     

--------------------- --------------------

Not yet priced        Net Etiquette       

Not yet priced        The Psychology of Co

Very Reasonable Title The Gourmet Microwav

Very Reasonable Title You Can Combat Compu

Very Reasonable Title Life Without Fear   

Very Reasonable Title Emotional Security: 

Coffee Table Title    Is Anger the Enemy? 

Coffee Table Title    Cooking with Compute

Coffee Table Title    Fifty Years in Bucki

Coffee Table Title    Sushi, Anyone?      

Coffee Table Title    Prolonged Data Depri

Coffee Table Title    Silicon Valley Gastr

Coffee Table Title    Straight Talk About 

Coffee Table Title    The Busy Executive's

Expensive book!       Secrets of Silicon V

Expensive book!       Onions, Leeks, and G

Expensive book!       Computer Phobic And 

Expensive book!       But Is It User Frien

  

(18 row(s) affected)

  

C. Use CASE with SUBSTRING and SELECT

This example uses CASE and THEN to produce a list of authors, the book identification numbers, and the book types each author has written.

USE pubs

SELECT SUBSTRING((RTRIM(a.au_fname) + ' '+

    RTRIM(a.au_lname) + ' '), 1, 25) AS Name, a.au_id, ta.title_id,

    Type =

  CASE

    WHEN SUBSTRING(ta.title_id, 1, 2) = 'BU' THEN 'Business'

    WHEN SUBSTRING(ta.title_id, 1, 2) = 'MC' THEN 'Modern Cooking'

    WHEN SUBSTRING(ta.title_id, 1, 2) = 'PC' THEN 'Popular Computing'

    WHEN SUBSTRING(ta.title_id, 1, 2) = 'PS' THEN 'Psychology'

    WHEN SUBSTRING(ta.title_id, 1, 2) = 'TC' THEN 'Traditional Cooking'

  END

FROM titleauthor ta JOIN authors a ON ta.au_id = a.au_id

  

Here is the result set:

Name                      au_id       title_id Type               

------------------------- ----------- -------- -------------------

Johnson White             172-32-1176 PS3333   Psychology         

Marjorie Green            213-46-8915 BU1032   Business           

Marjorie Green            213-46-8915 BU2075   Business           

Cheryl Carson             238-95-7766 PC1035   Popular Computing  

Michael O'Leary           267-41-2394 BU1111   Business           

Michael O'Leary           267-41-2394 TC7777   Traditional Cooking

Dean Straight             274-80-9391 BU7832   Business           

Abraham Bennet            409-56-7008 BU1032   Business           

Ann Dull                  427-17-2319 PC8888   Popular Computing  

Burt Gringlesby           472-27-2349 TC7777   Traditional Cooking

Charlene Locksley         486-29-1786 PC9999   Popular Computing  

Charlene Locksley         486-29-1786 PS7777   Psychology         

Reginald Blotchet-Halls   648-92-1872 TC4203   Traditional Cooking

Akiko Yokomoto            672-71-3249 TC7777   Traditional Cooking

Innes del Castillo        712-45-1867 MC2222   Modern Cooking     

Michel DeFrance           722-51-5454 MC3021   Modern Cooking     

Stearns MacFeather        724-80-9391 BU1111   Business           

Stearns MacFeather        724-80-9391 PS1372   Psychology         

Livia Karsen              756-30-7391 PS1372   Psychology         

Sylvia Panteley           807-91-6654 TC3218   Traditional Cooking

Sheryl Hunter             846-92-7186 PC8888   Popular Computing  

Anne Ringer               899-46-2035 MC3021   Modern Cooking     

Anne Ringer               899-46-2035 PS2091   Psychology         

Albert Ringer             998-72-3567 PS2091   Psychology         

Albert Ringer             998-72-3567 PS2106   Psychology         

  

(25 row(s) affected)

  

See Also
Data Types UPDATE
Data Type Conversion WHERE
Expressions System Functions
SELECT  

  


(c) 1988-98 Microsoft Corporation. All Rights Reserved.