Importing text files larger than 65536 rows (120596)



The information in this article applies to:

  • Microsoft Excel 97 for Windows
  • Microsoft Excel 2000
  • Microsoft Excel 2002
  • Microsoft Office Excel 2003

This article was previously published under Q120596

SUMMARY

In Excel 97 and all later versions, text files that contain more than 65,536 rows cannot be opened in their entirety. You cannot open these files because these versions of Microsoft Excel are limited to 65,536 rows. If you open a file that contains more data than this, the following error message appears, and the text file is truncated at the row 65,536:
File not loaded completely.
However, you can use a macro to open the file and automatically break the text into multiple worksheets

Note Versions of Excel prior to Microsoft Excel 97 have a limit of 16,384 rows.

MORE INFORMATION

Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements. The following sample macro prompts you for a text file name, and then opens the file into memory. If the number of rows is larger than the Microsoft Excel worksheet limit of 65,536, the macro breaks the file into multiple worksheets. This macro applies only to files you saved as text files and does not apply to any other file formats. The macro does not work with database file formats.

Note that because this is a macro, using it may be significantly slower than clicking Open on the File menu.
   'All lines that begin with an apostrophe (') are remarks and are not
   'required for the macro to run.
				
   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. test.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 Excel versions before Excel 97, change 65536 to 16384
          If ActiveCell.Row = 65536 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
				
Note The macro does not parse the data into columns. After using the macro, you may also need to use the Text To Columns command on the Data menu to parse the data as needed. When you run this macro on a Macintosh, and you are attempting to open a file that is on the desktop, you must precede the file name with the following

Hard disk:Desktop Folder:

where Hard disk is the name of your hard disk. Note that there is a space between the words Desktop and Folder.

Modification Type:MajorLast Reviewed:6/30/2005
Keywords:kbImport kbhowto kbcode KB120596