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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Laocsulak
Helper I
Helper I

Measure to show current, new, recovered and lost buyers of the current month and two months before

Hello,


I have created the next table to explain the measures I need to create:

Laocsulak_0-1675371806320.png

 

I need to create the next 5 measures, where I mention the value that it would take if I would be filtering the month 11 (november)

 

Current buyers 5. Because there were 5 different buyers in the months november, october or september.

 

New current buyers: 1. Because there was only one new buyer in the months november, october and september: buyer 7

 

Previous buyers: 3. Because there were 3 different buyers in the months august, july or june: buyers 4, 5 and 6

 

Recovered buyers: 3. This express the buyers that bought in the months november, october or september, and they didn't buy in the months august, july or june, but they have bought in some previous quarter. These are the buyers 1, 2 and 3 who bought in the months may, april or march.

 

Lost buyers: 2. This express the buyers that bought in august, july or june, but not in november, october or september. These are the buyers 5 and 6 that bought in quarter august, july or june but not in november, october or september.

 

I have created this model where I could create the Current buyers and the New current buyers measures, but not the last three:

https://drive.google.com/drive/folders/1A1lQk9UhC25q1rBgD-dIo1kdEi1FfDbL?usp=sharing

1 ACCEPTED SOLUTION

hi @Laocsulak 

 

1) indeed corss years could be an issue. This shall work:

Current3MBuyer2 = 
VAR _yymm = SELECTEDVALUE(TableName[YYMM])
VAR _date1 = DATE(LEFT(_yymm, 4), RIGHT(_yymm, 2),1)
VAR _uplimit = EOMONTH(_date1, 0) 
VAR _lowlimit = EOMONTH(_date1, -3)+1
VAR Result = 
COUNTROWS(
    CALCULATETABLE(
        VALUES(TableName[payer_id]),
        TableName[date] >= _lowlimit,
        TableName[date] <= _uplimit,
        ALL(TableName[YYMM])
    )
)
RETURN Result

others are very similar.

 

In cases like this, it would be good to utilize Time Intelligence functions like DATEADD and DATESBETWEEN

 

2) To see the list, try to write a measure like:

Current3MBuyerList = 
VAR _yymm = SELECTEDVALUE(TableName[YYMM])
VAR _date1 = DATE(LEFT(_yymm, 4), RIGHT(_yymm, 2),1)
VAR _uplimit = EOMONTH(_date1, 0) 
VAR _lowlimit = EOMONTH(_date1, -3)+1
VAR Result = 
CONCATENATEX(
    CALCULATETABLE(
        VALUES(TableName[payer_id]),
        TableName[date] >= _lowlimit,
        TableName[date] <= _uplimit,
        ALL(TableName[YYMM])
    ),
    TableName[payer_id],
    ", "
)
RETURN Result

others are very similar.

 

it worked like:

FreemanZ_0-1675569241220.png

 

View solution in original post

8 REPLIES 8
Dipakb
Regular Visitor

What if I prefer to view the customer names rather than the total number of customers? Please suggest the formula for this.

hi @Dipakb 

CONCATENATEX the list, whick is showcased in the last measure above.

Laocsulak
Helper I
Helper I

Thanks for the answer! It works quite well, but it fails when it compares to a different year because for example when filtering month = 202301, it compares to 202300 and 202299 which is not correct. Do you know how could I fix that? Besides, I would like to know something related to your first comment, if there's any way in which I can see the list of buyers that meet every requierement, for example a table that shows who are those 2 lost buyers.

hi @Laocsulak 

 

1) indeed corss years could be an issue. This shall work:

Current3MBuyer2 = 
VAR _yymm = SELECTEDVALUE(TableName[YYMM])
VAR _date1 = DATE(LEFT(_yymm, 4), RIGHT(_yymm, 2),1)
VAR _uplimit = EOMONTH(_date1, 0) 
VAR _lowlimit = EOMONTH(_date1, -3)+1
VAR Result = 
COUNTROWS(
    CALCULATETABLE(
        VALUES(TableName[payer_id]),
        TableName[date] >= _lowlimit,
        TableName[date] <= _uplimit,
        ALL(TableName[YYMM])
    )
)
RETURN Result

