+ Reply to Thread
Results 1 to 8 of 8

Formula not working

  1. #1
    Registered User
    Join Date
    10-13-2013
    Location
    Dublin
    MS-Off Ver
    Excel 2007
    Posts
    44

    Formula not working

    I am using Excel 2007
    Am trying to make a workbook with 10 worksheets. Sheets 1-9 are the same format, each with 12 columns, all the same layout. I want to SUM summarize onto sheet 10 a column from the other sheets, the criteria being that a col on each sheet (Catcode) has the same number as a col (Catno) on sheet 10. The formula I am trying to use in each cell of the Sheet10 cols is:
    SUMIF('Database1.xlsm'!Catcode,sheet10!Catno,'Database1.xlsm'!TP)
    Catcode is =Sheet1:Sheet9!$B$4:$B$41
    Catno is =Sheet10!$A$4:$A$58
    TP is =Sheet1:Sheet9!$KK$4:$K$41

    I have tried saving the formula as an array (Ctrl-SH-Enter) but to no effect. I get #VALUE in each cell.
    If I succeed I will be expanding the size of each Sheet 1-9 to a possible 3000 rows each.

    Any help would be welcome
    Billirl

  2. #2
    Forum Expert
    Join Date
    05-30-2012
    Location
    The Netherlands
    MS-Off Ver
    Office 365
    Posts
    14,987

    Re: Formula not working

    Why not put all data on 1 sheet (instead of 9 sheets).

    Then a pivot table can do the work for you.
    Notice my main language is not English.

    I appreciate it, if you reply on my solution.

    If you are satisfied with the solution, please mark the question solved.

    You can add reputation by clicking on the star * add reputation.

  3. #3
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    2016
    Posts
    14,675

    Re: Formula not working

    Hello Billirl,

    You can't use a 3d reference like that in SUMIF - try this formula in Sheet10 row 4 copied down

    =SUMPRODUCT(SUMIF(INDIRECT("Sheet"&{1,2,3,4,5,6,7,8,9}&"!B4:B41"),A4,INDIRECT("Sheet"&{1,2,3,4,5,6,7,8,9}&"!K4:K41")))
    Audere est facere

  4. #4
    Registered User
    Join Date
    10-13-2013
    Location
    Dublin
    MS-Off Ver
    Excel 2007
    Posts
    44

    Re: Formula not working

    Thanks, but does not work. All Indirects show up with #Value from each sheet on evaluating formula. result overall =0 in Sheet10:Col 6, copied down. Does the Col make a difference?
    I do not want to append as I want to keep each page discrete for later examination.
    I note your ref to 3-D but have not seen this stated anywhere - this is why I tried SUMIF.
    Regards

  5. #5
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    2016
    Posts
    14,675

    Re: Formula not working

    Are you using exactly the formula I suggested? Are the sheets actually called sheet1, sheet2, sheet3 etc.?

    I created a small test version and it works OK for me.......

  6. #6
    Registered User
    Join Date
    10-13-2013
    Location
    Dublin
    MS-Off Ver
    Excel 2007
    Posts
    44

    Re: Formula not working

    Sincere apologies. Transcribing with my eyesight and an old monitor was not a good idea. I copied it and it worked perfectly.
    Sincere thamks.

  7. #7
    Forum Contributor arlu1201's Avatar
    Join Date
    09-09-2011
    Location
    Bangalore, India
    MS-Off Ver
    Excel 2003 & 2007
    Posts
    19,166

    Re: Formula not working

    Based on your last post in this thread, its apparent that you are satisfied with the solution(s) you've received and have solved your question, but you haven't marked your thread as "SOLVED". I will do it for you this time.

    In future, to mark your thread as Solved, you can do the following -
    Select Thread Tools-> Mark thread as Solved.

    Incase your issue is not solved, you can undo it as follows -
    Select Thread Tools-> Mark thread as Unsolved.

    Also, since you are relatively new to the forum, i would like to inform you that you can thank those who have helped you by clicking the small star icon located in the lower left corner of the post which helped you. This adds to the reputation of the person who has taken the time to help you.
    If I have helped, Don't forget to add to my reputation (click on the star below the post)
    Don't forget to mark threads as "Solved" (Thread Tools->Mark thread as Solved)
    Use code tags when posting your VBA code: [code] Your code here [/code]

  8. #8
    Registered User
    Join Date
    10-13-2013
    Location
    Dublin
    MS-Off Ver
    Excel 2007
    Posts
    44

    Unhappy Re: Formula not working

    Sorry for the discourtesy shown. It was through ignorance and not reading the rules properly.
    Will try to conform in future.

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. Correct/Working (Index,Match) formula not working between cells
    By barnerd in forum Excel Formulas & Functions
    Replies: 17
    Last Post: 02-11-2014, 01:20 PM
  2. Replies: 3
    Last Post: 10-10-2013, 10:15 PM
  3. Replies: 9
    Last Post: 03-08-2013, 11:50 AM
  4. Replies: 2
    Last Post: 08-17-2012, 08:16 AM
  5. Replies: 2
    Last Post: 08-01-2012, 11:53 AM

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