Quickly Import and Export Excel Data with LINQ to XML

Quickly Import and Export Excel Data with LINQ to XML

Rate This
  • Comments 94

One really handy thing to do with relational data is to import and export it to Excel. This can be a total snap using LINQ to XML in Visual Basic 2008. For example, let's say I want to import data from an Excel spreadsheet into a local database file like SQL Compact Edition. I also want to be able to export that data back into an Excel spreadsheet, basically allowing me to edit the data from either my application or Excel.

The trick really is getting the format of the Excel spreadsheet as XML and using that sheet as a template to populate your data. First open Excel (for this example I'll use the Excel 2003 format so you can use Excel 2007 or 2003 to follow along). Next let's enter some column headers, for my example I have a list of customers I want to import/export so the fields I'll want are Abbrev, Name, Phone, Country. It's also helpful to enter one line of dummy data (you'll see why in a second). So here' what we've got:

Now what I want to do is get all the customers stored in my little SQL CE local database into this spreadsheet.

(As a side note, you can easily add a SQL CE local database file to your project by selecting the "Local Database" new item template in Visual Studio 2008. You can easily access the data in SQL CE sdf files by adding a new datasource (Data --> Add New Datasource), adding a new connection, and change the data source to "Microsoft Compact SQL Server 3.5" then locate or create the .sdf file. Then you can create typed Datasets like normal.)

So I have a form where I just dragged my CustomersDataSet that I created from my local database file onto it as a DataGridView. This also sets up the BindingSource and BindingNavigator toolstrip like we'd expect. I added a couple buttons to the toolstrip one called "Import" and one called "Export".

Now in order to get the Excel spreadsheet into an XML format you can simply "Save As.." and select "XML Spreadsheet 2003 (.xml)" as the file type. Now navigate to that file and open it with notepad, select and copy all the text into your clipboard. Open up your Visual Basic program, type "Dim sheet =" and then paste the contents of your clipboard directly into the editor. It should look something like this (I collapsed some of the sections we're going to ignore):

Next we need to import the namespaces in the spreadsheet. This is necessary so that when we create and query our XML, Visual Basic will know the correct namespaces we're working with. So at the top of code file for our form we'll add:

Imports <xmlns="urn:schemas-microsoft-com:office:spreadsheet">

Imports <xmlns:o="urn:schemas-microsoft-com:office:office">

Imports <xmlns:x="urn:schemas-microsoft-com:office:excel">

Imports <xmlns:ss="urn:schemas-microsoft-com:office:spreadsheet">
Imports <xmlns:html="http://www.w3.org/TR/REC-html40">

Now we can write a query that will take all of the customers in our SQL CE database file (technically the typed DataSet that was created for us) and populate the spreadsheet. You should see your dummy data in the XML above. Cut that out (ctrl-X) because we're going to replace that with all our customers using embedded expressions like so:

Dim customers = _

    From customer In Me.CustomersDataSet.Customers _

    Where customer.RowState <> DataRowState.Deleted _

        AndAlso Not customer.IsAbbrevNull _

    Order By customer.Abbrev _

    Select <Row>

               <Cell><Data ss:Type="String"><%= customer.Abbrev %></Data></Cell>

               <Cell><Data ss:Type="String"><%= If(customer.IsNameNull, "", customer.Name)%> </Data></Cell>

               <Cell><Data ss:Type="String"><%= If(customer.IsPhoneNull, "", customer.Phone)%> </Data></Cell>

               <Cell><Data ss:Type="String"><%= If(customer.IsCountryNull, "",customer.Country)%> </Data></Cell>

           </Row>

I'm just selecting the data inside my typed Dataset which is populated in the load of the form, making sure not to grab any deleted rows or rows where the abbreviation is NULL. The customers variable above becomes a collection of XElements (IEnumerable(Of XElement)) and we simply pop that back into the sheet, replacing the dummy line we removed:

<Table ss:ExpandedColumnCount="4" ss:ExpandedRowCount=<%= customers.Count + 1 %> x:FullColumns="1" x:FullRows="1" ss:DefaultRowHeight="15">

<Row ss:StyleID="s62">

               <Cell><Data ss:Type="String">Abbrev</Data></Cell>

               <Cell><Data ss:Type="String">Name</Data></Cell>

               <Cell><Data ss:Type="String">Phone</Data></Cell>

               <Cell><Data ss:Type="String">Country</Data></Cell>

       </Row>

       <%= customers %>

</Table>

Also notice that I had to adjust the ss:ExpandedRowCount attribute as well to include the count of our customers plus one for the header row. Now we can write the results out to disk and start Excel:

sheet.Save("C:\Customers.xml")

Process.Start("Excel.exe", "C:\Customers.xml")

Cool!

Okay so now we want to be able to import this data as well. If any rows were added or edited we want that data back in our database. I'm going to use the Abbrev field as the unique identifier of our data. The query we need to write will group join (outer join) the current (non-deleted) rows in our CustomerDataSet to the rows here in the spreadsheet. That way if the resulting items in the collection contain a group (of one CustomerDataRow in this case), then we know that the CustomerDataRow needs to be updated, otherwise we know it's a new customer that needs to be added. We also need to skip the first row because that's our header row in the spreadsheet, and I'm doing an extra check for empty cells.

Dim sheet = XDocument.Load("C:\Customers.xml")

 

'Skip the first row because that is the header row in the spreadsheet.

'Notice also that we're eliminating deleted rows from the group join.

'We'll use the existence of the group collection to determine if the

' row needs to be added to the database.

Dim customers = From xmlCustomer In sheet...<Row> _

                   Let Abbrev = xmlCustomer.<Cell>(0) _

                   Let Name = xmlCustomer.<Cell>(1) _

                   Let Phone = xmlCustomer.<Cell>(2) _

                   Let Country = xmlCustomer.<Cell>(3) _

                Where _

                   Abbrev IsNot Nothing AndAlso _

                   Name IsNot Nothing AndAlso _

                   Phone IsNot Nothing AndAlso _

                   Country IsNot Nothing _

                Group Join customer In _

                    (From row In Me.CustomersDataSet.Customers _

                       Where row.RowState <> DataRowState.Deleted _

                             AndAlso Not row.IsAbbrevNull _

                       Select row) _

                    On customer.Abbrev Equals Abbrev _

                    Into Group _

                Select _

                    Abbrev = Abbrev.Value, _

                    Name = Name.Value, _

                    Phone = Phone.Value, _

                    Country = Country.Value, _

                    Group _

                Skip 1

 

 

'Add or update the customer row depending on if the

' group collection exists.

For Each customer In customers

    Dim r As CustomersDataSet.CustomersRow

    If customer.Group.Count = 0 Then

        'Add new row ands set the customer abbreviation.

        ' This field is used to determine uniqueness of the data

        r = Me.CustomersDataSet.Customers.NewCustomersRow()

        r.Abbrev = customer.Abbrev

    Else

        r = customer.Group(0)

    End If

 

    r.Name = customer.Name

    r.Phone = customer.Phone

    r.Country = customer.Country

 

    If r.RowState = DataRowState.Detached Then

        Me.CustomersDataSet.Customers.AddCustomersRow(r)

    End If

Next

Now we can make changes to the spreadsheet, import the data into our local database, or make changes to our local database and export those changes to Excel. I've attached the complete example built with Visual Basic 2008. You'll also need Excel 2003 or higher to view the spreadsheet. It's worth reiterating that you don't actually need Excel to create the spreadsheet in Visual Basic via code as long as you have the XML format, you just need it if you want to open it in Excel later. Remember we're not using automation, we're just creating XML in a specific format.

Enjoy!

Attachment: ImportExportExcel.zip
Leave a Comment
  • Please add 8 and 7 and type the answer here:
  • Post
  • Nice work beth as usual, but you are unfair.

    You should give the code in VS 2005 too.

    btw good job.

  • Hi Ryan,

    LINQ is only available in VS 2008. You can download the beta here: http://msdn2.microsoft.com/en-us/vstudio/aa700831.aspx

    I'd have to take a different approach in VS2005 that wouldn't be as quick. :-) Like using automation or some XSLT.

  • We just released a new set of How-Do-I videos in our LINQ series on LINQ to XML in Visual Basic. These

  • We just released a new set of How-Do-I videos in our LINQ series on LINQ to XML in Visual Basic. These

  • I'm getting an error message "Expression cannot be converted into an expression tree" with th efollowing part underlined:

               Select <Row>

                          <Cell><Data ss:Type="String"><%= customer.Abbrev %></Data></Cell>

                          <Cell><Data ss:Type="String"><%= customer.Name %></Data></Cell>

                          <Cell><Data ss:Type="String"><%= customer.Phone %></Data></Cell>

                          <Cell><Data ss:Type="String"><%= customer.Country %></Data></Cell>

                      </Row>

    The IDE is Visual Studio 2008 9.0.20706.1 Beta 2

    .Net framework 3.5

    Any ideas?

     Thanks

        Duncan

  • Here's a summary of all the content the VB team members, including myself, have created for you on the

  • Hi Duncan,

    I recall that being a bug in Beta 2 (now fixed, of course ;-)). To work around this try adding a collection type that's not LINQ to SQL. Something like:

    Dim dummy() As String = {""}

    Dim customers = From d In dummy _

          From customer In dbNorthwind.Customers _

          Order By customer.CompanyName _

          Select <Row>

                    <Cell><Data ss:Type="String"><%= customer.CustomerID %></Data></Cell>

                    <Cell><Data ss:Type="String"><%= customer.CompanyName %></Data></Cell>

                    <Cell><Data ss:Type="String"><%= customer.Phone %></Data></Cell>

                    <Cell><Data ss:Type="String"><%= customer.Country %></Data></Cell>

                    </Row>

    BTW, today Soma announced that VS 2008 will be released this month! http://www.microsoft.com/presspass/press/2007/nov07/11-05TechEdDevelopersPR.mspx

  • I had some questions for you and figured you gave us your phone number in case we had some questions or were otherwise bored and lonely.  I tried the number and. . .You're a liar!  That's not your real phone number.  This kind of dishonesty just will not stand.

  • LOL Curt. Good one, I missed the example. If I gave my real phone number out on the internet I'd have more problems than just my backlog of email ;-)

  • Beth,

    Using Beta 2 and the "dummy fix" above the xl sheet will not open, the row data is as follows???

    <Row xmlns:ss="urn:schemas-microsoft-com:office:spreadsheet" xmlns="urn:schemas-microsoft-com:office:spreadsheet">

     <Cell>

       <Data p4:Type="String" xmlns:p4="urn:schemas-microsoft-com:office:spreadsheet">450813</Data>

     </Cell>

     <Cell>

       <Data p4:Type="String" xmlns:p4="urn:schemas-microsoft-com:office:spreadsheet">PROTECTION SPRAY WEICON STAINLESS STEEL 400ML</Data>

     </Cell>

     <Cell>

       <Data p4:Type="String" xmlns:p4="urn:schemas-microsoft-com:office:spreadsheet">3</Data>

     </Cell>

    </Row>

  • Re last post, Fixed, didnt set the ExpandedRowCount!

  • Beth,

    Really useful information.

    Not sure if this is an issue or is known behaviour;-

    With the following in the class;-

    Imports <xmlns="urn:schemas-microsoft-com:office:spreadsheet">

    This code accessing Xdocument does not work

    Dim specsX = XDocument.Parse(SpecText)

           Dim EQ = New With { _

                   .EqName = specsX...<name>.Value, _

                   .EqMake = specsX...<manufacturer>.Value}

    Had to put the code in a seperate class, which prompts the question how do I access the properties in EQ outside of that function ?

    Thanks,

    Kerry

  • Hi Kerry,

    I'm not sure what SpecText is in the above code but in order to pass out EQ in this case you would create a class (say you call it MyStuff) with two properties EqName and EqMake then you could do something like:

    Dim EQ As MyStuff = New MyStuff With {....

    Since you can't pass around anonymous types you just need to explicitly create a class first and use that instead.

    HTH,

    -B

  • Beth,

    Thanks for your prompt reply, as always you have the skill to explain in simple terms, solving the problem without going too deep! This iterative learning approach is the 'only' way for many of us trying to earn a living while embracing the new..

    SpectText is a simple string of XML that was extracted from an ntext column in SQL compact. The same code works OK when it is seperate from the imports statement.

    Thanks again,

    Kerry

  • I have an excel spreadsheet with data that I want to export to sql using vb.net and xml. I understand how you transferred data from sql to excel but what if you started with excel that has all the data and want to transfer to sql.

Page 1 of 7 (94 items) 12345»