ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Worksheet Functions (https://www.excelbanter.com/excel-worksheet-functions/)
-   -   SUM a Vlookup Array Formula (https://www.excelbanter.com/excel-worksheet-functions/450528-sum-vlookup-array-formula.html)

Dave011070

SUM a Vlookup Array Formula
 
Hi Guys,

hoping someone can help with something that is bugging me and I cannot get working.
I have a Pivot Table containing data from a MS Query download with data split by month and year across from column B, and the relevant lookup codes in column A, and an Excel Sheet with various VLOOKUP's pulling back the correct data based on a selected Month and Year all fine (using =VLOOKUP($A16&"-"&$B16,DATA,D$5,FALSE).
However due to the datasource there are a number of replications in the data that I need to SUM however I cannot get any of the formulas to work (SUM, SUMIF, SUMPRODUCT etc).
The issue (as I see it) is I can sum up the occurrences where I can pre-determine the column (ie with a SUMIF) but I have the need to use the Column Index Number in the VLOOKUP I have to dynamically change the lookup based on the user's selection.
is this possible?? im struggling here and hoping someone has a solution of sorts
Thanks in advance

Claus Busch

SUM a Vlookup Array Formula
 
Hi Dave,

Am Fri, 19 Dec 2014 16:52:50 +0000 schrieb Dave011070:

=VLOOKUP($A16&"-"&$B16,DATA,D$5,FALSE).


try:
=SUM(INDEX(Data,,MATCH(A16&"-"&B16,INDEX(Data,1,),0)))

If it does not work please offer your data


Regards
Claus B.
--
Vista Ultimate / Windows7
Office 2007 Ultimate / 2010 Professional

Claus Busch

SUM a Vlookup Array Formula
 
Hi Dave,

Am Fri, 19 Dec 2014 19:07:12 +0100 schrieb Claus Busch:

=SUM(INDEX(Data,,MATCH(A16&"-"&B16,INDEX(Data,1,),0)))


if you want sum the same column you detected with VLOOKUP then try:
=SUM(INDEX(Data,,MATCH(A16&"-"&B16,INDEX(Data,1,),0)+$D$5-1))


Regards
Claus B.
--
Vista Ultimate / Windows7
Office 2007 Ultimate / 2010 Professional

Dave011070

1 Attachment(s)
thank you so much for the reply Claus, really appreciated.

unfortunately it doesn't work for me but I am hoping if you have a few minutes you may see what I am trying to do in the attached spreadsheet.

I have had to cut it right down to an example of the problem as it is a 5MB file otherwise, but I hope it gives you an idea of what I am trying to achieve

thank you again, really appreciate your help

Dave



Quote:

Originally Posted by Claus Busch (Post 1619584)
Hi Dave,

Am Fri, 19 Dec 2014 19:07:12 +0100 schrieb Claus Busch:

=SUM(INDEX(Data,,MATCH(A16&"-"&B16,INDEX(Data,1,),0)))


if you want sum the same column you detected with VLOOKUP then try:
=SUM(INDEX(Data,,MATCH(A16&"-"&B16,INDEX(Data,1,),0)+$D$5-1))


Regards
Claus B.
--
Vista Ultimate / Windows7
Office 2007 Ultimate / 2010 Professional


Claus Busch

SUM a Vlookup Array Formula
 
Hi Dave,

Am Mon, 22 Dec 2014 14:28:12 +0000 schrieb Dave011070:

unfortunately it doesn't work for me but I am hoping if you have a few
minutes you may see what I am trying to do in the attached spreadsheet.


try it with:
=SUM(INDEX(Sheet1!A:CA,MATCH(A16&"-"&B16,Sheet1!A:A,0),))

or look he
https://onedrive.live.com/?cid=9378A...121822A3%21326
for your workbook


Regards
Claus B.
--
Vista Ultimate / Windows7
Office 2007 Ultimate / 2010 Professional


All times are GMT +1. The time now is 02:59 PM.

Powered by vBulletin® Copyright ©2000 - 2024, Jelsoft Enterprises Ltd.
ExcelBanter.com