By using this site, you agree to our updated Privacy Policy and our Terms of Use. Manage your Cookies Settings.
424,490 Members | 900 Online
Bytes IT Community
+ Ask a Question
Need help? Post your question and get tips & solutions from a community of 424,490 IT Pros & Developers. It's quick & easy.

Moving/Rolling Average in Ms Access Query

P: n/a
Hi,

Is there a way i can compute a moving/rolling average in ms access?

I have this excel spreadsheet (see below) and i would like to automate
it in ms access

%Change = (C5-D5)/D5

4WKAvg = SUM(E2:E5)/4
SUM(E3:E6)/4 Please note that the sum
SUM(E4:E7)/4 keeps moving down
1 A B C D E F
2 Type Wk CY LY %Change 4WKAvg
3 Cliff 1 92,694 94,584 -2.00%
4 Cliff 2 95,469 96,933 -1.51%
5 Cliff 3 95,547 93,377 2.32%
6 Cliff 4 91,190 93,670 -2.65% -0.96%
7 Cliff 5 86,484 95,336 -9.29% -2.78%
8 Cliff 6 88,639 96,093 -7.76% -4.34%
9 Cliff 7 87,806 91,529 -4.07% -5.94%
10 Cliff 8 88,304 100,801 -12.40% -8.38%
11 Cliff 9 92,804 87,008 6.66% -4.39%
12 Cliff 10 96,016 90,834 5.71% -1.02%
13 Cliff 11 83,913 90,849 -7.63% -1.92%
14 Cliff 12 85,099 90,501 -5.97% -0.31%
15 Cliff 13 88,120 92,875 -5.12% -3.25%
16 Cliff 14 91,543 95,175 -3.82% -5.63%
17 Cliff 15 87,951 94,230 -6.66% -5.39%
18 Cliff 16 84,613 94,353 -10.32% -6.48%
19 Cliff 17 86,839 95,123 -8.71% -7.38%
20 Cliff 18 92,835 94,459 -1.72% -6.85%
21 Cliff 19 88,335 94,366 -6.39% -6.79%
22 Cliff 20 87,844 92,018 -4.54% -5.34%
23 Cliff 21 85,180 92,309 -7.72% -5.09%
24 Cliff 22 98,069 102,387 -4.22% -5.72%
25 Cliff 23 86,591 91,446 -5.31% -5.45%
26 Cliff 24 88,477 90,901 -2.67% -4.98%
27 Cliff 25 87,011 90,550 -3.91% -4.03%
28 Cliff 26 86,707 92,550 -6.31% -4.55%
29 Cliff 27 90,295 91,558 -1.38% -3.57%
30 Cliff 28 86,512 89,333 -3.16% -3.69%
31 Cliff 29 85,952 88,909 -3.33% -3.54%
32 Cliff 30 86,556 93,452 -7.38% -3.81%
33 Cliff 31 93,673 97,677 -4.10% -4.49%
34 Cliff 32 93,430 94,635 -1.27% -4.02%
35 Cliff 33 87,205 90,475 -3.61% -4.09%
36 Cliff 34 86,777 90,646 -4.27% -3.31%
37 Cliff 35 86,735 93,755 -7.49% -4.16%
38 Cliff 36 87,036 91,286 -4.66% -5.01%
39 Cliff 37 87,041 91,788 -5.17% -5.40%
40 Cliff 38 86,047 90,821 -5.26% -5.64%
41 Cliff 39 88,010 91,333 -3.64% -4.68%
42 Cliff 40 88,065 90,572 -2.77% -4.21%
43 Cliff 41 89,917 92,865 -3.17% -3.71%
44 Cliff 42 95,440 97,788 -2.40% -3.00%
45 Cliff 43 104,325 107,070 -2.56% -2.73%
46 Cliff 44 85,918 91,699 -6.30% -3.61%
47 Cliff 45 89,328 91,733 -2.62% -3.47%
48 Cliff 46 88,819 97,227 -8.65% -5.03%
49 Cliff 47 92,835 94,459 -1.72% -4.82%
50 Cliff 48 88,335 94,366 -6.39% -4.85%
51 Cliff 49 87,844 92,018 -4.54% -5.32%
52 Cliff 50 85,180 92,309 -7.72% -5.09%
53 Cliff 51 98,069 102,387 -4.22% -5.72%
54 Cliff 52 86,591 91,446 -5.31% -5.45%
I am stuck and will really appreciate any help
Thanks in adavance
Cliff

Nov 13 '05 #1
Share this Question
Share on Google+
4 Replies


P: n/a
-----BEGIN PGP SIGNED MESSAGE-----
Hash: SHA1

I believe something like this:

