Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now
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
| Record | Red | Green | Yellow | Blue |
| 6026 | 1 | 0 | 0 | 0 |
| 7206 | 1 | 1 | 0 | 1 |
| 2172 | 0 | 1 | 1 | 0 |
| 4752 | 1 | 1 | 1 | 0 |
| 9960 | 1 | 1 | 0 | 1 |
| 8485 | 1 | 0 | 1 | 1 |
| 3515 | 1 | 0 | 1 | 0 |
| 3902 | 1 | 0 | 1 | 0 |
| 3094 | 1 | 1 | 1 | 1 |
Thank you.
Solved! Go to Solution.
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:
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.
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:
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.
Check out the November 2025 Power BI update to learn about new features.
Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!