Export Visible Cells to text file

Aliluz81

New Member
Joined
Sep 9, 2015
Messages
3
Hi All!!

Please I need help to export data from Excel to text file (.txt). I Select a range in Excel and after that I call to the Function below (Alt + F8) - ExporText (I googled it - hehe)

My problem is when I select a range only for filtered cells (Autofilter) (and after that I use a macro to call the function), the function works over all the cells, and I need it works only for visibles. i.e. export only the selected range and no the hidden. The selected range can be only three cells for example.-

Can someone tell me how to modify the code to do it requested?


Function WriteFile(delimiter As String, quotes As Integer) As String

' Dimension variables to be used in this function.
Dim CurFile As String
Dim SaveFileName
Dim CellText As String
Dim RowNum As Long
Dim ColNum As Long
Dim FNum As Integer
Dim TotalRows As Double
Dim TotalCols As Double


' Show Save As dialog box with the .TXT file name as the default.
' Test to see what kind of system this macro is being run on.
If Left(Application.OperatingSystem, 3) = "Win" Then
SaveFileName = Application.GetSaveAsFilename(CurFile, _
"Text Delimited (*.txt), *.txt", , "Text Delimited Exporter")
Else
SaveFileName = Application.GetSaveAsFilename(CurFile, _
"TEXT", , "Text Delimited Exporter")
End If

' Check to see if Cancel was clicked.
If SaveFileName = False Then
WriteFile = "Cancelado"
Exit Function
End If
' Obtain the next free file number.
FNum = FreeFile()

' Open the selected file name for data output.
Open SaveFileName For Output As #FNum

' Store the total number of rows and columns to variables.
TotalRows = Selection.Rows.Count
TotalCols = Selection.Columns.Count

' Loop through every cell, from left to right and top to bottom.
For RowNum = 1 To TotalRows
For ColNum = 1 To TotalCols
With Selection.Cells(RowNum, ColNum)

Dim ColWidth As Integer
ColWidth = Application.RoundUp(.ColumnWidth, 0)
' Store the current cells contents to a variable.
Select Case .HorizontalAlignment
Case xlRight
CellText = Space(Abs(ColWidth - Len(.Text))) & .Text
Case xlCenter
CellText = Space(Abs(ColWidth - Len(.Text)) / 2) & .Text & _
Space(Abs(ColWidth - Len(.Text)) / 2)
Case Else
CellText = .Text & Space(Abs(ColWidth - Len(.Text)))
End Select
End With
' Write the contents to the file.
' With or without quotation marks around the cell information.
Select Case quotes
Case vbYes
CellText = Chr(34) & CellText & Chr(34) & delimiter
Case vbNo
CellText = CellText & delimiter
End Select
Print #FNum, CellText;

' Update the status bar with the progress.
Application.StatusBar = Format((((RowNum - 1) * TotalCols) _
+ ColNum) / (TotalRows * TotalCols), "0%") & " Completed."

' Loop to the next column.
Next ColNum
' Add a linefeed character at the end of each row.
If RowNum <> TotalRows Then Print #FNum, ""
' Loop to the next row.
Next RowNum

' Close the .prn file.
Close #FNum

' Reset the status bar.
Application.StatusBar = False
WriteFile = "Exported"
End Function


Macro To call function:

Sub ExportText()

Dim delimiter As String
Dim quotes As Integer
Dim Returned As String

delimiter = ""

quotes = MsgBox("¿Información de celda separada por comillas?", vbYesNo)

' Call the WriteFile function passing the delimiter and quotes options.
Returned = WriteFile(delimiter, quotes)

' Print a message box indicating if the process was completed.
Select Case Returned
Case "Canceled"
MsgBox "The export operation was canceled."
Case "Exported"
MsgBox "La información fue exportada"
End Select

End Sub




Thanks in advance
 

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
I needed something similar. You might try this technique.

I select the range, and make a new workbook to paste into, and then save that workbook as txt file.


My Code:
Code:
    Range(Range("G2"), Range("G2").End(xlDown)).SpecialCells(xlCellTypeVisible).Copy
    Workbooks.Add
Set wb3 = ActiveWorkbook
Set ws3 = wb3.ActiveSheet
    ws3.Paste
    Application.CutCopyMode = False
    Application.DisplayAlerts = False
    wb3.SaveAs Filename:= _
        "Y:\our\Path\FileName.txt" _
        , FileFormat:=xlText, CreateBackup:=False
    wb3.Close True
 
Upvote 0
Thanks revcanon!! But my range can change, and for example I select today 20 cells and tomorrow 200 cells to export. The code uses "Selection", it works in current selection, but include hidden cells. I need to change that to select only visible in the macro. Do you know how to change that selection in the code?
 
