Extracting data from Excel (1 Viewer)

dkmoreland

Registered User.
Local time
Yesterday, 16:19
Joined
Dec 6, 2017
Messages
129
[SOLVED] Extracting data from Excel

I am using the code below to extract data from an Excel spreadsheet that is generated by another program. It's all working except for one thing. Please look at the section in red text. I need to make a comma separated list of those bulk ids and put them all in a field in the table. There are not always 3 of them - sometimes there is only 1 and sometimes there are several.

I also need to add together the values in the shot size field for each of these bulk lines. For example, since the attached has 3 lines with a shot size of 200, I need to set the access field value to 600. If there were 7 lines with a shot size of 200, the value would be 1400. Does that make sense?

It works fine if there is a set number of bulk lines but that will not the reality. How can I adapt the code shown below to create a list from an unknown number of cells and to add together the values from another unknown number of cells?

I appreciate any insight you can offer. I wouldn't have gotten this far with this without help from you guys.

Thanks

Code:
Private Sub CmdImport_Click()

Dim appExcel As Excel.Application
Dim wbk As Excel.Workbook
Dim wks As Excel.Worksheet
Dim FileName As String
Dim FirstSeparator As Integer
Dim db As DAO.Database
Dim Td As DAO.TableDef
Dim tdDefaults As DAO.TableDef
Dim rs As DAO.Recordset
Dim rsDefaults As DAO.Recordset
Dim strMsg As String
Dim strSQL As String
Dim strJob As String
Dim strSubJob As String
Dim strPress As String
Dim strDescription As String
Dim strCustomer As String
Dim strTechnology As String
Dim lngOrderPieces As Long
Dim lngLayout As Long
Dim strBulk1 As String
Dim strBulk2 As String
Dim strBulk3 As String
Dim strBulkList As String
Dim lngShot1 As Long
Dim lngShot2 As Long
Dim lngShot3 As Long
Dim lngShotSum As Long



