PowerPivot - New measure - calculate based on two criteria

tbablue

Active Member
Joined
Apr 29, 2007
Messages
488
Office Version
  1. 365
Platform
  1. Windows
Hi Forum,

Quite straightforward I'm sure - but I'm new to measures in PowerPivot.

I have three columns; Definitive Name, Yr.Mnth & Employee FTE. The table name is 'Summary Query'.

I need a measure that will calculate Employee FTE based on the number of times that 'Definitive Name' appears in 'Yr.Mnth'.

In Excel it would be something like...

=SUMIFS([Employee FTE],[Yr.Mnth],[@[Yr.Mnth]],[Definitive Name],[@[Definitive Name]])/COUNTIFS([Yr.Mnth],[@[Yr.Mnth]],[Definitive Name],[@[Definitive Name]])


Any help would be gratefully rec'd.
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
SumIfs:=CALCULATE(SUM([Employee FTE]),FILTER(SummaryQuery,SummaryQuery[Definitive Name]=[Definitive Name]&&SummaryQuery[Yr.Mnth]=SummaryQuery[Yr.Mnth]))
CountIfs:=CALCULATE(COUNTROWS(SummaryQuery),FILTER(SummaryQuery,SummaryQuery[Definitive Name]=SummaryQuery[Definitive Name]&&SummaryQuery[Yr.Mnth]=SummaryQuery[Yr.Mnth]))
 
Upvote 0
Solution
SumIfs:=CALCULATE(SUM([Employee FTE]),FILTER(SummaryQuery,SummaryQuery[Definitive Name]=[Definitive Name]&&SummaryQuery[Yr.Mnth]=SummaryQuery[Yr.Mnth]))
CountIfs:=CALCULATE(COUNTROWS(SummaryQuery),FILTER(SummaryQuery,SummaryQuery[Definitive Name]=SummaryQuery[Definitive Name]&&SummaryQuery[Yr.Mnth]=SummaryQuery[Yr.Mnth]))
Really grateful for your time and attention....

A small amount of tidying up the text (mostly spaces and apostrophes) appears to have answered the exam question ...you've saved my sanity!! TY!!

=CALCULATE(SUM([Employee FTE]),FILTER('Summary Query','Summary Query'[Definitive Name]=[Definitive Name]&&'Summary Query'[Yr.Mnth]='Summary Query'[Yr.Mnth]))/CALCULATE(COUNTROWS('Summary Query'),FILTER('Summary Query','Summary Query'[Definitive Name]='Summary Query'[Definitive Name]&&'Summary Query'[Yr.Mnth]='Summary Query'[Yr.Mnth]))

Quick supplemental question: I've never come across a double ampersand - is that the convention for joining multiple criteria?

I'll mark the answer you've supplied as a working solution.
 
Upvote 0

Forum statistics

Threads
1,223,711
Messages
6,174,025
Members
452,542
Latest member
Bricklin

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top