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
chrisb80
New Member

Average between summarized values

Hi, I am sorry for the newbie question but I am running into errors trying to calculate the average between the values in two matrices.

I understand that I need to build a relationship between the two tables with the names. However, I do not understand how I can access the summarized values by month. Would I need to create a new column?

I basically want to create a table that shows the average per person per month of the units specified. Also, the second table I was provided, the column names are in Text format and not formatted as Date. When I change it, the true values change. These are not the real values, just fake data to give an idea. Thank you so much for the help! if somebody could point me into the right direction

 

https://drive.google.com/file/d/1cihF6IaMyZuTN-Ffa3TkYSajQKk94n3I/view?usp=sharing

https://drive.google.com/file/d/1__cfSPlg4B2iLivW4GqKsXjbV369DyCN/view?usp=sharing

https://drive.google.com/file/d/1no6ghilZG07_ZLlsEX1qka1McXSqcLZp/view?usp=sharing

1 ACCEPTED SOLUTION
v-yangliu-msft
Community Support
Community Support

Hi  @chrisb80 ,

Here are the steps you can follow:

Summarized values by month

1. Convert the [Date] of the table Date2 to Date/Time format by selecting Column tools.

vyangliumsft_0-1624349221355.png

2. Create calculated column.

Formatted_Date = Format('Data 2'[Date], "YYYY-MM")

3. Create calculated table.

Slice =
SELECTCOLUMNS('Data 1',"Slice",'Data 1'[Formatted_Date])

4. Create measure.

Measure =
var _1=SELECTEDVALUE('Slice'[Slice])
var _2=CALCULATE(SUM('Data 1'[Unit]),FILTER(ALL('Data 1'),'Data 1'[Formatted_Date]=_1))
var _3=CALCULATE(SUM('Data 2'[Unit]),FILTER(ALL('Data 2'),'Data 2'[Formatted_Date]=_1))
return
_2+_3

5. Select [Slice] of the table Slice as the slicer, and place [measure] in Card.

6. Result:

vyangliumsft_1-1624349221360.png

Shows the average per person per month of the units specified:

1. Create calculated table.

Table = UNION('Data 1','Data 2')

2. Place [Formatted_Date] of Table to Rows, [Name] to Columns, and [Unit] to Values.

3. Set [Unit] to Average

vyangliumsft_2-1624349221364.png

4. Result.

vyangliumsft_3-1624349221366.png

 

 

Best Regards,

Liu Yang

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

2 REPLIES 2
v-yangliu-msft
Community Support
Community Support

Hi  @chrisb80 ,

Here are the steps you can follow:

Summarized values by month

1. Convert the [Date] of the table Date2 to Date/Time format by selecting Column tools.

vyangliumsft_0-1624349221355.png

2. Create calculated column.

Formatted_Date = Format('Data 2'[Date], "YYYY-MM")

3. Create calculated table.

Slice =
SELECTCOLUMNS('Data 1',"Slice",'Data 1'[Formatted_Date])

4. Create measure.

Measure =
var _1=SELECTEDVALUE('Slice'[Slice])
var _2=CALCULATE(SUM('Data 1'[Unit]),FILTER(ALL('Data 1'),'Data 1'[Formatted_Date]=_1))
var _3=CALCULATE(SUM('Data 2'[Unit]),FILTER(ALL('Data 2'),'Data 2'[Formatted_Date]=_1))
return
_2+_3

5. Select [Slice] of the table Slice as the slicer, and place [measure] in Card.

6. Result:

vyangliumsft_1-1624349221360.png

Shows the average per person per month of the units specified:

1. Create calculated table.

Table = UNION('Data 1','Data 2')

2. Place [Formatted_Date] of Table to Rows, [Name] to Columns, and [Unit] to Values.

3. Set [Unit] to Average

vyangliumsft_2-1624349221364.png

4. Result.

vyangliumsft_3-1624349221366.png

 

 

Best Regards,

Liu Yang

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

TomMartens
Super User
Super User

Hey @chrisb80 ,

 

I have to admit that I do not fully understand your requirement, but nevertheless maybe this article Budget – DAX Patterns provides some ideas, it describes how to gain insight from data based on different granularity.

 

Next to that, it's also a best practice to use a dedicated calendar table, that contains all the necessary columns like date (connected to data 1) and month column in data 2.

 

Hopefully, this provides some ideas on how to tackle your challenge.

 

Regards,

Tom



Did I answer your question? Mark my post as a solution, this will help others!

Proud to be a Super User!
I accept Kudos 😉
Hamburg, Germany

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.