Upvote 0
Welcome to MrExcel

Here are some suggestions and some code:

1. Please put code in the code form (click on #)
2. This will allow you to indent code to make it more readable.
3. You can bold, color, underline etc code to give it emphasis.

Now to the using only the visible cells.

What I have done is to copy the Selection and paste it into a new sheet, did your processing, and deleted the new sheet. The copy only copies the visible cells.

Note: I did the minimum of testing on this. It's up to you to completely test it.

After testing, please post your results.


Code:
Function WriteFile(delimiter As String, quotes As Integer) As String

    ' Dimension variables to be used in this function.
    Dim CurFile As String
    Dim SaveFileName
    Dim CellText As String
    Dim RowNum As Long
    Dim ColNum As Long
    Dim FNum As Integer
    Dim TotalRows As Double
    Dim TotalCols As Double
    
    
    ' Show Save As dialog box with the .TXT file name as the default.
    ' Test to see what kind of system this macro is being run on.
    If Left(Application.OperatingSystem, 3) = "Win" Then
            SaveFileName = Application.GetSaveAsFilename(CurFile, _
                "Text Delimited (*.txt), *.txt", , "Text Delimited Exporter")
        Else
            SaveFileName = Application.GetSaveAsFilename(CurFile, _
                "TEXT", , "Text Delimited Exporter")
    End If
    
    ' Check to see if Cancel was clicked.
    If SaveFileName = False Then
        WriteFile = "Cancelado"
        Exit Function
    End If
    ' Obtain the next free file number.
    
    FNum = FreeFile()
    
    ' Open the selected file name for data output.
    Open SaveFileName For Output As #FNum
    
[COLOR=#0000ff][B]'============================================================
    Selection.Copy
    With Sheets.Add
        Range("A1").PasteSpecial xlPasteAll
        .UsedRange.Select
'=============================================================
 [/B][/COLOR]           
            ' Store the total number of rows and columns to variables.
            TotalRows = Selection.Rows.Count
            TotalCols = Selection.Columns.Count
            
            
            
            ' Loop through every cell, from left to right and top to bottom.
            For RowNum = 1 To TotalRows
                For ColNum = 1 To TotalCols
                    With Selection.Cells(RowNum, ColNum)
                    Dim ColWidth As Integer
                    ColWidth = Application.RoundUp(.ColumnWidth, 0)
                    ' Store the current cells contents to a variable.
                    Select Case .HorizontalAlignment
                        Case xlRight
                            CellText = Space(Abs(ColWidth - Len(.Text))) & .Text
                            Case xlCenter
                            CellText = Space(Abs(ColWidth - Len(.Text)) / 2) & .Text & _
                            Space(Abs(ColWidth - Len(.Text)) / 2)
                        Case Else
                            CellText = .Text & Space(Abs(ColWidth - Len(.Text)))
                        End Select
                    End With
            ' Write the contents to the file.
            ' With or without quotation marks around the cell information.
            Select Case quotes
                Case vbYes
                    CellText = Chr(34) & CellText & Chr(34) & delimiter
                Case vbNo
                    CellText = CellText & delimiter
            End Select
            Print #FNum, CellText;
                ' Update the status bar with the progress.
                Application.StatusBar = Format((((RowNum - 1) * TotalCols) _
                + ColNum) / (TotalRows * TotalCols), "0%") & " Completed."
                    ' Loop to the next column.
                    Next ColNum
                    ' Add a linefeed character at the end of each row.
                    If RowNum <> TotalRows Then Print #FNum, ""
                    ' Loop to the next row.
                Next RowNum
            ' Close the .prn file.
            Close #FNum
            ' Reset the status bar.
            Application.StatusBar = False
            WriteFile = "Exported"
            
[COLOR=#0000ff][B]'===============================================================
'   Get rid of added sheet
        Application.DisplayAlerts = False
        .Delete
        Application.DisplayAlerts = True
    End With[/B][/COLOR]
End Function
 
Upvote 0
Great tlowry!!!
It worked perfectly. I had to modify code in this part because I need the column width from the original worksheet.-

Thanks!!!

Code:
    Selection.Copy    With Sheets.Add
        Range("A1").PasteSpecial Paste:=xlPasteColumnWidths
        Range("A1").PasteSpecial Paste:=xlPasteValues
        Range("A1").PasteSpecial Paste:=xlPasteFormats
        .UsedRange.Select
 
Upvote 0

Forum statistics

Threads
1,215,261
Messages
6,123,943
Members
449,134
Latest member
NickWBA

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
Back
Top