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

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes! Register now.

Reply
Beerlover
Frequent Visitor

Sales for Region are saved in two separate columns in my model

Sales for Region are saved in two separate columns in my model. For Region-A,B,C & F correct value is in Sales 1 and for Region - D, E - it is in Sales 2. By desired output is to have all regions together in one matrix table that contain column sales with correct sales value and further I have to roll up the data based on date selection to rolling 3,6,12 months and YTD.

Beerlover_2-1713904232231.png

 

Second part, I am using dynamic slicer in the table ...based on selection from the slicer we can also see Organisation->Account->Country->Region->province-> category-> sub-category->product -> Item( depends on end user what combination they choose).

 

@lbendlin @amitchandak @Ritaf1983 @Ashish_Mathur 

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @Beerlover 

 

@Ashish_Mathur , thanks for your concern about this case.

 

I added a Date column to your sample data. Hopefully the following will help.

vxuxinyimsft_1-1714038290015.png

 

1. Create a calculated column as follows

 

Final Sales = IF([Region] = "D" || [Region] = "E", [Sales2], [Sales1])

 

 

Result:

vxuxinyimsft_2-1714038378593.png

 

2. Create a calculated table to be used as a slicer

 

Date = CALENDAR(DATE(2024, 4, 1), TODAY())

 

vxuxinyimsft_3-1714038566709.png

 

Create the following measure to get rolling three-month data

 

R3M = 
VAR _last3months = EOMONTH(SELECTEDVALUE('Date'[Date]), -4)
VAR _diff = DATEDIFF(EOMONTH(SELECTEDVALUE('Date'[Date]), -1) + 1, SELECTEDVALUE('Date'[Date]), DAY) + 1
VAR _last3monthsresult = _last3months + _diff
RETURN
CALCULATE(SUM('Table'[Final Sales]), FILTER(ALLEXCEPT('Table', 'Table'[Region]), MAX([Date]) >= _last3monthsresult && SELECTEDVALUE('Date'[Date])))

 

 

Result:

vxuxinyimsft_4-1714038599060.png

 

You can calculate the rolling 6 month and rolling 12 month values in the same way.

 

3. Create a measure to calculate the YTD

 

YTD = 
VAR _date = SELECTEDVALUE('Date'[Date])
VAR _year = YEAR(_date)
RETURN
CALCULATE(SUM('Table'[Final Sales]), FILTER(ALLEXCEPT('Table', 'Table'[Region]), [Date] >= DATE(_year, 1, 1) && [Date] <= _date))

 

 

Result:

vxuxinyimsft_5-1714039122992.png

I'm a little confused about your second part request, could you please reflect the results you want in the sample data? That would be very helpful.

 

Best Regards,
Yulia Xu

 

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

View solution in original post

3 REPLIES 3
Beerlover
Frequent Visitor

Thank you everyone for the response. I am checking it now and will respond soon.

Anonymous
Not applicable

Hi @Beerlover 

 

@Ashish_Mathur , thanks for your concern about this case.

 

I added a Date column to your sample data. Hopefully the following will help.

vxuxinyimsft_1-1714038290015.png

 

1. Create a calculated column as follows

 

Final Sales = IF([Region] = "D" || [Region] = "E", [Sales2], [Sales1])

 

 

Result:

vxuxinyimsft_2-1714038378593.png

 

2. Create a calculated table to be used as a slicer

 

Date = CALENDAR(DATE(2024, 4, 1), TODAY())

 

vxuxinyimsft_3-1714038566709.png

 

Create the following measure to get rolling three-month data

 

R3M = 
VAR _last3months = EOMONTH(SELECTEDVALUE('Date'[Date]), -4)
VAR _diff = DATEDIFF(EOMONTH(SELECTEDVALUE('Date'[Date]), -1) + 1, SELECTEDVALUE('Date'[Date]), DAY) + 1
VAR _last3monthsresult = _last3months + _diff
RETURN
CALCULATE(SUM('Table'[Final Sales]), FILTER(ALLEXCEPT('Table', 'Table'[Region]), MAX([Date]) >= _last3monthsresult && SELECTEDVALUE('Date'[Date])))

 

 

Result:

vxuxinyimsft_4-1714038599060.png

 

You can calculate the rolling 6 month and rolling 12 month values in the same way.

 

3. Create a measure to calculate the YTD

 

YTD = 
VAR _date = SELECTEDVALUE('Date'[Date])
VAR _year = YEAR(_date)
RETURN
CALCULATE(SUM('Table'[Final Sales]), FILTER(ALLEXCEPT('Table', 'Table'[Region]), [Date] >= DATE(_year, 1, 1) && [Date] <= _date))

 

 

Result:

vxuxinyimsft_5-1714039122992.png

I'm a little confused about your second part request, could you please reflect the results you want in the sample data? That would be very helpful.

 

Best Regards,
Yulia Xu

 

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

Ashish_Mathur
Super User
Super User

Hi,

Sharing a picture is absolutely useless.  Atleast share data in a format that can be pasted in an MS Excel file.  Also, if you want running totals, then you shuould also have a date column.  Why have you not shown that?  Furthermore, when does the FY start?


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Helpful resources

Announcements
September Power BI Update Carousel

Power BI Monthly Update - September 2025

Check out the September 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors
Top Kudoed Authors