Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
wongzqn
Frequent Visitor

CountRows of Matrix Visualization with values from a Measure

Hello, I have this matrix visualization below, corporate donor name from table 1, year 2017-2020 from table 2, and the values (donor status) as a measure to categorize the donor status.  

 

The ultimate goal is to calculate the number of 'new', 'lapsed', 'recurring', 'lost', 'recovered' (values) for each year to do a YoY analysis. Currently met with difficulty to countrows on measure. 

 

Not sure and 

 

Appreciate your help! 

 

wongzqn_1-1596422255485.png

 

wongzqn_2-1596422355730.png

 

 

1 ACCEPTED SOLUTION

Hi @wongzqn,

 

Please refer to the steps:

 

1. Create a status table by enter data:

Capture3.PNG

Then create a calculated table:

 

Donor Status year = CROSSJOIN(VALUES('Status'[Donor Status]),VALUES(_Calendar[Year]))

 

Capture4.PNG

 

Then you can use the following measure to count values:

 

Measure =
VAR t =
    SUMMARIZE (
        CROSSJOIN ( VALUES ( CombinedData[Donor Name] ), VALUES ( _Calendar[Year] ) ),
        CombinedData[Donor Name],
        _Calendar[Year],
        "status", [Donor Status]
    )
RETURN
    COUNTX (
        FILTER (
            t,
            [Year] = MAX ( 'Donor Status year'[Year] )
                && [status] = MAX ( 'Donor Status year'[Donor Status] )
        ),
        [Donor Name]
    ) + 0

 

Capture5.PNG

For more details, please refer to pbix file:  https://qiuyunus-my.sharepoint.com/personal/pbipro_qiuyunus_onmicrosoft_com/_layouts/15/onedrive.asp...

 

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

 

Best Regards,

Dedmon Dai

 

View solution in original post

5 REPLIES 5
Greg_Deckler
Super User
Super User

Not really enough information to go on, please first check if your issue is a common issue listed here: https://community.powerbi.com/t5/Community-Blog/Before-You-Post-Read-This/ba-p/1116882

Also, please see this post regarding How to Get Your Question Answered Quickly: https://community.powerbi.com/t5/Community-Blog/How-to-Get-Your-Question-Answered-Quickly/ba-p/38490

The most important parts are:
1. Sample data as text, use the table tool in the editing bar
2. Expected output from sample data
3. Explanation in words of how to get from 1. to 2.


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...
amitchandak
Super User
Super User

@wongzqn ,  The information you have provided is not making the problem clear to me. Can you please explain with an example.
Can you share sample data and sample output in table format?

 

Please refer these three


https://blog.enterprisedna.co/new-vs-existing-customers-advanced-analytics-w-dax/
https://www.sqlbi.com/articles/computing-new-customers-in-dax/

https://community.powerbi.com/t5/Desktop/Churn-Rate-lost-Customer/m-p/1173754#M529196


Appreciate your Kudos.


Hi @amitchandak, thanks for reverting!

 

Sample data:

 

Donor NameDonation ValueDonation Date
DonorA5009 Sep 2018
DonorB10008 Dec 2018
DonorA10007 Mar 2019

 

Sample Output:

Donor StatusYearCount
New

2017

10
Lost20177
Recurring20179
Recovered201710
Lasped201743
New

2018

15
Lost201812
Recurring20188
Recovered201811
Lasped201845
New

2019

20
Lost201915
Recurring201916
Recovered201915
Lasped201947

 

 

The value of 'Donor Status' is a measure where I categorize and label based on date and donation:

 

2.9 Donor Status =


VAR ThisYearDonations =
CALCULATE(SUM(CombinedData[Donation Cash Value]), DATESYTD(_Calendar[Date]))


VAR LastYearDonations =
CALCULATE(SUM(CombinedData[Donation Cash Value]), PREVIOUSYEAR(_Calendar[Date]))


VAR PriorYearsDonations =
CALCULATE(SUM(CombinedData[Donation Cash Value]),
       FILTER(
           ALL(_Calendar[Date]),
           YEAR(_Calendar[Date]) < YEAR(MAX(_Calendar[Date]))-1
         )
)

 

 

RETURN
      IF(AND(ThisYearDonations = 0 && LastYearDonations = 0, PriorYearsDonations > 0), "Lost",
              (IF(AND(ThisYearDonations= 0 && LastYearDonations = 0, PriorYearsDonations = 0), "NA",
              (IF(AND(ThisYearDonations = 0, LastYearDonations > 0), "Lapsed",
              (IF(AND(ThisYearDonations > 0, LastYearDonations > 0), "Recurring",
              (IF(AND(ThisYearDonations > 0 && LastYearDonations = 0, PriorYearsDonations > 0), "Recovered",
            (IF(AND(ThisYearDonations > 0 && LastYearDonations = 0, PriorYearsDonations = 0), "New", BLANK())))))))))))

 

 

Hi @wongzqn,

 

Please refer to the steps:

 

1. Create a status table by enter data:

Capture3.PNG

Then create a calculated table:

 

Donor Status year = CROSSJOIN(VALUES('Status'[Donor Status]),VALUES(_Calendar[Year]))

 

Capture4.PNG

 

Then you can use the following measure to count values:

 

Measure =
VAR t =
    SUMMARIZE (
        CROSSJOIN ( VALUES ( CombinedData[Donor Name] ), VALUES ( _Calendar[Year] ) ),
        CombinedData[Donor Name],
        _Calendar[Year],
        "status", [Donor Status]
    )
RETURN
    COUNTX (
        FILTER (
            t,
            [Year] = MAX ( 'Donor Status year'[Year] )
                && [status] = MAX ( 'Donor Status year'[Donor Status] )
        ),
        [Donor Name]
    ) + 0

 

Capture5.PNG

For more details, please refer to pbix file:  https://qiuyunus-my.sharepoint.com/personal/pbipro_qiuyunus_onmicrosoft_com/_layouts/15/onedrive.asp...

 

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

 

Best Regards,

Dedmon Dai

 

Hi @v-deddai1-msft

 

Appreciate your revert. 

 

I am having error with the DAX you've provided - see below.  Not sure what went wrong 😞 

 

wongzqn_0-1599731488006.png

 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.