+ Reply to Thread
Results 1 to 4 of 4

Replacing all formulas in a folder of workbooks

Hybrid View

  1. #1
    Registered User
    Join Date
    07-24-2012
    Location
    Sg
    MS-Off Ver
    Excel 2007
    Posts
    3

    Replacing all formulas in a folder of workbooks

    Hi, I need help with this:

    I need to replace all the formulas in a folder of workbooks to give just the value so that i can transfer the values to another table.

    Help, please? I have tried several macros but they did not give me the result that i need...

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

    Re: Replacing all formulas in a folder of workbooks

    Try this code. It will convert formulae to values in the first sheet of every workbook.
    Option Explicit
    
    Sub paste_values()
    
    Dim sourceBook As Workbook
    Dim sourceData As Worksheet
    Dim CurrentFileName As String
    Dim myPath As String
    
    'The folder containing the files to be recap'd
    myPath = "D:\Test"
    
    'Finds the name of the first file of type .xls in the current directory
    CurrentFileName = Dir(myPath & "\*.xlsx")
    
    'Create a workbook for the recap report
    
    Do
        Workbooks.Open (myPath & "\" & CurrentFileName)
        Set sourceBook = Workbooks(CurrentFileName)
        Set sourceData = sourceBook.Worksheets(1)
        
            With sourceData
                .Cells.Copy
                .Cells.PasteSpecial Paste:=xlPasteValues
                Application.CutCopyMode = False
            End With
          
        sourceBook.Save
        sourceBook.Close
      
    'Calling DIR w/o argument finds the next .xlsx file within the current directory.
    CurrentFileName = Dir()
    Loop While CurrentFileName <> ""
    
    End Sub
    Copy the Excel VBA code
    Select the workbook in which you want to store the Excel VBA code
    Hold the Alt key, and press the F11 key, to open the Visual Basic Editor
    Choose Insert | Module
    Where the cursor is flashing, choose Edit | Paste

    To run the Excel VBA code:
    Choose View | Macros
    Select a macro in the list, and click the Run button
    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]

  3. #3
    Registered User
    Join Date
    07-24-2012
    Location
    Sg
    MS-Off Ver
    Excel 2007
    Posts
    3

    Re: Replacing all formulas in a folder of workbooks

    Hi,

    Thank you for the suggestion, but could you suggest something that would replace formulas in all sheets in the workbooks?
    The number of worksheets in each workbook vary.

    Thank you~

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

    Re: Replacing all formulas in a folder of workbooks

    Try this code
    Option Explicit
    
    Sub paste_values()
    
    Dim sourceBook As Workbook
    Dim ws As Worksheet
    Dim CurrentFileName As String
    Dim myPath As String
    
    'The folder containing the files to be recap'd
    myPath = "D:\Test"
    
    'Finds the name of the first file of type .xls in the current directory
    CurrentFileName = Dir(myPath & "\*.xlsx")
    
    'Create a workbook for the recap report
    
    Do
        Workbooks.Open (myPath & "\" & CurrentFileName)
        Set sourceBook = Workbooks(CurrentFileName)
        
        For Each ws In sourceBook.Worksheets
           
            With ws
                .Cells.Copy
                .Cells.PasteSpecial Paste:=xlPasteValues
                Application.CutCopyMode = False
            End With
          
        Next ws
        
        sourceBook.Save
        sourceBook.Close
      
    'Calling DIR w/o argument finds the next .xlsx file within the current directory.
    CurrentFileName = Dir()
    Loop While CurrentFileName <> ""
    
    End Sub

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

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