Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Usenet -> c.d.o.misc -> Re: excel to oracle

Re: excel to oracle

From: Charles Hooper <hooperc2000_at_yahoo.com>
Date: Sat, 06 Oct 2007 04:14:53 -0700
Message-ID: <1191669293.305305.13870@o80g2000hse.googlegroups.com>


On Oct 5, 9:16 pm, "Tim B" <nos..._at_someisp.ca> wrote:
> "Charles Hooper" <hooperc2..._at_yahoo.com> wrote in message
>
> news:1191597379.577870.194270_at_r29g2000hsg.googlegroups.com...
> > On Oct 5, 10:37 am, "Tim B" <nos..._at_someisp.ca> wrote:
> > > I have some data in an Excel spreadsheet - about 100 -200 records - that
> I
> > > need to import into Oracle, likely with some transformation required. I
> can
> > > convert it to csv or xml via MS Access and then set it up as an external
> > > table and proceed from there. What other ways could you suggest that
> might
> > > be feasible for this task? Is there another way to do it with xml as the
> > > source?
>
> > If you have Access, the easiest way to do this is to:
> > 1. Connect to the Excel spreadsheet as an external table source in
> > Excel
> > 2. Create a query in Access to retrieve all rows from the Excel
> > spreadsheet and rename the columns so that they match the Oracle
> > table.
> > 3. Create an external table source connection to the Oracle table
> > (through an ODBC connection).
> > 4. Modify the query definition so that it is an append query, and
> > select the connection to the Oracle table.
> > 5. Run the query.
>
> > Much easier than it is to explain.
>
> Well, today I found out that for every record I import from my spreadsheet I
> will need to add a record to an additional table, and I'll have to deal with
> a couple of sequences. What I'm likely going to do is import the spreadsheet
> into Access and use some VBA to read the records, create the needed insert
> statements, and save them to a text file. I'll keep your solution in mind
> for when I have a more straightforward import to do. Thanks.
>
> Tim B

Expanding on a suggestion by Malcolm Dew-Jones - just do it all in Excel. Following is a code sample that I produced a while ago to show someone how to select from and update an Oracle database based on the values in an Excel spreadsheet. Word wrapping will make this a little ugly, but each line is indented, so it should be easy to undo the word wrapping.

Macro security must be medium or low to access the macro. The macro code looks like this:



Sub CheckSpreadsheet()

    Dim dbMyDB As New ADODB.Connection
    Dim snpData As New ADODB.Recordset
    Dim intLastRowChecked
    Dim intFoundFirstBlank
    Dim intResult As Integer
    Dim intColumn
    Dim strColumn
    Dim strFilename
    Dim strWorkbookname
    Dim strSheet
    Dim strExcelValue
    Dim strSQL
    Dim strMessage

    'You must create a reference to Microsoft ActiveX Data Objects (Tools menu)

    'Make sure that we don't crash - looks ugly     On Error Resume Next

    'Replace MyODBCConnection with an ODBC connection name, MyUserName with a database user name and MyPassword with the user's password

    dbMyDB.ConnectionString = "Data Source=MyODBCConnection;User ID=MyUserName;Password=MyPassword;"

    dbMyDB.ConnectionTimeout = 40
    dbMyDB.CursorLocation = adUseClient
    dbMyDB.Open

    strWorkbookname = Right(ActiveWorkbook.FullName, Len(ActiveWorkbook.FullName) - InStrRev(ActiveWorkbook.FullName, "\"))

    strSheet = ActiveSheet.Name

    intLastRowChecked = 1 'Set to skip the first row     intColumn = 65 'Column A
    strColumn = Chr(intColumn)

    Do While intFoundFirstBlank = False

        intLastRowChecked = intLastRowChecked + 1

        'Read the value from the spreadsheet
        strExcelValue =

Format(Workbooks(strWorkbookname).Worksheets(strSheet).Range(strColumn & Format(intLastRowChecked)).Value)
        If strExcelValue = "" Then
            intFoundFirstBlank = True
        Else
            'Could perform an INSERT statement rather than a SELECT
statement
            strSQL = "SELECT" & vbCrLf
            strSQL = strSQL & "  LINE_NO," & vbCrLf
            strSQL = strSQL & "  PART_ID," & vbCrLf
            strSQL = strSQL & "  USER_ORDER_QTY," & vbCrLf
            strSQL = strSQL & "  DESIRED_SHIP_DATE" & vbCrLf
            strSQL = strSQL & "FROM" & vbCrLf
            strSQL = strSQL & "  CUST_ORDER_LINE" & vbCrLf
            strSQL = strSQL & "WHERE" & vbCrLf
            strSQL = strSQL & "  CUST_ORDER_ID='" & strExcelValue &
"'" & vbCrLf
            strSQL = strSQL & "ORDER BY" & vbCrLf
            strSQL = strSQL & "  DESIRED_SHIP_DATE"

            snpData.Open strSQL, dbMyDB

            Do While Not snpData.EOF
                strMessage = strExcelValue & "/" &
Format(snpData("line_no")) & " " &
Format(snpData("desired_ship_date"), "m/d/yyyy") & " " & snpData("part_id") & " Qty " & Format(snpData("user_order_qty"))
                MsgBox strMessage

                snpData.MoveNext
            Loop
            snpData.Close
        End If

    Loop

    Set snpData = Nothing
    dbMyDB.Close
    Set dbMyDB = Nothing
End Sub


The above macro pulls customer order IDs out of the spreadsheet (in column A, stopping when a blank cell is found), and for each of those customer orders, lists the order lines in the database, sorted by desired ship date. Change it around a little, and you can then update the database, rather than just querying information from the database.

With the above method, it should not be a problem dealing with sequences.

Charles Hooper
IT Manager/Oracle DBA
K&M Machine-Fabricating, Inc Received on Sat Oct 06 2007 - 06:14:53 CDT

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US