Increment Sheet Count when dragging formula

arijitirf

Board Regular
Joined
Aug 11, 2016
Messages
110
Office Version
  1. 2016
Platform
  1. Windows
Hi!!!

I have a formula with SUMIF "=SUMIF('[Stock Register.xlsx]Stock Code 1'!$O$8:$O$500,"Issued to Sanitary Syndicate",'[Stock Register.xlsx]Stock Code 1'!$I$8:$I$500)" which basically sums up the total with if condition, but my problem is that I have above 570 sheets from which I am getting result in an another sheet and when I am dragging that formula it calculates the with same sheet name.

I want to get a formula which will automatically increment the sheet no and display result.

Thanks in advance.
 

Excel Facts

Format cells as time
Select range and press Ctrl+Shift+2 to format cells as time. (Shift 2 is the @ sign).
arijitirf, Good morning.

Try to use:

=SUMIF(INDIRECT("'[Stock Register.xlsx]Stock Code " & ROW(A1) & "'!" & "$O$8:$O$500"), "Issued to Sanitary Syndicate", INDIRECT("'[Stock Register.xlsx]Stock Code " & ROW(A1) & "'!" & "$I$8:$I$500")

The ROW function in this case is a trick to be used as a sort of automatic counter.

Now you can copy it down as much as necessary.

Please, tell us if it worked for you.
I hope it helps.
 
Upvote 0
Thank you so much for your reply. Your formula is working like a charm.

But, It's showing #Ref error when the source file is closed. Please advice how to deal with it.

Thanks in advance.
 
Upvote 0
Hi Scot T

Thanks for sharing this video.

I have checked that formula changing SUMIF to SUMPRODUCT and got result I want. This is working like a charm but I cannot add ROW(a1) which is required to change the sheet name when dragging.

Please advice.

Thanks in advance.
 
Upvote 0
INDIRECT doesn't work on a closed workbook, you can try INDIRECT.EXT from the MoreFunc add-in or try Harlan Groves Pull function.

Morefunc - Free download and software reviews - CNET Download.com

instructions for installing MoreFunc

For MS Excel 2007 and prior versions, one can simply download, install and use this addin. In Excel 2007, once this addin is installed, it will appear under Formulas > Morefunc. For Excel 2010, the process for installing this addin is as follows:

a. Unzip the downloaded folder and double-click on the Setup file
b. Navigate to the following folder C:\Program Files\Morefunc and copy three files - Morefunc, Morefunc11 and Morefunc12 (please note it is Program Files (x86) for me)
c. Navigate to the following folder C:\Program Files\Microsoft Office\Office14\Library and paste the files there
d. Open MS Excel 2010
e. Go to Files > Options > Addins > Manage Excel Add-ins > Go
f. Check the following three boxes - Morefunc (add-in functions), Morefunc Tools and Morefunc12
g. Click on OK
h. Close MS Excel 2010 and reopen
i. Morefunc should now appear under the Formulas Tab in the Ribbon





Harlan Grove's Pull function

Code:
Function pull(xref As String) As Variant
'inspired by Bob Phillips and Laurent Longre
'but written by Harlan Grove
'-----------------------------------------------------------------
'Copyright (c) 2003 Harlan Grove.
'
'This code is free software; you can redistribute it and/or modify
'it under the terms of the GNU General Public License as published
'by the Free Software Foundation; either version 2 of the License,
'or (at your option) any later version.
'-----------------------------------------------------------------
'2004-05-28
'fixed the previous fix - replaced all instances of 'expr' with 'xref'
'also now checking for initial single quote in xref, and if found
'advancing past it to get the full pathname [dumb, really dumb!]
'-----------------------------------------------------------------
'2004-03-25
'revised to check if filename in xref exists - if it does, proceed;
'otherwise, return a #REF! error immediately - this avoids Excel
'displaying dialogs when the referenced file doesn't exist
'-----------------------------------------------------------------

Dim xlapp As Object, xlwb As Workbook
Dim b As String, r As Range, C As Range, n As Long

'** begin 2004-05-28 changes **
'** begin 2004-03-25 changes **
n = InStrRev(Len(xref), xref, "\")

If n > 0 Then
If Mid(xref, n, 2) = "\[" Then
b = Left(xref, n)
n = InStr(n + 2, xref, "]") - n - 2
If n > 0 Then b = b & Mid(xref, Len(b) + 2, n)

Else
n = InStrRev(Len(xref), xref, "!")
If n > 0 Then b = Left(xref, n - 1)

End If

'** key 2004-05-28 addition **
If Left(b, 1) = "'" Then b = Mid(b, 2)

On Error Resume Next
If n > 0 Then If Dir(b) = "" Then n = 0
Err.Clear
On Error GoTo 0

End If

If n <= 0 Then
pull = CVErr(xlErrRef)
Exit Function
End If
'** end 2004-03-25 changes **
'** end 2004-05-28 changes **

pull = Evaluate(xref)

If CStr(pull) = CStr(CVErr(xlErrRef)) Then
On Error GoTo CleanUp   'immediate clean-up at this point

Set xlapp = CreateObject("Excel.Application")
Set xlwb = xlapp.Workbooks.Add  'needed by .ExecuteExcel4Macro

On Error Resume Next    'now clean-up can wait

n = InStr(InStr(1, xref, "]") + 1, xref, "!")
b = Mid(xref, 1, n)

Set r = xlwb.Sheets(1).Range(Mid(xref, n + 1))

If r Is Nothing Then
pull = xlapp.ExecuteExcel4Macro(xref)

Else
For Each C In r
C.Value = xlapp.ExecuteExcel4Macro(b & C.Address(1, 1, xlR1C1))
Next C

pull = r.Value

End If

CleanUp:
If Not xlwb Is Nothing Then xlwb.Close 0
If Not xlapp Is Nothing Then xlapp.Quit
Set xlapp = Nothing

End If

End Function

Please note that MoreFunc doesn't work with 64bit Excel and I suspect the Pull function won't either.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,215,884
Messages
6,127,565
Members
449,385
Latest member
KMGLarson

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top