Home |
Search |
Today's Posts |
|
#1
![]() |
|||
|
|||
![]()
Could someone please show me a formula to average weekly data into monthly.
I have a spreadhseet: Date Data 2/1/99 1.15 9/1/99 2.42 16/1/99 1.24 through to..... 25/2/05 3.54 How can i calculate the average of every month between 1999 and 2005? In other words, i need something which looks up all the weeks in a particular month (ie Jan 2001) and averages them out into a table: 1999 2000 ......... 2005 Jan 2.45 6.42 Feb 3.64 etc etc. I was thinking vlookup, but don't know how to average in a vlookup. I would appreciate some help. |
#2
![]() |
|||
|
|||
![]()
format dates as month-year (in excel 2000 it is given as <march-98
it will be february-99, march-99 etc then click data-subtotals in the subtotals window at each change date usefunciton average add shubtotal to check ---dates click ok =========================== Kaine wrote in message ... Could someone please show me a formula to average weekly data into monthly. I have a spreadhseet: Date Data 2/1/99 1.15 9/1/99 2.42 16/1/99 1.24 through to..... 25/2/05 3.54 How can i calculate the average of every month between 1999 and 2005? In other words, i need something which looks up all the weeks in a particular month (ie Jan 2001) and averages them out into a table: 1999 2000 ......... 2005 Jan 2.45 6.42 Feb 3.64 etc etc. I was thinking vlookup, but don't know how to average in a vlookup. I would appreciate some help. |
#3
![]() |
|||
|
|||
![]()
One way to get it in the way you want ..
Assume the source data below is in Sheet1, cols A and B, data from row2 down Date Data 2/1/99 1.15 9/1/99 2.42 16/1/99 1.24 through to..... 25/2/05 3.54 and assume this table below is in Sheet2, with col A containing *text* (in A2 down): Jan, Feb, .. and with cols B, C .. across housing: 1999, 2000, .. 1999 2000 ......... 2005 Jan 2.45 6.42 Feb 3.64 etc etc. Put in the formula bar for B2: =IF(ISERROR(AVERAGE(IF((TEXT(Sheet1!$A$2:$A$100,"m mm")=$A2)*(TEXT(Sheet1!$A$ 2:$A$100,"yyyy")+0=B$1),Sheet1!$B$2:$B$100))),"",A VERAGE(IF((TEXT(Sheet1!$A$ 2:$A$100,"mmm")=$A2)*(TEXT(Sheet1!$A$2:$A$100,"yyy y")+0=B$1),Sheet1!$B$2:$B$ 100))) Array-enter the formula in B2, i.e. press CTRL+SHIFT+ENTER instead of just pressing ENTER Copy B2 across and fill down to populate the table (or copy down and fill across) Blanks "" will be returned (instead of #DIV/0!) if there are divisional calc errors (e.g.: 0/0, xx/0) for a neater output in the table Adapt to suit the 2 ranges: $A$2:$A$100, $B$2:$B$100 and the source data sheetname: Sheet1 -- Rgds Max xl 97 --- GMT+8, 1° 22' N 103° 45' E xdemechanik <atyahoo<dotcom ---- "Kaine" wrote in message ... Could someone please show me a formula to average weekly data into monthly. I have a spreadhseet: How can i calculate the average of every month between 1999 and 2005? In other words, i need something which looks up all the weeks in a particular month (ie Jan 2001) and averages them out into a table: 1999 2000 ......... 2005 Jan 2.45 6.42 Feb 3.64 etc etc. I was thinking vlookup, but don't know how to average in a vlookup. I would appreciate some help. |
Reply |
Thread Tools | Search this Thread |
Display Modes | |
|
|
![]() |
||||
Thread | Forum | |||
Converting data from a pasted document | Excel Worksheet Functions | |||
Pulling data from 1 sheet to another | Excel Worksheet Functions | |||
Weekly data allocated to months | Excel Worksheet Functions | |||
Weekly data allocated to months | Excel Worksheet Functions | |||
Weekly data into Calendar Weeks | Excel Worksheet Functions |