• Hi All

    Please note that at the Chandoo.org Forums there is Zero Tolerance to Spam

    Post Spam and you Will Be Deleted as a User

    Hui...

  • When starting a new post, to receive a quicker and more targeted answer, Please include a sample file in the initial post.

Copying formula into multiple workbooks

Tripp

Member
Hello,

I have about 100 workbooks that I need to update with a simple formula. The formula needs to be pasted into the same place and same tab on each workbook. The only difference is the name of the workbook.

Tab name: Progress
Paste location: K21 then drag across to N21
Formula to Paste: =COUNTIFS(K8:K20,">1/1/1900",$P$8:$P$20,"<>No")/(13 - COUNTIF($P$8:$P$20,"No"))

This will take me a while manually, which I'm doing at the moment, but thought there might be a way to speed up the process via VBA.

Any help appreciated.
Tripp
 
Hi Tripp,

Modified the code available here:
https://www.thespreadsheetguru.com/...oop-through-all-excel-files-in-a-given-folder


Code:
Sub LoopAllExcelFilesInFolder()
'PURPOSE: To loop through all Excel files in a user specified folder and perform a set task on them
'SOURCE: www.TheSpreadsheetGuru.com

Dim wb As Workbook
Dim myPath As String
Dim myFile As String
Dim myExtension As String
Dim FldrPicker As FileDialog

'Optimize Macro Speed
  Application.ScreenUpdating = False
  Application.EnableEvents = False
  Application.Calculation = xlCalculationManual

'Retrieve Target Folder Path From User
  Set FldrPicker = Application.FileDialog(msoFileDialogFolderPicker)

    With FldrPicker
      .Title = "Select A Target Folder"
      .AllowMultiSelect = False
        If .Show <> -1 Then GoTo NextCode
        myPath = .SelectedItems(1) & "\"
    End With

'In Case of Cancel
NextCode:
  myPath = myPath
  If myPath = "" Then GoTo ResetSettings

'Target File Extension (must include wildcard "*")
  myExtension = "*.xls*"

'Target Path with Ending Extention
  myFile = Dir(myPath & myExtension)

'Loop through each Excel file in folder
  Do While myFile <> ""
    'Set variable equal to opened workbook
      Set wb = Workbooks.Open(Filename:=myPath & myFile)
   
    'Ensure Workbook has opened before moving on to next line of code
      DoEvents
   
    'Change First Worksheet's Background Fill Blue
      wb.Worksheets("Progress").Activate
      wb.Worksheets("Progress").Range("K21").Select
    ActiveCell.Formula = _
        "=COUNTIFS(K8:K20,"">1/1/1900"",$P$8:$P$20,""<>No"")/(13 - COUNTIF($P$8:$P$20,""No""))"
    Range("K21").Select
    Selection.AutoFill Destination:=Range("K21:N21"), Type:=xlFillDefault
    Range("K21:N21").Select
     
   
    'Save and Close Workbook
      wb.Close SaveChanges:=True
     
    'Ensure Workbook has closed before moving on to next line of code
      DoEvents

    'Get next file name
      myFile = Dir
  Loop

'Message Box when tasks are completed
  MsgBox "Task Complete!"

ResetSettings:
  'Reset Macro Optimization Settings
    Application.EnableEvents = True
    Application.Calculation = xlCalculationAutomatic
    Application.ScreenUpdating = True

End Sub

Regards,
 
Thanks Khalid :)

Turns out I have to do in manually as all the files are in Sharepoint and these don't allow macros. But I will save this macro for future use.

Cheers
 
Back
Top