others are very similar.

 

In cases like this, it would be good to utilize Time Intelligence functions like DATEADD and DATESBETWEEN

 

2) To see the list, try to write a measure like:

Current3MBuyerList = 
VAR _yymm = SELECTEDVALUE(TableName[YYMM])
VAR _date1 = DATE(LEFT(_yymm, 4), RIGHT(_yymm, 2),1)
VAR _uplimit = EOMONTH(_date1, 0) 
VAR _lowlimit = EOMONTH(_date1, -3)+1
VAR Result = 
CONCATENATEX(
    CALCULATETABLE(
        VALUES(TableName[payer_id]),
        TableName[date] >= _lowlimit,
        TableName[date] <= _uplimit,
        ALL(TableName[YYMM])
    ),
    TableName[payer_id],
    ", "
)
RETURN Result

others are very similar.

 

it worked like:

FreemanZ_0-1675569241220.png

 

Perfect solution, thank you very much!!

FreemanZ
Super User
Super User

hi @Laocsulak 

a measure could not return a list/table, how are you going to showcase the expected measure/list? You wanna show the list or sum a value for the listed payers?

Hi Freeman, I want to count the number of buyers for every definition in a card. In the model uploaded, I was able to calculate the first 2 measures (current buyers and new current buyers), but not the last three.

hi @Laocsulak 

 

you would need to add column like:

YYMM = FORMAT([date], "YYYYMM")

 

then write 5 measures like:

Current3MBuyer =
VAR _month = SELECTEDVALUE(TableName[YYMM])
RETURN
COUNTROWS(
    CALCULATETABLE(
        VALUES(TableName[payer_id]),
        TableName[YYMM] IN {_month, _month-1, _month-2}
    )
)

New3MBuyer =
VAR _month = SELECTEDVALUE(TableName[YYMM])
RETURN
COUNTROWS(
    EXCEPT(
        CALCULATETABLE(
            VALUES(TableName[payer_id]),
            TableName[YYMM] IN {_month, _month-1, _month-2}
        ),
        CALCULATETABLE(
            VALUES(TableName[payer_id]),
            TableName[YYMM] < _month - 3
        )
    )
)

PreviousBuyer =
VAR _month = SELECTEDVALUE(TableName[YYMM])
RETURN
COUNTROWS(
    CALCULATETABLE(
        VALUES(TableName[payer_id]),
        TableName[YYMM] IN {_month-3, _month-4, _month-5}
    )
)

RecoveredBuyer =
VAR _month = SELECTEDVALUE(TableName[YYMM])
RETURN
COUNTROWS(
    EXCEPT(    
        INTERSECT(
            CALCULATETABLE(
                VALUES(TableName[payer_id]),
                TableName[YYMM] IN {_month, _month-1, _month-2}
            ),
            CALCULATETABLE(
                VALUES(TableName[payer_id]),
                TableName[YYMM] IN {_month-6, _month-7, _month-8}
            )
        ),
        CALCULATETABLE(
            VALUES(TableName[payer_id]),
            TableName[YYMM] IN {_month-3, _month-4, _month-5}
        )
    )
)

LostBuyers =
VAR _month = SELECTEDVALUE(TableName[YYMM])
RETURN
COUNTROWS(
    EXCEPT(    
        CALCULATETABLE(
            VALUES(TableName[payer_id]),
            TableName[YYMM] IN {_month-3, _month-4, _month-5}
        ),
        CALCULATETABLE(
            VALUES(TableName[payer_id]),
            TableName[YYMM] IN {_month, _month-1, _month-2}
        )
    )
)

 

it worked like:

FreemanZ_0-1675394617120.png

 

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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

Top Solution Authors