Pls Help me speed up this macro

straus

Board Regular
Joined
Oct 7, 2002
Messages
192
I have the following macro for exporting large text files (more than 65536 rows ) into excel (by moving data more than 65536 rows to Sheet 2). However, the macro is very slow and a file that has 200000 rows is taking too long to export. could you pls do something about it? Thanks

Sub LargeFileImport()

'Dimension Variables
Dim ResultStr As String
Dim FileName As String
Dim FileNum As Integer
Dim Counter As Double
'Ask User for File's Name
FileName = InputBox("Please enter the Text File's name, e.g. S:RevenueStrausBATCHOCCMUM231002.txt")
'Check for no entry
If FileName = "" Then End
'Get Next Available File Handle Number
FileNum = FreeFile()
'Open Text File For Input
Open FileName For Input As #FileNum
'Turn Screen Updating Off
Application.ScreenUpdating = False
'Create A New WorkBook With One Worksheet In It
Workbooks.Add template:=xlWorksheet
'Set The Counter to 1
Counter = 1
'Loop Until the End Of File Is Reached
Do While Seek(FileNum) <= LOF(FileNum)
'Display Importing Row Number On Status Bar
Application.StatusBar = "Importing Row " & _
Counter & " of text file " & FileName
'Store One Line Of Text From File To Variable
Line Input #FileNum, ResultStr
'Store Variable Data Into Active Cell
If Left(ResultStr, 1) = "=" Then
ActiveCell.Value = "'" & ResultStr
Else
ActiveCell.Value = ResultStr
End If

'For xl97 and later change 16384 to 65536
If ActiveCell.Row = 16384 Then
'If On The Last Row Then Add A New Sheet
ActiveWorkbook.Sheets.Add
Else
'If Not The Last Row Then Go One Cell Down
ActiveCell.Offset(1, 0).Select
End If
'Increment the Counter By 1
Counter = Counter + 1
'Start Again At Top Of 'Do While' Statement
Loop
'Close The Open Text File
Close
'Remove Message From Status Bar
Application.StatusBar = False

End Sub
 

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.

dk

MrExcel MVP
Joined
Feb 15, 2002
Messages
2,942
Hi,

You would probably be much better off using a database application such as Access, which is designed to store and manipulate large amounts of data. That said, I'm sure you have your reasons for using Excel so here is a potential solution. This will only work with Excel 2000 or Excel 2002. Let me know how you get on...

Code:
Sub OpenBigFile()

    Dim strFilename As String, strPathToFile As String, strFullPath As String
    Dim oADORS As Object, oADOConn As Object
    Dim oFSObj As Object

    strFullPath = Application.GetOpenFilename("Text Files (*.txt),*.txt", , "Please select text file...")

    If strFullPath = "False" Then Exit Sub

    'We have the full path of the file.  Now need path and name

    Set oFSObj = CreateObject("SCRIPTING.FILESYSTEMOBJECT")

    strFilename = oFSObj.GetFileName(strFullPath)
    strPathToFile = oFSObj.GetFile(strFullPath).ParentFolder & ""


    Set oADOConn = CreateObject("ADODB.CONNECTION")

    oADOConn.Provider = "Microsoft.Jet.OLEDB.4.0"
    oADOConn.Open "Provider=Microsoft.Jet.OLEDB.4.0;" & _
                  "Data Source=" & strPathToFile & ";" & _
                  "Extended Properties=""text;HDR=Yes;FMT=Delimited"""

    Set oADORS = CreateObject("ADODB.RECORDSET")

    oADORS.Open "SELECT * FROM " & strFilename, oADOConn, 3, 1, 1

    While Not oADORS.EOF

        Sheets.Add
        ActiveSheet.Range("A1").CopyFromRecordset oADORS, 65536

    Wend

    oADORS.Close
    oADOConn.Close

End Sub
 

Forum statistics

Threads
1,143,923
Messages
5,721,559
Members
422,370
Latest member
A Nonomus

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