Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
I'm struggling trying to find a measure that can do the following:
For example, assuming the data begins January 1, 2020. If Nov 30, 2020 is selected from the date slicer, the corrresponding visual (bar chart with dates as x-axis) should show Nov 25, 26, 27, 28, 29, 30 along the x-axis while the counts for each date should equal to the amounts from Jan 1, 2020 to Nov 25, Jan 1 to Nov 26...
Unforunately, every combination I try results in:
If someone could help provide a solution, i'd be extremely greatful. Thank you!
Solved! Go to Solution.
Hi @AccrualJoke ,
You can do this by creating a disconnected date table for the picker (this means it's not connected by relationship to another table in the model). You can do this with the TABLE DAX:
Then you would NOT use the date picker date on your chart, the other one.
Respectfully,
Zoe Douglas (DataZoe)
Follow me on LinkedIn at https://www.linkedin.com/in/zoedouglas-data
See my reports and blog at https://www.datazoepowerbi.com/
Hi @AccrualJoke ,
You can do this by creating a disconnected date table for the picker (this means it's not connected by relationship to another table in the model). You can do this with the TABLE DAX:
Then you would NOT use the date picker date on your chart, the other one.
Respectfully,
Zoe Douglas (DataZoe)
Follow me on LinkedIn at https://www.linkedin.com/in/zoedouglas-data
See my reports and blog at https://www.datazoepowerbi.com/
@DataZoe Thank you so much! I just tried your measure now and it's working well!
The one issue is that I'll need to calculate totals beyond just the year. The data will most likely spanning past 2020 into future periods. So is there a variation that allows for that?
I tried substituting TOTALYTD with Calculate, but that doesn't seem to work.
Please let me know if you have further insight to this! Thank you again!
The TOTALYTD will work on any period, so should accomodate future years just like it is.
Respectfully,
Zoe Douglas (DataZoe)
Follow me on LinkedIn at https://www.linkedin.com/in/zoedouglas-data
See my reports and blog at https://www.datazoepowerbi.com/
Is there a way to make it so that the cumulative count does NOT reset at the beginning of a new year?
For example, instead of a TOTALYTD is there an equivalent for life-to-date or inception-to-date? I would want 2021 to include the 2020 and prior year counts as part of the 2021 totals.
@AccrualJoke Sure, you can use this cumulative instead:
Respectfully,
Zoe Douglas (DataZoe)
Follow me on LinkedIn at https://www.linkedin.com/in/zoedouglas-data
See my reports and blog at https://www.datazoepowerbi.com/
Thanks again for saving me!
Instead of referencing the Date column from my disconnected Date Table, I used the date column from my actual data table. After making the switch, the measure seemed to work perfectly fine.
EDIT: 2022-10-03 -- A year later and I'm still finding myself using this as reference! For clarity, I've included the full measure I ended up using. For the running total measure to work as intended, it needed to include the condition to return a value of BLANK if the date from the fact table is greater than the selected date from the disconnected date table.
RUNNING / CUMULATIVE TOTAL =
IF (
MAX ( Fact_Table[Date] ) > SELECTEDVALUE ( Disconnected_Date_Table[Date] ),
BLANK (),
CALCULATE (
SUM ( Fact_Table[Sales] ),
FILTER (
ALLSELECTED ( Fact_Table[Date] ),
Fact_Table[Date] <= MAX ( Fact_Table[Date] )
)
)
)
Alternatively, one could use ISONORAFTER
RUNNING / CUMULATIVE TOTAL V2 =
IF (
MAX ( Fact_Table[Date] ) > SELECTEDVALUE ( Disconnected_Date_Table[Date] ),
BLANK (),
CALCULATE (
SUM ( Fact_Table[Sales] ),
FILTER (
ALLSELECTED ( Fact_Table[Date] ),
ISONORAFTER ( Fact_Table[Date], MAX ( Fact_Table[Date] ), DESC )
)
)
)
@AccrualJoke ah perfect, I am glad you got it to work 🙂
Respectfully,
Zoe Douglas (DataZoe)
Follow me on LinkedIn at https://www.linkedin.com/in/zoedouglas-data
See my reports and blog at https://www.datazoepowerbi.com/
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
105 | |
99 | |
98 | |
38 | |
37 |
User | Count |
---|---|
152 | |
120 | |
73 | |
72 | |
63 |