Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
Hi,
I'm looking to sum cummulative sales month on month per fiscal year(FY) my data is as per the below & the result i'm looking for is a calculated column called "FY Cummulative" as shown.
Month Name (text) | FY | Revenue | FY Cummulative |
Apr | 23 | 120000 | 120000 |
May | 23 | 100000 | 220000 |
Jun | 23 | 200000 | 420000 |
Jul | 23 | 300000 | 720000 |
Aug | 23 | 100000 | 820000 |
Sep | 23 | 200000 | 1020000 |
Oct | 23 | 100000 | 1120000 |
Nov | 23 | 100000 | 1220000 |
Dec | 23 | 200000 | 1420000 |
Jan | 23 | 100000 | 1320000 |
Feb | 23 | 200000 | 1520000 |
Mar | 23 | 100000 | 1620000 |
Apr | 24 | 100000 | 100000 |
May | 24 | 200000 | 300000 |
Jun | 24 | 400000 | 700000 |
Jul | 24 | 100000 | 800000 |
Can you please advise how i can achieve this with DAX so that its adds up the revenue cummulative each month and then resets the sum once the number in the FY column changes to a new financial year.
Thanks in advance.
Solved! Go to Solution.
Hi @PowerRanger1 ,
Thanks @tamerj1 for your replies, allow me to provide another insight:
1. create new index column in power query editor.
2. create calculated column and write expression.
Column =
CALCULATE(
SUM('Table'[Revenue]),
FILTER(
ALL('Table'),
'Table'[FY] = EARLIER('Table'[FY]) &&
'Table'[Index] <= EARLIER('Table'[Index])
)
)
If your Current Period does not refer to this, please clarify in a follow-up reply.
Best Regards,
Clara Gong
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @PowerRanger1 ,
Thanks @tamerj1 for your replies, allow me to provide another insight:
1. create new index column in power query editor.
2. create calculated column and write expression.
Column =
CALCULATE(
SUM('Table'[Revenue]),
FILTER(
ALL('Table'),
'Table'[FY] = EARLIER('Table'[FY]) &&
'Table'[Index] <= EARLIER('Table'[Index])
)
)
If your Current Period does not refer to this, please clarify in a follow-up reply.
Best Regards,
Clara Gong
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Thats great, working as expected. Thanks Clara
Please try
FY Cummulative =
IF (
HASONEVALUE ( 'Date'[FY] ),
SUMX (
FILTER (
CALCULATETABLE (
SUMMARIZE ( 'Date', 'Date'[FY], 'Date'[Month Name] ),
ALLSELECTED ()
),
'Date'[FY] = MAX ( 'Date'[FY] )
),
[Revenue]
)
)
User | Count |
---|---|
25 | |
12 | |
8 | |
6 | |
6 |
User | Count |
---|---|
26 | |
12 | |
11 | |
10 | |
6 |