SQL SERVER – A Puzzle – Swap Value of Column Without Case Statement

For the last few weeks, I have been doing Friday Puzzles and I am really loving it. Yesterday I received a very interesting question by Navneet Chaurasia on Facebook Page. He was asked this question in one of the interview questions for job. Please read the original thread for a complete idea of the conversation. I am presenting the same question here.

Puzzle

Let us assume there is a single column in the table called Gender. The challenge is to write a single update statement which will flip or swap the value in the column. For example if the value in the gender column is ‘male’ swap it with ‘female’ and if the value is ‘female’ swap it with ‘male’.

Here is the quick setup script for the puzzle.

USE tempdb
GO
CREATE TABLE SimpleTable (ID INT, Gender VARCHAR(10))
GO
INSERT INTO SimpleTable (ID, Gender)
SELECT 1, 'female'
UNION ALL
SELECT 2, 'male'
UNION ALL
SELECT 3, 'male'
GO
SELECT *
FROM SimpleTable
GO

The above query will return following result set.

The puzzle was to write a single update column which will generate following result set.

There are multiple answers to this simple puzzle. Let me show you three different ways. I am assuming that the column will have either value ‘male’ or ‘female’ only.

Method 1: Using CASE Statement

I believe this is going to be the most popular solution as we are all familiar with CASE Statement.

UPDATE SimpleTable
SET Gender = CASE Gender WHEN 'male' THEN 'female' ELSE 'male' END
GO
SELECT *
FROM SimpleTable
GO

Method 2: Using REPLACE  Function

I totally understand it is the not cleanest solution but it will for sure work in giving situation.

UPDATE SimpleTable
SET Gender = REPLACE(('fe'+Gender),'fefe','')
GO
SELECT *
FROM SimpleTable
GO

Method 3: Using IIF in SQL Server 2012

If you are using SQL Server 2012 you can use IIF and get the same effect as CASE statement.

UPDATE SimpleTable
SET Gender = IIF(Gender = 'male', 'female', 'male')
GO
SELECT *
FROM SimpleTable
GO

You can read my article series on SQL Server 2012 various functions over here.

Let us clean up.

DROP TABLE SimpleTable
GO

Question to you:

I came up with three simple tricks where there is a single UPDATE statement which swaps the values in the column. Do you know any other simple trick? If yes, please post here in the comments. I will pick two random winners from all the valid answers. Winners will get 1) Print Copy of SQL Server Interview Questions and Answers 2) Free Learning Code for Online Video Courses

I will announce the winners on coming Monday.

Reference:  Pinal Dave (https://blog.sqlauthority.com)

Previous Post
SQL SERVER – Tricks to Replace SELECT * with Column Names – SQL in Sixty Seconds #017 – Video
Next Post
SQL SERVER – Service Broker and CAP_CPU_PERCENT – Limiting SQL Server Instances to CPU Usage

Related Posts

No results found.

78 Comments. Leave new

  • Prasad Sirigiri
    May 16, 2016 4:59 pm

    being practical, some times gender column will be blank… may be data unavailable…. i prefer first approach because it is reliable… by the way great discussion thread

    Reply
  • I don’t have a writable schema at hand, but this should do the trick.
    We define a CTE with the replacement values, then join on that to find the replacement value for each value.

    WITH
    OriginalValues AS (
    SELECT 1 AS ID, ‘female’ AS Gender
    UNION ALL
    SELECT 2, ‘male’
    UNION ALL
    SELECT 3, ‘male’
    ),
    Replacements AS (
    SELECT ‘male’ AS FromValue, ‘female’ AS ToValue
    UNION ALL
    SELECT ‘female’, ‘male’
    )
    SELECT
    og.ID,
    og.Gender AS OriginalValue,
    rp.ToValue AS ReplacementValue
    FROM OriginalValues og
    JOIN Replacements rp ON (og.Gender = rp.FromValue)

    Reply

Leave a Reply Cancel reply

Exit mobile version