VBA CSV Change First Column Export to Space

talkinggoat

New Member
Joined
Feb 1, 2022
Messages
33
Office Version
  1. 365
Platform
  1. Windows
I need to export a spreadsheet to CSV, but:
  1. The import application needs exactly 16 spaces as the delimiter between the first column and the second column.
  2. The commas need to be tilde.
I can convert them all to spaces and I can convert them all to commas, but I don't know how I would make VBA change only column A's delimiter to 16 spaces and everything else to tilde.

I was thinking of using a for loop with a nested if statement, something like:

for row
if row is in column1
change the delimiter to value & space(16)
else
output as tilde
next

I've only been using VBA for about 6 days, so I'm not sure how to do it and combine that to a file. I can do it in PowerShell and I have created a working script, but I'd like to cut out that step.
 

Excel Facts

Links? Where??
If Excel says you have links but you can't find them, go to Formulas, Name Manager. Look for old links to dead workbooks & delete.
Mybe you can create in Sheet2 the text to export using the following formula:
Excel Formula:
=IF(Sheet1!A1="","",Sheet1!A1&REPT(" ",20)&TEXTJOIN("~",FALSE,Sheet1!B1:G1))
This chains from col A to G; adapt to your layout.
Set the formula in A1 and copy down

Then save this worksheet in text format

Bye
 
Upvote 0
Here is the script I've come up with... I need it to cycle through each row of the worksheet, because the cells aren't always the same length. The only issue I'm having is getting it to write to the file. It only writes the last line.

VBA Code:
Dim x As String 
Dim j As Long 
Dim k As Long      
Dim fso As Object 
Dim i As Long

For i = 5 To 26
        With ActiveSheet
            If .Rows(i).EntireRow.Hidden Then
                
            Else
                .Rows(i).Select
                rowCell = ActiveSheet.Rows(i).Find(what:="*", lookat:=xlPart, LookIn:=xlFormulas, searchorder:=xlByColumns, SearchDirection:=xlPrevious, _
                MatchCase:=False).Column - 1
                'Debug.Print "Row " & i; " Column " & rowCell
                'Debug.Print Cells(5, 5).Value
                k = 5
                x = Cells(i, k)
                For k = 6 To rowCell
                    If k = 6 Then
                        x = x & Space(16) & Cells(i, k)
                    Else
                        x = x & "," & Cells(i, k)
                    '// Debug.Print x & "-" & k
                    End If
                Next k
                'Debug.Print x
            End If
            x = x & vbChr
        End With
        
        'Debug.Print x
    
    Next i
    'Debug.Print (TypeName(fso))
    Set fso = CreateObject("ADODB.Stream")
        With fso
            .Type = 2
            .Charset = "UTF-8"
            .Open
            .WriteText x
            .SaveToFile stFilename, 2
        End With
    Set fso = Nothing
    Debug.Print x
 
Upvote 0
You should modify the following 2 instructions in the following positions (the line marked '***)
VBA Code:
                K = 5
                X = X & Cells(I, K)        '***
                For K = 6 To rowCell

VBA Code:
            End If
            X = X & vbCrLf             '***
        End With

Bye
 
Upvote 0

Forum statistics

Threads
1,213,485
Messages
6,113,931
Members
448,533
Latest member
thietbibeboiwasaco

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