Reply
 
LinkBack Thread Tools Search this Thread Display Modes
  #1   Report Post  
Lynn
 
Posts: n/a
Default SumIf - Linked Workbook - #VALUE

I am using the following function in Master.xls

=SUMIF(Source.xls!Colours,A1,Source.xls!Values)

As long as both workbooks are open, it calculates properly.

When I close both workbooks, reopen Master.xls & choose to update linked
formulas, the #VALUE error appears. I tried replacing named ranges with cell
references - same error.

As soon as I open Source.xls, the formula calculates properly.

Why is #VALUE appearing & how can I open only Master.xls & have the formuala
display the calculation?

I also have =SUM(Source.xls!Values) in Master.xls which does calculate
correctly when Source.xls is closed.

HELP!
  #2   Report Post  
Harlan Grove
 
Posts: n/a
Default

Lynn wrote...
I am using the following function in Master.xls

=SUMIF(Source.xls!Colours,A1,Source.xls!Values)

As long as both workbooks are open, it calculates properly.

When I close both workbooks, reopen Master.xls & choose to update linked
formulas, the #VALUE error appears. I tried replacing named ranges with cell
references - same error.

As soon as I open Source.xls, the formula calculates properly.

Why is #VALUE appearing & how can I open only Master.xls & have the formuala
display the calculation?

....

Excel returns references to blocks of cells in closed workbooks as
arrays. They're not, strictly speaking, ranges in the way Excel works
internally with ranges. SUMIF only accepts true range references in its
first and third arguments. When the other workbook is open, references
to block of cells in it are returned as ranges. That's not the case
when it's closed. That's the cause of your problem.

In short, use SUMIF and COUNTIF only with references to ranges in the
same workbook. If you need conditional summing or counting in other
workbooks, use SUMPRODUCT, e.g.,

=SUMPRODUCT(--(Source.xls!Colours=A1),Source.xls!Values)

(assuming A1 contains an equality criterion without wildcards).

Reply
Thread Tools Search this Thread
Search this Thread:

Advanced Search
Display Modes

Posting Rules

Smilies are On
[IMG] code is On
HTML code is Off
Trackbacks are On
Pingbacks are On
Refbacks are On


Similar Threads
Thread Thread Starter Forum Replies Last Post
Linked Data within workbook rudy1010 Excel Discussion (Misc queries) 1 August 11th 05 05:47 PM
Creating Linked Workbook file name using cell variables RichT Excel Worksheet Functions 5 April 13th 05 07:44 PM
Sumif Linking to Another Workbook error #VALUE! Tunde Excel Discussion (Misc queries) 16 March 4th 05 03:02 AM
SUMIF linked WBs giving OUT OF MEMORY Carl @ Flo-Products Excel Worksheet Functions 0 February 8th 05 07:09 PM
Update linked cells within a workbook??? Chance224 Links and Linking in Excel 4 January 21st 05 06:33 PM


All times are GMT +1. The time now is 06:28 AM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
Copyright ©2004-2025 ExcelBanter.
The comments are property of their posters.
 

About Us

"It's about Microsoft Excel"