Skip to Main Content

Breadcrumb

Question and Answer

Connor McDonald

Thanks for the question, vishal.

Asked: April 24, 2017 - 11:35 am UTC

Last updated: May 15, 2019 - 4:06 pm UTC

Version: 10.1

Viewed 10K+ times! This question is

You Asked

Hi team,

I have a table test having column as name,id,language....

name id  language
a 1 eng
b 2 eng
c 3 fer
d 4 (null)

  select * from TEST
      pivot (min(id) for language in('eng' as "english",'fer' as "french",))  


gives you below output

name  english  french
a     1        (null)
b     2        (null)
c     (null)    3



query-1:

I want is to handle null present for 'd' in language by getting below output:

name  english  french   no-language
a     1        (null)    (null)
b     2        (null)    (null)
c     (null)    3        (null) 
d     (null)   (null)    4



query :2

 select * from TEST
      pivot (min(id) for language in('eng' as "english",'fer' as "french",))  


gives you below output

name  english  french
a     1        (null)
b     2        (null)
c     (null)    3


I want to replace all null with zero

name  english  french
a     1        0
b     2        0
c     0        3


and Chris said...

If you want to show rows with null as a column, map the null to a value first and add this to the IN list.

To get zeroes in your ouput, use standard nvl/coalesce in the select:

with rws as (
  select 'a' name, 1 id, 'eng' lang from dual union all
  select 'b' name, 2 id, 'eng' lang from dual union all
  select 'c' name, 3 id, 'fer' lang from dual union all
  select 'd' name, 4 id, null lang from dual 
), no_nulls as (
  select name, id, nvl(lang, 'NONE') lang from rws
)
  select *
  from   no_nulls
  pivot (min(id) for lang in 
    ( 'eng' as english,'fer' as french, 'NONE' as none )
  )  
  order by 1;

NAME  ENGLISH  FRENCH  NONE  
a     1                      
b     2                      
c              3             
d                      4

Rating

  (2 ratings)

Is this answer out of date? If it is, please let us know via a Comment

Comments

missed point

Marko, May 15, 2019 - 2:42 pm UTC

Author asked if null values within pivot functions could be used, not if null values would be mapped to additional column, answer, in my opinion, missed the point of quest
Chris Saxon
May 15, 2019 - 4:06 pm UTC

not if null values would be mapped to additional column

That's what's asked in Query 1, right?

And to do that, you HAVE to map them to non-null value first:

with rws as (
  select 'a' name, 1 id, 'eng' lang from dual union all
  select 'b' name, 2 id, 'eng' lang from dual union all
  select 'c' name, 3 id, 'fer' lang from dual union all
  select 'd' name, 4 id, null lang from dual 
)
  select * from rws
  pivot (min(id) for lang in 
    ( 'eng' as english,'fer' as french, null as none )
  )  
  order by 1;

NAME    ENGLISH FRENCH NONE
a 1 -  - 
b 2 -  - 
c -  3 - 
d -  -  - 

NULL is not equal NULL

Duke Ganote, May 28, 2019 - 5:00 pm UTC

Seems to me the original questioner wanted PIVOT to work like the Oracle-specific DECODE rather than SQL-standard CASE within the MIN. A DIY version showing the diff below:

WITH 
tester 
( "name","id","language") AS (           SELECT
     'a', 1  , 'eng' FROM DUAL UNION ALL SELECT 
     'b', 2  , 'fre' FROM DUAL UNION ALL SELECT
     'c', 3  ,  NULL FROM DUAL
) 
SELECT "name"
     , MIN(CASE "language" WHEN NULL THEN "id" END) AS "no-lang CASE"
     , MIN(DECODE("language",NULL,"id")) AS "no-lang DECODE"
  FROM TESTER
 WHERE "name" = 'c'
  GROUP BY "name"
  ORDER BY "name";

name  no-lang CASE no-lang DECODE
c         -             3