+ Reply to Thread
Results 1 to 7 of 7

Links only update when external workbook is open

  1. #1
    CMB
    Guest

    Links only update when external workbook is open

    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. #2
    Harlan Grove
    Guest

    Re: Links only update when external workbook is open

    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. #3
    Harlan Grove
    Guest

    Re: Links only update when external workbook is open

    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. #4
    Harlan Grove
    Guest

    Re: Links only update when external workbook is open

    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. #5
    Harlan Grove
    Guest

    Re: Links only update when external workbook is open

    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. #6
    RagDyer
    Guest

    Re: Links only update when external workbook is open

    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" <hrlngrv@aol.com> wrote in message
    news:1131053547.781036.248240@o13g2000cwo.googlegroups.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))
    >



  7. #7
    CMB
    Guest

    Re: Links only update when external workbook is open

    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))
    >
    >


+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1