MVSFORUMS.com Forum Index MVSFORUMS.com
A Community of and for MVS Professionals
 
 FAQFAQ   SearchSearch   Quick Manuals   RegisterRegister 
 ProfileProfile   Log in to check your private messagesLog in to check your private messages   Log inLog in 

VERTICAL to HORIZONAL COLUMNS

 
Post new topic   Reply to topic   printer-friendly view    MVSFORUMS.com Forum Index -> Database
View previous topic :: View next topic  
Author Message
NASCAR9
Intermediate


Joined: 08 Oct 2004
Posts: 274
Topics: 52
Location: California

PostPosted: Tue Dec 18, 2018 2:33 pm    Post subject: VERTICAL to HORIZONAL COLUMNS Reply with quote

The data is in a vertical format with a key of FAMILY_ID that allows grouping a Family. The data looks something like this:

Code:

FAMILY_ID    RELATION_ID   FIRST_NAME   LAST_NAME
123456      0              HOBO      KELLY
123456      1              BOZO      CLOWN
123456      6              YUCKO      CLOWN   
123456      9              SIDESHOW   BOB
654321      0              ROY                 RODGERS
654321      2                      DALE                 EVANS
654321      3             CISCO      KID
654321      4             LUCAS      McCAIN   
654321      9             HOPALONG           CASSIDY


This query will flatten the data. I allowed for 10 FAMILY members in a FAMILY_ID. This is just an example.
Code:


 SELECT Z.FAMILY_ID,       
       MAX(DECODE(Z.RELATIONID_RANK, 01, Z.FIRST_NAME || ' ' || Z.LAST_NAME)) AS D1,
       MAX(DECODE(Z.RELATIONID_RANK, 02, Z.FIRST_NAME || ' ' || Z.LAST_NAME)) AS D2,
       MAX(DECODE(Z.RELATIONID_RANK, 03, Z.FIRST_NAME || ' ' || Z.LAST_NAME)) AS D3,
       MAX(DECODE(Z.RELATIONID_RANK, 04, Z.FIRST_NAME || ' ' || Z.LAST_NAME)) AS D4,
       MAX(DECODE(Z.RELATIONID_RANK, 05, Z.FIRST_NAME || ' ' || Z.LAST_NAME)) AS D5,
       MAX(DECODE(Z.RELATIONID_RANK, 06, Z.FIRST_NAME || ' ' || Z.LAST_NAME)) AS D6,
       MAX(DECODE(Z.RELATIONID_RANK, 07, Z.FIRST_NAME || ' ' || Z.LAST_NAME)) AS D7,
       MAX(DECODE(Z.RELATIONID_RANK, 08, Z.FIRST_NAME || ' ' || Z.LAST_NAME)) AS D8,
       MAX(DECODE(Z.RELATIONID_RANK, 09, Z.FIRST_NAME || ' ' || Z.LAST_NAME)) AS D9,
       MAX(DECODE(Z.RELATIONID_RANK, 10, Z.FIRST_NAME || ' ' || Z.LAST_NAME)) AS D10
    FROM
   (SELECT  FAMILY_ID, RELATION_ID, FIRST_NAME, LAST_NAME, 
           RANK() OVER ( PARTITION BY  FAMILY_ID   
                             ORDER BY  FAMILY_ID
                                    , RELATION_ID ) AS RELATIONID_RANK
   FROM YOUR.TABLE     
   WHERE FAMILY_ID   IN (123456, 654321)
   ORDER BY  FAMILY_ID, RELATION_ID ) Z
   GROUP BY Z.FAMILY_ID;


The result will be in columns. The reason I needed columns was for an Insert into another table

Code:


123456   HOBO KELLY    BOZO CLOWN   YUCKO CLOWN  SIDESHOW BOB
654321   ROY RODGERS   DALE EVANS   CISCO KID    LUCAS McCAIN   HOPALONG CASSIDY


I tried to line the data up so it would display correctly, but no joy.

Tried to edit for lineup, better but not pretty
_________________
Thanks,
NASCAR9


Last edited by NASCAR9 on Wed Dec 19, 2018 10:48 am; edited 2 times in total
Back to top
View user's profile Send private message
kolusu
Site Admin
Site Admin


Joined: 26 Nov 2002
Posts: 12366
Topics: 75
Location: San Jose

PostPosted: Tue Dec 18, 2018 4:27 pm    Post subject: Reply with quote

NASCAR9,

You can use the trick of using XMLAGG listed in here

https://www.mvsforums.com/helpboards/viewtopic.php?t=12879

NASCAR9 wrote:
The reason I needed columns was for an Insert into another table


Isn't it simple to do a INSERT INTO with a SELECT statement? Something like this
Code:

 INSERT INTO New_Table
     SELECT FAMILY_ID
           ,CHAR(RTRIM(IFNULL(FIRST_NAME, ' ')) ||         
            CHAR(' ')                           ||         
            RTRIM(IFNULL(LAST_NAME, ' '))) AS FULLNAME
      FROM Old_table
     WHERE FAMILY_ID IN (123456, 654321)
;

_________________
Kolusu - DFSORT Development Team (IBM)
DFSORT is on the Web at:
www.ibm.com/storage/dfsort

www.linkedin.com/in/kolusu
Back to top
View user's profile Send private message Send e-mail Visit poster's website
NASCAR9
Intermediate


Joined: 08 Oct 2004
Posts: 274
Topics: 52
Location: California

PostPosted: Tue Dec 18, 2018 5:06 pm    Post subject: Reply with quote

kolusu,

I have xml to do the concatenating of data and flatting.
xml returns the data in a single column(as far as I know). I'm familiar with the link, I participated in it Very Happy

The point of my post was to show how to take vertical data and be able to retrieve the data into individual columns. This query is only an example I'm sharing.
_________________
Thanks,
NASCAR9


Last edited by NASCAR9 on Tue Jan 29, 2019 1:37 pm; edited 1 time in total
Back to top
View user's profile Send private message
kolusu
Site Admin
Site Admin


Joined: 26 Nov 2002
Posts: 12366
Topics: 75
Location: San Jose

PostPosted: Tue Dec 18, 2018 5:36 pm    Post subject: Reply with quote

NASCAR9 wrote:
kolusu,
The point of my post was to show how to take horizonal data and be able to retrieve the data into individual columns. This query is only an example I'm sharing.


Nascar9,

I apologize for the oversight. Thanks for sharing the query.
_________________
Kolusu - DFSORT Development Team (IBM)
DFSORT is on the Web at:
www.ibm.com/storage/dfsort

www.linkedin.com/in/kolusu
Back to top
View user's profile Send private message Send e-mail Visit poster's website
NASCAR9
Intermediate


Joined: 08 Oct 2004
Posts: 274
Topics: 52
Location: California

PostPosted: Tue Dec 18, 2018 7:08 pm    Post subject: Reply with quote

kolusu,
No apology necessary. Your help is second to none.
I posted the query because I have never seen/used the Function DECODE before.
It solves a problem I'm faced with periodical. I'm hoping it's able to help someone else. There are many ways to skin a cat in SQL.
_________________
Thanks,
NASCAR9
Back to top
View user's profile Send private message
Display posts from previous:   
Post new topic   Reply to topic   printer-friendly view    MVSFORUMS.com Forum Index -> Database All times are GMT - 5 Hours
Page 1 of 1

 
Jump to:  
You cannot post new topics in this forum
You cannot reply to topics in this forum
You cannot edit your posts in this forum
You cannot delete your posts in this forum
You cannot vote in polls in this forum


MVSFORUMS
Powered by phpBB © 2001, 2005 phpBB Group