SELECT Type, WK, CY, LY, (CY-LY)/LY As PctChange,
(SELECT Avg((CY-LY)/LY)
FROM table_name
WHERE Type=A.Type
AND WK BETWEEN A.WK-5 And A.WK-1) As AvgPrev4Weeks
FROM table_name AS A
ORDER BY Type, WK
GROUP BY Type, WK, CY, LY, (CY-LY)/LY

See this site for a sample Access db of queries, for more info:

http://support.microsoft.com/default...b;en-us;207626

--
MGFoster:::mgf00 <at> earthlink <decimal-point> net
Oakland, CA (USA)

-----BEGIN PGP SIGNATURE-----
Version: PGP for Personal Privacy 5.0
Charset: noconv

iQA/AwUBQcpVMoechKqOuFEgEQKpCQCggO5xbsF8n+pnYybgFJOy70 tQk3YAoMbl
2pM/30pbpB1go9QewkPdXDED
=o59M
-----END PGP SIGNATURE-----
CliffKing wrote:
Hi,

Is there a way i can compute a moving/rolling average in ms access?

I have this excel spreadsheet (see below) and i would like to automate
it in ms access

%Change = (C5-D5)/D5

4WKAvg = SUM(E2:E5)/4
SUM(E3:E6)/4 Please note that the sum
SUM(E4:E7)/4 keeps moving down
1 A B C D E F
2 Type Wk CY LY %Change 4WKAvg
3 Cliff 1 92,694 94,584 -2.00%
4 Cliff 2 95,469 96,933 -1.51%
5 Cliff 3 95,547 93,377 2.32%
6 Cliff 4 91,190 93,670 -2.65% -0.96%
7 Cliff 5 86,484 95,336 -9.29% -2.78%
8 Cliff 6 88,639 96,093 -7.76% -4.34%
9 Cliff 7 87,806 91,529 -4.07% -5.94%
10 Cliff 8 88,304 100,801 -12.40% -8.38%
11 Cliff 9 92,804 87,008 6.66% -4.39%
< SNIP >

I am stuck and will really appreciate any help
Thanks in adavance

Nov 13 '05 #2

P: n/a
MGFoster wrote:
-----BEGIN PGP SIGNED MESSAGE-----
Hash: SHA1

I believe something like this:

SELECT Type, WK, CY, LY, (CY-LY)/LY As PctChange,
(SELECT Avg((CY-LY)/LY)
FROM table_name
WHERE Type=A.Type
AND WK BETWEEN A.WK-5 And A.WK-1) As AvgPrev4Weeks
FROM table_name AS A
ORDER BY Type, WK
GROUP BY Type, WK, CY, LY, (CY-LY)/LY

See this site for a sample Access db of queries, for more info:

http://support.microsoft.com/default...b;en-us;207626


Correction:

The main query doesn't need the GROUP BY line.
--
MGFoster:::mgf00 <at> earthlink <decimal-point> net
Oakland, CA (USA)
Nov 13 '05 #3

P: n/a
Thanks so much for you response.
i tried to use the sql statement but i am getting this error 3075:

