vba Code is putting *UNWANTED* apostophes in calculating functions - how to fix

ChrisOK

Well-known Member
Joined
Mar 26, 2003
Messages
599
Anyone know why this small chunk of code is putting unwanted apostrophes in my cell functions? It's causing them to error out... Once I manually remove the marks, it calculates properly...

Here's what it's doing:
=COUNTIF(A:A, A5)>1 looks like this instead: =COUNTIF(A:A, ‘A5’)>1
=G5 looks like this instead: =’G5’
=I5 looks like this instead: =’I5’
=SUM('Z5'+'AA5')/730


Code:
' DRAG FORMULAS FROM X TO Z DOWN TO BOTTOM
   

    Range("X5").Select
    ActiveCell.FormulaR1C1 = "=MID(RC[-23],5,9)"
    'THE ABOVE ACTUAL CELL FORMULA IS:  =MID(A5,5,9)
    
    Range("Y5").Select
    ActiveCell.FormulaR1C1 = "=COUNTIF(A:A, A5)>1"
    'THE ABOVE ACTUAL CELL FORMULA IS:   =COUNTIF(A:A, A5)>1
    
    Range("Z5").Select
    ActiveCell.FormulaR1C1 = "=G5"
    'THE ABOVE ACTUAL CELL FORMULA IS:  =G5
    
    Range("AA5").Select
    ActiveCell.FormulaR1C1 = "=I5"
    'THE ABOVE ACTUAL CELL FORMULA IS:  =I5
    
    Range("AB5").Select
    ActiveCell.FormulaR1C1 = "=SUM(Z5+AA5)/730"
    'THE ABOVE ACTUAL CELL FORMULA IS:  =SUM(Z5+AA5)/730
    
    Range("AC5").Select
    ActiveCell.FormulaR1C1 = "=A5"
    'THE ABOVE ACTUAL CELL FORMULA IS:  =A5)

    Range("X5:AC5").Select
    Range("X5:AC5").AutoFill Destination:=Range("X5:AC" & Range("A" & Rows.Count).End(xlUp).Row), Type:=xlFillDefault
 

Excel Facts

Waterfall charts in Excel?
Office 365 customers have access to Waterfall charts since late 2016. They were added to Excel 2019.

Michael M

Well-known Member
Joined
Oct 27, 2005
Messages
21,648
Office Version
  1. 365
  2. 2019
  3. 2013
  4. 2007
Platform
  1. Windows
Try
Code:
    Range("X5").Formula = "=MID(A5,5,9)"
    'THE ABOVE ACTUAL CELL FORMULA IS:  =MID(A5,5,9)
    
    Range("Y5").Formula = "=COUNTIF(A:A, A5)>1"
    'THE ABOVE ACTUAL CELL FORMULA IS:   =COUNTIF(A:A, A5)>1
    
    Range("Z5").Formula = "=G5"
    'THE ABOVE ACTUAL CELL FORMULA IS:  =G5
    
    Range("AA5").Formula = "=I5"
    'THE ABOVE ACTUAL CELL FORMULA IS:  =I5
    
    Range("AB5").Formula = "=SUM(Z5+AA5)/730"
    'THE ABOVE ACTUAL CELL FORMULA IS:  =SUM(Z5+AA5)/730
    
    Range("AC5").Formula = "=A5"
    'THE ABOVE ACTUAL CELL FORMULA IS:  =A5)

    Range("X5:AC5").AutoFill Destination:=Range("X5:AC" & Range("A" & Rows.Count).End(xlUp).Row), Type:=xlFillDefault
 
Upvote 0

ChrisOK

Well-known Member
Joined
Mar 26, 2003
Messages
599
FANTASTIC! Works like a charm!
Thanks Michael

BTW, clicking "LIKE" to make sure you get credit!
 
Upvote 0

Michael M

Well-known Member
Joined
Oct 27, 2005
Messages
21,648
Office Version
  1. 365
  2. 2019
  3. 2013
  4. 2007
Platform
  1. Windows
Het Chris, glad it worked....

BTW, clicking like deson't really do anything on this forum.....the simple thank you was more than adequate...(y)
 
Upvote 0

ChrisOK

Well-known Member
Joined
Mar 26, 2003
Messages
599
Granted, there's no compensation per se for the *likes* but it's a nice gesture I think ---
When you go to look at a person's profile it shows the qty of likes they rec'd -- hence showing that the source has provided content that was actually 'useful' to others (as indicated by the like).. Now a beer might be more in line with a more meaningful act -- sadly, a ~virtual beer~ is all I can provide... Thanks again (y)
 
Upvote 0

Forum statistics

Threads
1,195,600
Messages
6,010,651
Members
441,558
Latest member
lambierules

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
Top