cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
sglendenning
Helper I
Helper I

Organizing Data for Waterfall or Funnel

I have data organized as below and would like to create a waterfall or funnel that goes thru each record color from left to right and counts the number that drop at each color and excludes if the colors before were dropped.  For instace; record 2172 didn't make it past red so gets dropped for all other consideration.

 

Ultimately giving me data that shows;

9 records in total

8 red

4 green

2 yellow

1 blue

 

RecordRedGreenYellowBlue
60261000
72061101
21720110
47521110
99601101
84851011
35151010
39021010
30941111

 

Thank you.

 

 

1 ACCEPTED SOLUTION
v-eqin-msft
Community Support
Community Support

Hi @sglendenning ,

 

Please firstly create measures to get the numbers of each color column:

Red Count = CALCULATE(COUNTROWS('Table'),FILTER('Table',[Red]=1))

Green Count = SUMX(FILTER('Table',[Red]=1) ,[Green])

Yellow Count = SUMX( FILTER('Table',[Red]=1 && [Green]=1) ,[Yellow])

Blue Count = SUMX( FILTER('Table',[Red]=1 && [Green]=1 &&[Yellow]=1) ,[Blue])

Then add a new table with all colors:

Table 2 = {"Red","Green","Yellow","Blue"}

Use SWITCH() to match the measures created before:

Measure = SWITCH(MAX('Table 2'[Value]),"Red",[Red Count],"Green",[Green Count],"Yellow",[Yellow Count],"Blue",[Blue Count])

Output:

Eyelyn9_0-1653361560987.png

 

Best Regards,
Eyelyn Qin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

1 REPLY 1
v-eqin-msft
Community Support
Community Support

Hi @sglendenning ,

 

Please firstly create measures to get the numbers of each color column:

Red Count = CALCULATE(COUNTROWS('Table'),FILTER('Table',[Red]=1))

Green Count = SUMX(FILTER('Table',[Red]=1) ,[Green])

Yellow Count = SUMX( FILTER('Table',[Red]=1 && [Green]=1) ,[Yellow])

Blue Count = SUMX( FILTER('Table',[Red]=1 && [Green]=1 &&[Yellow]=1) ,[Blue])

Then add a new table with all colors:

Table 2 = {"Red","Green","Yellow","Blue"}

Use SWITCH() to match the measures created before:

Measure = SWITCH(MAX('Table 2'[Value]),"Red",[Red Count],"Green",[Green Count],"Yellow",[Yellow Count],"Blue",[Blue Count])

Output:

Eyelyn9_0-1653361560987.png

 

Best Regards,
Eyelyn Qin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources

Announcements
PBI Sept Update Carousel

Power BI September 2023 Update

Take a look at the September 2023 Power BI update to learn more.

Learn Live

Learn Live: Event Series

Join Microsoft Reactor and learn from developers.

Dashboard in a day with date

Exclusive opportunity for Women!

Join us for a free, hands-on Microsoft workshop led by women trainers for women where you will learn how to build a Dashboard in a Day!

MPPC 2023 PBI Carousel

Power Platform Conference-Power BI and Fabric Sessions

Join us Oct 1 - 6 in Las Vegas for the Microsoft Power Platform Conference.

Top Solution Authors