Conditional weighted average

Charles Bushby

New Member
Joined
Aug 10, 2005
Messages
42
Would anyone know how to work out the weighted average P Year based on the Area field for any given Species in the table below where Land Use can be either High Forest or Windblow and Forecast can only be F?

I can do this with sumproduct but am not sure how to have more than one allowable option in the Land Use field i.e. High Forest or Windblow


Area Land Use Species P year Forecast
10.00 High Forest SS 1995 F
5.00 High Forest LP 2000 F
200.00 Windblow SS 1950 F
4.00 High Forest NS 1968 F
30.00 Replanting SS 2019 F
4.00 High Forest MB 1850 N

If anyone can help I would be most obliged.

Charles
 

Excel Facts

Excel motto
Not everything I do at work revolves around Excel. Only the fun parts.
Hello Charles, try as follows for Species = "SS":

=SUMPRODUCT((Species="SS")*((LandUse="High Forest")+(LandUse="Windblow"))*(Forecast="F"),Area,PYear)/SUMPRODUCT((Species="SS")*((LandUse="High Forest")+(LandUse="Windblow"))*(Forecast="F"),Area)

Note + instead of * gives you an "OR" for the Landuse Category

This gives me 1952.14
 
Last edited:
Upvote 0
Hi Old Brewer,

It is similar to a normal average but one can weight the average with data from another field. If you do a search on the internet for weighted averages you will find a lot of information that defines it very well.

Charles
 
Upvote 0

Forum statistics

Threads
1,223,236
Messages
6,170,915
Members
452,366
Latest member
TePunaBloke

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