Changing cell References by fixed value

howard

Well-known Member
Joined
Jun 26, 2006
Messages
5,632
Office Version
  1. 2019
Platform
  1. Windows
I have a series of formula copies from another workbook, but need all the references to be reduced by 10

for Eg for original formula which was copies is =SUM(INDEX(Sheet1!A1671:DG1671,0,104))

I need this automatically reduced by 10 for eg =SUM(INDEX(Sheet1!A1661:DG1661,0,104))

Is there a way in Excel where I can reduce a the values in the range by say 10

Your assistance will be most appreciated
 

Some videos you may like

Excel Facts

Show numbers in thousands?
Use a custom number format of #,##0,K. Each comma after the final 0 will divide the displayed number by another thousand

Fazza

MrExcel MVP
Joined
May 17, 2006
Messages
9,368
What if you just replace, CTRL-H. change all 1671 to 1661 ?

I guess there are lots of different ones to do? If so, can you give some more info - maybe some VBA would be good?
 

howard

Well-known Member
Joined
Jun 26, 2006
Messages
5,632
Office Version
  1. 2019
Platform
  1. Windows
Hi Faza

Thanks for the reply Here are some sample formula where the reference must be reduced by 10. The formulas are in col B

SUM(INDEX(Sheet1!A1674:CZ1674,0,104))
change to SUM(INDEX(Sheet1!A1664:CZ1664,0,104))

SUM(INDEX(Sheet1!$A$1531:$CZ$1531,0,104),SUM(INDEX(Sheet1!$A$1533:$CZ$1534,0,104),SUM(INDEX(Sheet1!$A$1537:$CZ$1537,0,104),SUM(INDEX(Sheet1!$A$1539:$CZ$1539,0,104),SUM(INDEX(Sheet1!$A$1541:$CZ$1541,0,104))))))

change to

SUM(INDEX(Sheet1!$A$1521:$CZ$1521,0,104),SUM(INDEX(Sheet1!$A$1523:$CZ$1524,0,104),SUM(INDEX(Sheet1!$A$1527:$CZ$1527,0,104),SUM(INDEX(Sheet1!$A$1529:$CZ$1529,0,104),SUM(INDEX(Sheet1!$A$1531:$CZ$1531,0,104))))))

Your assistance will be most appreciated

Regards

Howard
 

Fazza

MrExcel MVP
Joined
May 17, 2006
Messages
9,368
Thanks. If I understand the pattern it helps.

Such as, every number after a $

or every number > 104

what do you think would be suitable?
 

Fazza

MrExcel MVP
Joined
May 17, 2006
Messages
9,368

ADVERTISEMENT

PS

are all the numbers to change in the range 1000 to 9999. That is, a four digit number?
 

Fazza

MrExcel MVP
Joined
May 17, 2006
Messages
9,368
Also, approximately how many worksheets & formulas need to change?
 

howard

Well-known Member
Joined
Jun 26, 2006
Messages
5,632
Office Version
  1. 2019
Platform
  1. Windows

ADVERTISEMENT

Hi Faza

The range is from B1:B300. The values that must change are after $

Regards

Howard
 

Fazza

MrExcel MVP
Joined
May 17, 2006
Messages
9,368
Hi Howard, some quick & dirty code. Range B1:B300 has formulas, numbers after $ to reduce by 10. No error checking.

:eek: Important: please back up your file before starting. :eek:

From the worksheet's tab right click and choose view code. Copy & paste code from below into the big white window on the RHS of the VBE (Visual Basic Editor). Insert cursor into the pasted code. Hit F5 to execute the code. Then return to Excel & check if it worked correctly.

Code:
Sub test()
  Dim a, b
  Dim i As Long, j As Long, k As Long
  Dim g$
  With Range("B1:B300")
    .Replace What:="=", Replacement:="'="
    ReDim a(1 To .Rows.Count, 1 To .Columns.Count)
    a = .Value
    For i = LBound(a, 1) To UBound(a, 1)
      b = Split(a(i, 1), "$")
      For j = LBound(b) To UBound(b)
        If IsNumeric(Left$(b(j), 1)) Then
          g$ = vbNullString
          k = 1
          Do While IsNumeric(Mid$(b(j), k, 1))
            g$ = g$ & Mid$(b(j), k, 1)
            k = k + 1
          Loop
          b(j) = CLng(g$) - 10 & Mid$(b(j), k)
        End If
      Next j
      a(i, 1) = Join$(b, "$")
    Next i
    .Value = a
    .Replace What:="'=", Replacement:="="
  End With
End Sub
 

howard

Well-known Member
Joined
Jun 26, 2006
Messages
5,632
Office Version
  1. 2019
Platform
  1. Windows
Hi Fazza

Thanks for the help, much appreciated
 

Fazza

MrExcel MVP
Joined
May 17, 2006
Messages
9,368
You're welcome, Howard. Just thinking, if you encounter this again another approach [without VBA] is to convert the formulas to text (such as replace the "=" by "zzz=") and then temporarily use adjacent columns & text functions - such as FIND, LEFT, RIGHT, LEN - to isolate components of the formula, change as required, and then put it back together again. Regards, F
 

Watch MrExcel Video

Forum statistics

Threads
1,108,931
Messages
5,525,686
Members
409,660
Latest member
1817538628

This Week's Hot Topics

Top