Skip to content

Commit 9abc235

Browse files
Create unpivot-multiple-columns in-snowflake.md
1 parent 7f8c14c commit 9abc235

File tree

1 file changed

+65
-0
lines changed

1 file changed

+65
-0
lines changed
Lines changed: 65 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,65 @@
1+
# Unpivot multiple columns in Snowflake
2+
3+
Suppose you have a Wide Table format Performance Ratings data as following:
4+
5+
| NAME | ACTING_RATING | ACTING_COMMENTS | COMEDY_RATING | COMEDY_COMMENTS | MUSICAL_PERFORMANCE_RATING | MUSICAL_PERFORMANCE_COMMENTS |
6+
|--------------|---------------|-----------------|---------------|-----------------|----------------------------|------------------------------|
7+
| Groucho Marx | 4 | Awesome | 3 | Super | 4 | Really good |
8+
| Harpo Marx | 4 | Awesome | 4 | Awesome | 4 | |
9+
| Groucho Marx | 4 | | 3 | Thumbs up | 4 | Nice |
10+
| Harpo Marx | 4 | Best Acting | 4 | Nice | 4 | Best performance Award! |
11+
12+
and you need to convert it to a Long Table Format as following
13+
14+
| NAM | SKILL | SKILL_RATING | COMMENTS | SKILL_COMMENTS | SPLIT(SKILL, '-')[1] |
15+
|--------------|----------------------------|--------------|-------------------------|------------------------------|----------------------|
16+
| Groucho Marx | ACTING_RATING | 4 | Awesome | ACTING_COMMENTS | |
17+
| Groucho Marx | COMEDY_RATING | 3 | Super | COMEDY_COMMENTS | |
18+
| Groucho Marx | MUSICAL_PERFORMANCE_RATING | 4 | Really good | MUSICAL_PERFORMANCE_COMMENTS | |
19+
| Harpo Marx | ACTING_RATING | 4 | Awesome | ACTING_COMMENTS | |
20+
| Harpo Marx | COMEDY_RATING | 4 | Awesome | COMEDY_COMMENTS | |
21+
| Harpo Marx | MUSICAL_PERFORMANCE_RATING | 4 | | MUSICAL_PERFORMANCE_COMMENTS | |
22+
| Groucho Marx | ACTING_RATING | 4 | | ACTING_COMMENTS | |
23+
| Groucho Marx | COMEDY_RATING | 3 | Thumbs up | COMEDY_COMMENTS | |
24+
| Groucho Marx | MUSICAL_PERFORMANCE_RATING | 4 | Nice | MUSICAL_PERFORMANCE_COMMENTS | |
25+
| Harpo Marx | ACTING_RATING | 4 | Best Acting | ACTING_COMMENTS | |
26+
| Harpo Marx | COMEDY_RATING | 4 | Nice | COMEDY_COMMENTS | |
27+
| Harpo Marx | MUSICAL_PERFORMANCE_RATING | 4 | Best performance Award! | MUSICAL_PERFORMANCE_COMMENTS | |
28+
29+
This can be achieve by using the UNPIVOT function or the UNION ALL in Snowflake
30+
31+
## Using UNPIVOT
32+
33+
```sql
34+
select
35+
name
36+
, skill
37+
, skill_rating
38+
, comments
39+
, skill_comments
40+
from performer_ratings
41+
unpivot include nulls (skill_rating for skill in (acting_rating, comedy_rating, musical_performance_rating))
42+
unpivot include nulls (comments for skill_comments in (acting_comments,comedy_comments, musical_performance_comments))
43+
--Following where clause is added to filter the unmatched rows
44+
where split(skill, '_')[0] = split(skill_comments, '_')[0];
45+
46+
```
47+
48+
49+
## Using UNION ALL
50+
51+
```sql
52+
53+
select NAME
54+
, 'ACTING_RATING' as SKILL, ACTING_RATING as SKILL_RATING, ACTING_COMMENTS as SKILL_COMMENTS
55+
from performer_ratings
56+
union all
57+
select NAME
58+
, 'COMEDY_RATING', COMEDY_RATING, COMEDY_COMMENTS
59+
from performer_ratings
60+
union all
61+
select NAME
62+
, 'MUSICAL_PERFORMANCE_RATING', MUSICAL_PERFORMANCE_RATING, MUSICAL_PERFORMANCE_COMMENTS
63+
from performer_ratings
64+
;
65+
```

0 commit comments

Comments
 (0)