"BETWEEN operator without AND in query expression 'TYPE]=[TYPE] AND
[WK] BETWEEN (([WK]-5 AND [WK]-1)"

This is the table i am using:

Type Wk CY LY
Cliff 1.00 92,694.14 94,584.47
Cliff 2.00 95,468.55 96,933.28
Cliff 3.00 95,547.45 93,377.15
Cliff 4.00 91,189.98 93,669.53
Cliff 5.00 86,484.01 95,336.38
Cliff 6.00 88,639.29 96,092.55
Cliff 7.00 87,806.36 91,528.59
Cliff 8.00 88,304.46 100,800.70
Cliff 9.00 92,804.12 87,008.28
Cliff 10.00 96,016.44 90,834.26
Cliff 11.00 83,913.27 90,848.96
Cliff 12.00 85,098.99 90,500.50
Cliff 13.00 88,120.20 92,874.74
Cliff 14.00 91,542.87 95,175.41
Cliff 15.00 87,950.52 94,230.31
Cliff 16.00 84,613.37 94,353.02
Cliff 17.00 86,838.74 95,123.23
Cliff 18.00 92,834.60 94,459.23
Cliff 19.00 88,334.89 94,365.75
Cliff 20.00 87,844.46 92,017.95
Cliff 21.00 85,180.26 92,309.28
Cliff 22.00 98,068.86 102,386.60
Cliff 23.00 86,590.71 91,445.52
Cliff 24.00 88,476.57 90,900.55
Cliff 25.00 87,010.58 90,549.88
Cliff 26.00 86,706.62 92,549.55
Cliff 27.00 90,294.59 91,558.38
Cliff 28.00 86,512.39 89,332.52
Cliff 29.00 85,951.52 88,909.26
Cliff 30.00 86,556.10 93,451.94
Cliff 31.00 93,672.80 97,676.61
Cliff 32.00 93,430.38 94,634.54
Cliff 33.00 87,204.79 90,474.68
Cliff 34.00 86,776.79 90,645.77
Cliff 35.00 86,734.79 93,754.53
Cliff 36.00 87,035.59 91,285.72
Cliff 37.00 87,040.73 91,787.87
Cliff 38.00 86,047.33 90,821.02
Cliff 39.00 88,009.64 91,333.39
Cliff 40.00 88,064.84 90,571.89
Cliff 41.00 89,916.64 92,864.86
Cliff 42.00 95,439.89 97,788.35
Cliff 43.00 104,324.90 107,070.20
Cliff 44.00 85,918.27 91,699.13
Cliff 45.00 89,327.67 91,732.71
Cliff 46.00 88,819.06 97,227.32
Cliff 47.00 92,834.60 94,459.23
Cliff 48.00 88,334.89 94,365.75
Cliff 49.00 87,844.46 92,017.95
Cliff 50.00 85,180.26 92,309.28
Cliff 51.00 98,068.86 102,386.60
Cliff 52.00 86,590.71 91,445.52

The sql to the query is:

SELECT example.Type, example.Wk, example.CY, example.LY,
([cy]-[ly])/[ly] AS PctChange, (SELECT Avg(([CY]-[LY])/[LY]) FROM
example WHERE [Type] =
[TYPE] AND [Wk] BETWEEN ([Wk]-5 and [Wk]-1)) AS AvgPrev4Weeks
FROM example;

where am i going wrong? thanks

MGFoster wrote:
MGFoster wrote:
-----BEGIN PGP SIGNED MESSAGE-----
Hash: SHA1

I believe something like this:

SELECT Type, WK, CY, LY, (CY-LY)/LY As PctChange,
(SELECT Avg((CY-LY)/LY)
FROM table_name
WHERE Type=A.Type
AND WK BETWEEN A.WK-5 And A.WK-1) As AvgPrev4Weeks
FROM table_name AS A
ORDER BY Type, WK
GROUP BY Type, WK, CY, LY, (CY-LY)/LY

See this site for a sample Access db of queries, for more info:

http://support.microsoft.com/default...b;en-us;207626


Correction:

The main query doesn't need the GROUP BY line.
--
MGFoster:::mgf00 <at> earthlink <decimal-point> net
Oakland, CA (USA)


Nov 13 '05 #4

P: n/a
-----BEGIN PGP SIGNED MESSAGE-----
Hash: SHA1

You're leaving out the table alias "A." on the WK column and the Type
column in the subquery. Try this:

SELECT Type, WK, CY, LY, (CY-LY)/LY As PctChange,

(SELECT Avg((CY-LY)/LY)
FROM example
WHERE Type=A.Type
AND WK BETWEEN A.WK-5 And A.WK-1) As AvgPrev4Weeks

FROM example AS A

ORDER BY Type, WK
--
MGFoster:::mgf00 <at> earthlink <decimal-point> net
Oakland, CA (USA)
-----BEGIN PGP SIGNATURE-----
Version: PGP for Personal Privacy 5.0
Charset: noconv

iQA/AwUBQctutYechKqOuFEgEQJI+QCgrapMvWfcIQPyz3951x+xgO b7yzgAoMv3
kiFGywIEgCzx1r8Wki3j/deK
=u4Rv
-----END PGP SIGNATURE-----
CliffKing wrote:
Thanks so much for you response.
i tried to use the sql statement but i am getting this error 3075:

"BETWEEN operator without AND in query expression 'TYPE]=[TYPE] AND
[WK] BETWEEN (([WK]-5 AND [WK]-1)"

This is the table i am using:

Type Wk CY LY
Cliff 1.00 92,694.14 94,584.47
Cliff 2.00 95,468.55 96,933.28 <SNIP> The sql to the query is:

SELECT example.Type, example.Wk, example.CY, example.LY,
([cy]-[ly])/[ly] AS PctChange, (SELECT Avg(([CY]-[LY])/[LY]) FROM
example WHERE [Type] =
[TYPE] AND [Wk] BETWEEN ([Wk]-5 and [Wk]-1)) AS AvgPrev4Weeks
FROM example;
MGFoster wrote:

SELECT Type, WK, CY, LY, (CY-LY)/LY As PctChange,
(SELECT Avg((CY-LY)/LY)
FROM table_name
WHERE Type=A.Type
AND WK BETWEEN A.WK-5 And A.WK-1) As AvgPrev4Weeks
FROM table_name AS A
ORDER BY Type, WK

Nov 13 '05 #5

This discussion thread is closed

Replies have been disabled for this discussion.