Home |
Search |
Today's Posts |
|
#1
![]() |
|||
|
|||
![]()
I have a formula that sums a range from a column in another workbook. The
formula works fine when the source workbook is open. However, when the source workbook is closed, I get a #VALUE! error or a !REF# error depending on the function I use. I've tried to compute the sum using both the OFFSET and INDEX functions, but to no avail. Here are two things I've tried: 1. Using the OFFSET function: =SUM(OFFSET('[Daily-Data.xls]Daily'!$F$5,273,0,303,1)) When the Daily-Data.xls workbook is closed I get a #VALUE! error. I heard that OFFSET is a volatile function. So I rewrote my formula to use the non-volatile INDEX function. 2. Using the INDEX function: =SUM(INDEX('[Daily-Data.xls]Daily'!$F$5:$F$369,274):INDEX('[Daily-Data.xls]Daily'!$F$5:$F$369,302)) However, when the Daily-Data.xls workbook is closed I get a #REF! error. Both of these formulas work fine when the source workbook is open. What's the best way to sum a range of columns from another worksheet without having to open the source worksheet each time?? Thanks! |
#2
![]() |
|||
|
|||
![]()
CMB wrote...
.... 1. Using the OFFSET function: =SUM(OFFSET('[Daily-Data.xls]Daily'!$F$5,273,0,303,1)) .... 2. Using the INDEX function: =SUM(INDEX('[Daily-Data.xls]Daily'!$F$5:$F$369,274): INDEX('[Daily-Data.xls]Daily'!$F$5:$F$369,302)) .... Both of these formulas work fine when the source workbook is open. .... These two formulas sum different ranges. The OFFSET formula sums F278:F580 while the INDEX formula sums F278:F306. Which do you want? The short but technical answer is that you're using both OFFSET and INDEX to return range references, but external references into closed workbooks *NEVER* resolve to range references, rather they're returned as arrays. You need to use something like the following. =SUMPRODUCT('[Daily-Data.xls]Daily'!$F$1:$F$580, (ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)=k) *(ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)<=n)) If you want to sum F278:F580, make it =SUMPRODUCT('[Daily-Data.xls]Daily'!$F$1:$F$580, (ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)=278) *(ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)<=580)) |
#3
![]() |
|||
|
|||
![]()
Thanks! That did the trick. Also, I was trying to sum F278:F306. I just
had some fat fingers when I typed the OFFSET formula. "Harlan Grove" wrote: CMB wrote... .... 1. Using the OFFSET function: =SUM(OFFSET('[Daily-Data.xls]Daily'!$F$5,273,0,303,1)) .... 2. Using the INDEX function: =SUM(INDEX('[Daily-Data.xls]Daily'!$F$5:$F$369,274): INDEX('[Daily-Data.xls]Daily'!$F$5:$F$369,302)) .... Both of these formulas work fine when the source workbook is open. .... These two formulas sum different ranges. The OFFSET formula sums F278:F580 while the INDEX formula sums F278:F306. Which do you want? The short but technical answer is that you're using both OFFSET and INDEX to return range references, but external references into closed workbooks *NEVER* resolve to range references, rather they're returned as arrays. You need to use something like the following. =SUMPRODUCT('[Daily-Data.xls]Daily'!$F$1:$F$580, (ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)=k) *(ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)<=n)) If you want to sum F278:F580, make it =SUMPRODUCT('[Daily-Data.xls]Daily'!$F$1:$F$580, (ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)=278) *(ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)<=580)) |
#4
![]() |
|||
|
|||
![]()
CMB wrote...
.... 1. Using the OFFSET function: =SUM(OFFSET('[Daily-Data.xls]Daily'!$F$5,273,0,303,1)) .... 2. Using the INDEX function: =SUM(INDEX('[Daily-Data.xls]Daily'!$F$5:$F$369,274): INDEX('[Daily-Data.xls]Daily'!$F$5:$F$369,302)) .... Both of these formulas work fine when the source workbook is open. .... These two formulas sum different ranges. The OFFSET formula sums F278:F580 while the INDEX formula sums F278:F306. Which do you want? The short but technical answer is that you're using both OFFSET and INDEX to return range references, but external references into closed workbooks *NEVER* resolve to range references, rather they're returned as arrays. You need to use something like the following. =SUMPRODUCT('[Daily-Data.xls]Daily'!$F$1:$F$580, (ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)=k) *(ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)<=n)) If you want to sum F278:F580, make it =SUMPRODUCT('[Daily-Data.xls]Daily'!$F$1:$F$580, (ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)=278) *(ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)<=580)) |
#5
![]() |
|||
|
|||
![]()
CMB wrote...
.... 1. Using the OFFSET function: =SUM(OFFSET('[Daily-Data.xls]Daily'!$F$5,273,0,303,1)) .... 2. Using the INDEX function: =SUM(INDEX('[Daily-Data.xls]Daily'!$F$5:$F$369,274): INDEX('[Daily-Data.xls]Daily'!$F$5:$F$369,302)) .... Both of these formulas work fine when the source workbook is open. .... These two formulas sum different ranges. The OFFSET formula sums F278:F580 while the INDEX formula sums F278:F306. Which do you want? The short but technical answer is that you're using both OFFSET and INDEX to return range references, but external references into closed workbooks *NEVER* resolve to range references, rather they're returned as arrays. You need to use something like the following. =SUMPRODUCT('[Daily-Data.xls]Daily'!$F$1:$F$580, (ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)=k) *(ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)<=n)) If you want to sum F278:F580, make it =SUMPRODUCT('[Daily-Data.xls]Daily'!$F$1:$F$580, (ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)=278) *(ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)<=580)) |
#6
![]() |
|||
|
|||
![]()
CMB wrote...
.... 1. Using the OFFSET function: =SUM(OFFSET('[Daily-Data.xls]Daily'!$F$5,273,0,303,1)) .... 2. Using the INDEX function: =SUM(INDEX('[Daily-Data.xls]Daily'!$F$5:$F$369,274): INDEX('[Daily-Data.xls]Daily'!$F$5:$F$369,302)) .... Both of these formulas work fine when the source workbook is open. .... These two formulas sum different ranges. The OFFSET formula sums F278:F580 while the INDEX formula sums F278:F306. Which do you want? The short but technical answer is that you're using both OFFSET and INDEX to return range references, but external references into closed workbooks *NEVER* resolve to range references, rather they're returned as arrays. You need to use something like the following. =SUMPRODUCT('[Daily-Data.xls]Daily'!$F$1:$F$580, (ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)=k) *(ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)<=n)) If you want to sum F278:F580, make it =SUMPRODUCT('[Daily-Data.xls]Daily'!$F$1:$F$580, (ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)=278) *(ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)<=580)) |
#7
![]() |
|||
|
|||
![]()
In case you can't see your posts, I see 4 of them.
-- HTH, RD ============================================== Please keep all correspondence within the Group, so all may benefit! ============================================== "Harlan Grove" wrote in message oups.com... CMB wrote... ... 1. Using the OFFSET function: =SUM(OFFSET('[Daily-Data.xls]Daily'!$F$5,273,0,303,1)) ... 2. Using the INDEX function: =SUM(INDEX('[Daily-Data.xls]Daily'!$F$5:$F$369,274): INDEX('[Daily-Data.xls]Daily'!$F$5:$F$369,302)) ... Both of these formulas work fine when the source workbook is open. ... These two formulas sum different ranges. The OFFSET formula sums F278:F580 while the INDEX formula sums F278:F306. Which do you want? The short but technical answer is that you're using both OFFSET and INDEX to return range references, but external references into closed workbooks *NEVER* resolve to range references, rather they're returned as arrays. You need to use something like the following. =SUMPRODUCT('[Daily-Data.xls]Daily'!$F$1:$F$580, (ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)=k) *(ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)<=n)) If you want to sum F278:F580, make it =SUMPRODUCT('[Daily-Data.xls]Daily'!$F$1:$F$580, (ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)=278) *(ROW('[Daily-Data.xls]Daily'!$F$1:$F$580)<=580)) |
Reply |
Thread Tools | Search this Thread |
Display Modes | |
|
|
![]() |
||||
Thread | Forum | |||
How to find links to another workbook? | Excel Discussion (Misc queries) | |||
inter workbook links do not update even when both are open ??? | Excel Discussion (Misc queries) | |||
Edit Links: make update manual | Excel Discussion (Misc queries) | |||
Emailing a workbook with links | Excel Worksheet Functions | |||
Manually update links | Excel Worksheet Functions |