On Error GoTo ErrProc
    Set db = CurrentDb()

    StrImportFile = Me.TextImport
        
    If Me.TextImport = "" Then
        Exit Sub
        MsgBox "Please select a file.", vbOKOnly
    End If
        
    Set rs = db.OpenRecordset("Job Info")
        
    'open spreadsheet (Input Sheet) page, get data from specific cells
    Set appExcel = Excel.Application
    Set wbk = appExcel.Workbooks.Open(Me.TextImport)
    strJob = Range("'RunTicket'!P3").Value
    strSubJob = Range("'RunTicket'!P4").Value
    
    If IsEmpty(Range("'RunTicket'!P5").Value) Then
        strPress = "N/A"
    Else
        strPress = Range("'RunTicket'!P5").Value
    End If
      
     
    strDescription = Range("'RunTicket'!E8").Value
    strCustomer = Range("'RunTicket'!H9").Value
    strTechnology = Range("'RunTicket'!H12").Value
    lngOrderPieces = Range("'RunTicket'!E16").Value
    
    If strTechnology = "BeautiSeal®" Then
        lngLayouta = Left(Range("'RunTicket'!P25").Value, 1)
        lngLayoutb = Mid(Range("'RunTicket'!P25").Value, 6, 1)
        lngLayoutProd = lngLayouta * lngLayoutb
        
        [COLOR="Sienna"]If Not IsEmpty(Range("'RunTicket'!B30").Value) Then
            strBulk1 = Range("'RunTicket'!B30").Value
            strBulk2 = Range("'RunTicket'!B31").Value
            strBulk3 = Range("'RunTicket'!B31").Value
            strBulkList = strBulk1 & "," & strBulk2 & "," & strBulk3
            lngShot1 = Val(Range("'RunTicket'!N30").Value)
            lngShot2 = Val(Range("'RunTicket'!N30").Value)
            lngShot3 = Val(Range("'RunTicket'!N30").Value)
            lngShotSum = lngShot1 + lngShot2 + lngShot3
        End If[/COLOR]
    End If
    
    
    'close excel
    wbk.Close (False)   'close without saving changes
    appExcel.Quit
    Set wbk = Nothing
    Set appExcel = Nothing
    
    rs.AddNew
        rs![Job #] = strJob + "-" + strSubJob
        Debug.Print strJob + "-" + strSubJob
        rs![Press] = strPress
        rs![Job Name] = strDescription
        rs![Customer Name] = strCustomer
        rs!Technology = strTechnology
        rs![Order Quantity] = lngOrderPieces
        rs!QC = "IM"
        
        If strTechnology = "BeautiSeal®" Then
            rs![Labels on Repeat] = lngLayoutProd
            rs![FP / Bulk #] = strBulkList
            rs![shot size] = lngShotSum
        End If
        
        
    rs.Update
    
    rs.Close

    MsgBox "File " + StrImportFile + " has been imported", vbOKOnly
    
    DoCmd.Close
    Application.Echo False
    DoCmd.Close
    DoCmd.OpenForm "Job Info Form"
    Application.Echo True
        
    
ExitProc:
    Set db = Nothing
    Exit Sub
ErrProc:
    Select Case Err.Number
        Case 462    'excel not open
            Set appExcel = New Excel.Application
            Resume Next
        Case 3125
            MsgBox "The selected workbook is not the correct format.", vbOKOnly
            Resume ExitProc
        Case 3201
            MsgBox "Job Prefix is not valid.  Please add the new prefix to the prefix list.  Import was cancelled.", vbOKOnly
            Resume ExitProc
        Case Else
            MsgBox Err.Number & "--" & Err.Description
            Resume ExitProc
            Resume Next
    End Select
    
End Sub
 
Last edited:

isladogs

MVP / VIP
Local time
Today, 00:19
Joined
Jan 14, 2017
Messages
18,239
Perhaps something like this:

Code:
strBulkList = IIf(Nz(strBulk1,"")<>"", strBulk1 & ",","") & IIf(Nz(strBulk2,"")<>"", strBulk2 & ",","") & IIf(Nz(strBulk3,"")<>"", strBulk3,"")

lngShotSum = Nz(lngShot1,0) + Nz(lngShot2,0) + Nz(lngShot3.0)

I may not have understood the 2nd part correctly but are you sure that this code is correct as the lines are IDENTICAL

Code:
 lngShot1 = Val(Range("'RunTicket'!N30").Value)
            lngShot2 = Val(Range("'RunTicket'!N30").Value)
            lngShot3 = Val(Range("'RunTicket'!N30").Value)
 

dkmoreland

Registered User.
Local time
Yesterday, 16:19
Joined
Dec 6, 2017
Messages
129
Perhaps something like this:

Code:
strBulkList = IIf(Nz(strBulk1,"")<>"", strBulk1 & ",","") & IIf(Nz(strBulk2,"")<>"", strBulk2 & ",","") & IIf(Nz(strBulk3,"")<>"", strBulk3,"")

lngShotSum = Nz(lngShot1,0) + Nz(lngShot2,0) + Nz(lngShot3.0)

I may not have understood the 2nd part correctly but are you sure that this code is correct as the lines are IDENTICAL

Code:
 lngShot1 = Val(Range("'RunTicket'!N30").Value)
            lngShot2 = Val(Range("'RunTicket'!N30").Value)
            lngShot3 = Val(Range("'RunTicket'!N30").Value)

There is a typo in that last part - the cell address for lngShot3 should be N31. Typing is hard. :)

Please look at the highlighted lines on the attached screenshot at how this is laid out in the spreadsheet. There might be 1 of these lines but there might be several. I coded it with 3 just to test it. I'm trying to figure how to loop through and capture the data with an unknown number of lines. Would a FOR..NEXT loop be better than a DO UNTIL in this case?
 

Attachments

  • run ticket - sample 2.PNG
    run ticket - sample 2.PNG
    40 KB · Views: 292

isladogs

MVP / VIP
Local time
Today, 00:19
Joined
Jan 14, 2017
Messages
18,239
There is a typo in that last part - the cell address for lngShot3 should be N31. Typing is hard. :)

BUT copy & paste is EASY!
Should lngShot1 cell be N29 in that case?

Please look at the highlighted lines on the attached screenshot at how this is laid out in the spreadsheet. There might be 1 of these lines but there might be several. I coded it with 3 just to test it. I'm trying to figure how to loop through and capture the data with an unknown number of lines. Would a FOR..NEXT loop be better than a DO UNTIL in this case?

Personally I'd use FOR ... NEXT but DO ... UNTIL or WHILE ...WEND might all work. Partly its personal preference. Do whichever seems easiest

Was the strBulkList part OK?
I do hope you're not populating a multivalue field!
 

Cronk

Registered User.
Local time
Today, 09:19
Joined
Jul 4, 2013
Messages
2,772
DKM, in your previous thread, we went through the process of finding the start of the range of cells, moving down the range till the end within a loop, and doing any processing of data on the way through.

Why have you reverted to hard coding now?
 

dkmoreland

Registered User.
Local time
Yesterday, 16:19
Joined
Dec 6, 2017
Messages
129
DKM, in your previous thread, we went through the process of finding the start of the range of cells, moving down the range till the end within a loop, and doing any processing of data on the way through.

Why have you reverted to hard coding now?

I only did the hard coding for testing to make sure the fields in the table were being populated correctly.

I'm having trouble getting the code you provided to work in my situation - I am sure I am missing something.

Here is the code you posted in other thread, with only a couple of modifications. Can you what I am missing, considering what it is I am trying to do?

Code:
   intRow = 0

Do
   introw = 30 'Bulk items always start at row 30, column P and shot size is always at column N
     If intRow > 5000 Then
     MsgBox "Problem"
     Exit Do
   'End If
Until appExcel.Cells(intRow, 1) = "Materials"  

intRow = intRow + 1     '--skip the next line has the column headings

While appExcel.Cells(intRow, 1) <> ""
  strBulkList = appExcel.Cells(introw, 1)
   Debug.Print strBulkList
   rs!Field1 = appExcel.Cells(intRow, 1)
   rs!Field2 = appExcel.Cells(intRow, 2)
   rs!Field3 = appExcel.Cells(intRow, 3)
   '.....
   introw = introw + 1
Loop
 

Cronk

Registered User.
Local time
Today, 09:19
Joined
Jul 4, 2013
Messages
2,772
"I am sure I am missing something."

Yes, you are missing something which is not understanding what your code is doing.

Insert the line
Code:
Stop
before the first Do loop and run your code.

Then step through your code line by line by pressing the F8 key. Look at the values of the variables in the immediate window by typing
Code:
? intRow,  appExcel.Cells(intRow, 1)
in the immediate window.

Come back after that if you want more help.

By the way, in your screen shot before, there was nothing showing what comes after the last line of your bulk/shot data. You'll need to include a test for that to know when the last entry has been read.
 

dkmoreland

Registered User.
Local time
Yesterday, 16:19
Joined
Dec 6, 2017
Messages
129
"I am sure I am missing something."

Yes, you are missing something which is not understanding what your code is doing.

Insert the line
Code:
Stop
before the first Do loop and run your code.

Then step through your code line by line by pressing the F8 key. Look at the values of the variables in the immediate window by typing
Code:
? intRow,  appExcel.Cells(intRow, 1)
in the immediate window.

Come back after that if you want more help.

By the way, in your screen shot before, there was nothing showing what comes after the last line of your bulk/shot data. You'll need to include a test for that to know when the last entry has been read.

Yes - I did go step through it and found the problems. Everything is working now and I learned a great deal in the process. Here's the code for the whole import subroutine, in case it helps anybody else. If you see any glaring errors, feel free to point them out to me.

Thanks to everyone that helped me with this.

Code:
Private Sub CmdImport_Click()

Dim appExcel As Excel.Application
Dim wbk As Excel.Workbook
Dim wks As Excel.Worksheet
Dim FileName As String
Dim FirstSeparator As Integer
Dim db As DAO.Database
Dim Td As DAO.TableDef
Dim tdDefaults As DAO.TableDef
Dim rs As DAO.Recordset
Dim rsDefaults As DAO.Recordset
Dim strMsg As String
Dim strSQL As String
Dim strJob As String
Dim strSubJob As String
Dim strPress As String
Dim strDescription As String
Dim strCustomer As String
Dim strTechnology As String
Dim lngOrderPieces As Long
Dim lngLayout As Long
Dim strBulkList As String
Dim lngShotSum As Long
Dim intRow As Integer
Dim bBulk As Boolean


On Error GoTo ErrProc
    Set db = CurrentDb()

    StrImportFile = Me.TextImport
        
    If Me.TextImport = "" Then
        Exit Sub
        MsgBox "Please select a file.", vbOKOnly
    End If
    
    
    Set rs = db.OpenRecordset("Job Info")
    
    
    'open spreadsheet (Input Sheet) page, get data from specific cells
    Set appExcel = Excel.Application
    Set wbk = appExcel.Workbooks.Open(Me.TextImport)
    strJob = Range("'RunTicket'!P3").Value
    strSubJob = Range("'RunTicket'!P4").Value
    
    If IsEmpty(Range("'RunTicket'!P5").Value) Then
        strPress = "N/A"
    Else
        strPress = Range("'RunTicket'!P5").Value
    End If
      
     
    strDescription = Range("'RunTicket'!E8").Value
    strCustomer = Range("'RunTicket'!H9").Value
    strTechnology = Range("'RunTicket'!H12").Value
    lngOrderPieces = Range("'RunTicket'!E16").Value
    
    If strTechnology = "BeautiSeal®" Then
        lngLayouta = Left(Range("'RunTicket'!P25").Value, 1)
        lngLayoutb = Mid(Range("'RunTicket'!P25").Value, 6, 1)
        lngLayoutProd = lngLayouta * lngLayoutb
        
        intRow = 30
        bBulk = True
        
        Do
            If Left(Cells(intRow, 2).Value, 4) = "bulk" Then
                strBulkList = strBulkList & "," & Cells(intRow, 2).Value
                lngShotSum = lngShotSum + Val(Cells(intRow, 14).Value)
            Else
                bBulk = False
            End If
            
            intRow = intRow + 1
            
         Loop Until bBulk = False

    End If
    
      
    'close excel
    wbk.Close (False)   'close without saving changes
    appExcel.Quit
    Set wbk = Nothing
    Set appExcel = Nothing
    
    rs.AddNew
        rs![Job #] = strJob + "-" + strSubJob
        rs![Press] = strPress
        rs![Job Name] = strDescription
        rs![Customer Name] = strCustomer
        rs!Technology = strTechnology
        rs![Order Quantity] = lngOrderPieces
        rs!QC = "IM"
        
        If strTechnology = "BeautiSeal®" Then
            rs![Labels on Repeat] = lngLayoutProd
            rs![FP / Bulk #] = strBulkList
            rs![shot size] = lngShotSum
        End If
       
    rs.Update
    
    rs.Close

    MsgBox "File " + StrImportFile + " has been imported", vbOKOnly
    
    DoCmd.Close
    Application.Echo False
    DoCmd.Close
    DoCmd.OpenForm "Input Form"
    DoCmd.OpenForm "Job Info Form"
    Application.Echo True
        
    
ExitProc:
    Set db = Nothing
    Exit Sub
ErrProc:
    Select Case Err.Number
        Case 462    'excel not open
            Set appExcel = New Excel.Application
            Resume Next
        Case 3125
            MsgBox "The selected workbook is not the correct format.", vbOKOnly
            Resume ExitProc
        Case 3201
            MsgBox "Job Prefix is not valid.  Please add the new prefix to the prefix list.  Import was cancelled.", vbOKOnly
            Resume ExitProc
        Case Else
            MsgBox Err.Number & "--" & Err.Description
            Resume ExitProc
            Resume Next
    End Select
    
End Sub
 

Cronk

Registered User.
Local time
Today, 09:19
Joined
Jul 4, 2013
Messages
2,772
Great to hear you've nailed it. So much satisfaction in doing it yourself with some guidance than just being handed the solution on a plate.
 

dkmoreland

Registered User.
Local time
Yesterday, 16:19
Joined
Dec 6, 2017
Messages
129
Great to hear you've nailed it. So much satisfaction in doing it yourself with some guidance than just being handed the solution on a plate.

Absolutely! There is no nerd buzz when somebody does all the work for you! :D

But - the help I received from you and others on this forum has taught me so much!

Let's mark this one solved. How do I do that?
 

Cronk

Registered User.
Local time
Today, 09:19
Joined
Jul 4, 2013
Messages
2,772
Go to your first post in the thread and then Click EDIT > GO ADVANCED and there you can modify the subject title and that will show in the thread list
 

Users who are viewing this thread

Top Bottom