Consulting

Results 1 to 3 of 3

Thread: Validating column Heads

  1. #1
    VBAX Regular
    Joined
    Jan 2008
    Posts
    75
    Location

    Unhappy Validating column Heads

    Hi All,

    I am having a big problem with the code I wrote to import text files into Excel. It works fine, but as part of the requirement it should validate that the following column headings are there, and appears in the following order: First_Name, Last_Name, Purch_Ord_Num, Amount, Purc_Date, Received_By, Verified_By.

    Here is the code,
    [VBA]
    Sub ImportTextFile()

    Dim sFile As String
    Dim sInput As String
    Dim lFNum As Long
    Dim vaFields As Variant
    Dim i As Long
    Dim lRow As Long
    Dim vaStrip As Variant
    Dim FileName As Variant
    Dim Sep As String
    Application.ScreenUpdating = False
    On Error GoTo EndMacro:
    lFNum = FreeFile

    sFile = Application.GetOpenFilename(FileFilter:="Excel File (*.txt),*.txt")
    'If sFile = False Then
    ''''''''''''''''''''''''''
    ' user cancelled, get out
    ''''''''''''''''''''''''''
    ' Exit Sub
    'End If
    Const sDELIM = "," 'Set the delimeter

    lFNum = FreeFile
    'sFile = "C:CaratDelim.txt"
    vaStrip = Array(vbLf, vbTab) 'list the text to strip

    'Open the file
    Open sFile For Input As lFNum

    'Loop through the file until the end
    Do While Not EOF(lFNum)
    Line Input #lFNum, sInput 'input the current line

    'remove the unwanted text
    For i = LBound(vaStrip) To UBound(vaStrip)
    sInput = Replace(sInput, vaStrip(i), " ")
    Next i

    'split the text based on the delimeter
    vaFields = Split(sInput, sDELIM)
    lRow = lRow + 1

    'Write to the worksheet
    For i = 0 To UBound(vaFields)
    Sheet1.Cells(lRow, i + 1).Value = vaFields(i)
    Next i
    Loop



    EndMacro:
    On Error GoTo 0
    Application.ScreenUpdating = True
    Close lFNum

    End Sub
    [/VBA]
    I have tried writing codes to add to it to do it but it is not working. I would be very grateful if someone in this forum will help me out.

    Thanks

    Lucpian

    Edit Lucas: VBA Tags added: Lucipian, when posting your code select it and hit the VBA button...

  2. #2
    Moderator VBAX Wizard lucas's Avatar
    Joined
    Jun 2004
    Location
    Tulsa, Oklahoma
    Posts
    7,323
    Location
    Can you put your header row in using an array and then import your text file?

    [VBA]
    Dim myarray As Variant
    myarray = Array("Heading 1", "Heading 2", "Heading 3", "Heading 4", "Heading 5")
    Range("a1:e1").Value = myarray
    [/VBA]
    Steve
    "Nearly all men can stand adversity, but if you want to test a man's character, give him power."
    -Abraham Lincoln

  3. #3
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    [vba]

    Sub ImportTextFile()

    Dim sFile As String
    Dim lFNum As Long
    Dim vaFields As Variant
    Dim i As Long
    Dim lRow As Long
    Dim vaStrip As Variant
    Dim FileName As Variant
    Dim Sep As String

    Application.ScreenUpdating = False
    On Error GoTo EndMacro:
    lFNum = FreeFile

    sFile = Application.GetOpenFilename(FileFilter:="Excel File (*.txt),*.txt")
    'If sFile = False Then
    ''''''''''''''''''''''''''
    ' user cancelled, get out
    ''''''''''''''''''''''''''
    ' Exit Sub
    'End If
    Const sDELIM = "," 'Set the delimiter

    lFNum = FreeFile
    'sFile = "C:CaratDelim.txt"
    vaStrip = Array(vbLf, vbTab) 'list the text to strip

    'Open the file
    Open sFile For Input As lFNum

    vaFields = GetData(lFNum, vaStrip, sDELIM)
    i = LBound(vaFields)
    If UBound(vaFields) - i + 1 = 7 Then

    If vaFields(i) = "First_Name" And _
    vaFields(i + 1) = "Last_Name" And _
    vaFields(i + 2) = "Purch_Ord_Num" And _
    vaFields(i + 3) = "Amount" And _
    vaFields(i + 4) = "Purc_Date" And _
    vaFields(i + 5) = "Received_By" And _
    vaFields(i + 6) = "Verified_By" Then

    'Loop through the file until the end
    Do While Not EOF(lFNum)

    vaFields = GetData(lFNum, vaStrip, sDELIM)
    lRow = lRow + 1

    'Write to the worksheet
    For i = 0 To UBound(vaFields)
    Sheet1.Cells(lRow, i + 1).Value = vaFields(i)
    Next i
    Loop
    Else

    MsgBox "Invalid headers"
    End If
    Else

    MsgBox "Invalid headers"
    End If

    EndMacro:
    On Error GoTo 0
    Application.ScreenUpdating = True
    Close lFNum

    End Sub

    Private Function GetData(ByVal FileNum As Long, _
    ByVal Redundant As Variant, _
    ByVal Delimiter As String) As Variant
    Dim sInput As String
    Dim i As Long

    Line Input #FileNum, sInput 'input the current line
    'remove the unwanted text
    For i = LBound(Redundant) To UBound(Redundant)
    sInput = Replace(sInput, Redundant(i), " ")
    Next i

    'split the text based on the delimeter
    GetData = Split(sInput, Delimiter)
    End Function
    [/vba]
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •