Importing XML through .NET Web Service with VBA

brazilnut

New Member
Joined
Sep 13, 2005
Messages
41
I need some guidance regarding importing XML data through .NET Web Services using VBA.

I currently have a spreadsheet (Excel v 2003) that utilizes external data. I currently use ADODB to connect to and retrieve data from my databases. These import procedures are written in VBA code modules and are invoked through various forms and buttons throughout the spreadsheet. These databases are located on a SQL Server (v 5.1 I think). I have local ODBC datasources setup on my PC to access the data. And the queries are written in stored procedures. The problem is that I can only use the spreadsheet on a PC with access to the SQL server. My solution is to setup a .NET Web Service that makes the calls to the DB and returns an XML result set to the calling app (or client application). The difficulty I am having is creating the procedure in VBA to open, read, and copy the XML data from the web service to a range of cells in my spreadsheet.

This is what I have so far:

Here is the WebMethod I have setup on the web service:
Code:
‘ convert an adodb recordset into xml and return the a string of xml
Public Function ConvertADODBRecordset2XmlString(ByRef rst As ADODB.Recordset) As String
   Dim oDomDoc As New Interop.MSXML5.DOMDocument40Class
   rst.Save(oDomDoc, ADODB.PersistFormatEnum.adPersistXML)
   Return oDomDoc.xml
End Function

Here is the code I have in my VBA code module:
Code:
Public Sub GetData()
  Dim objSClient As MSSOAPLib30.SoapClient30  
  Dim oXML As MSXML2.DOMDocument40
    
  ' Point the SOAP API to the web service that we want to call...
  Set objSClient = New SoapClient30   
  Call objSClient.mssoapinit(par_WSDLFile:="http://localhost/WebService/WebService.wsdl")
  
  'create new empty XML document
   Set oXML = New DOMDocument40
   
  ' Call the web service and get requested XML document
  Call oXML.LoadXml(objSClient.ConvertADODBRecordset2XmlString(var1, var2, var3))
  
  ' copy xml data to sheet in Excel
???WHAT CODE DO I USE HERE????
  
  Set oXML = Nothing
  Set objSClient = Nothing
  
End Sub

Before I was using the Range(“A1”).CopyFromRecordset rst method. This worked GREAT. Very fast and easy to use. The code I have now seems to work fine. I simply don’t know of a good way to get the XML data in the cells, like I did with ADODB. Does this make sense?

Thank you.

PS – I have considered converting the xml back into a recordset and then use the .CopyFromRecordset procedure. But I don’t know how slow this would make the app. The speed of the data imports is very fast. I would like to keep it that way.
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
GOT IT!!

For those who may find it useful, I have figured it out. Here is the algorithm:

Code:
Public Sub GetXML()
  
  Dim objSClient As MSSOAPLib30.SoapClient30    ' soap object to access and expose web service interface
  Dim oXML As MSXML2.DOMDocument40              ' xml document object
  Dim rst As New ADODB.Recordset                ' ADODB recordset
  Dim str As New ADODB.Stream                   ' ADODB stream
    
  ' create new soap client
  Set objSClient = New SoapClient30
  
  'create new empty XML document
   Set oXML = New DOMDocument40
  
  ' Point the SOAP API to the web service that we want to call...
  ' the wsdl file contains the scheme for the webservice
  Call objSClient.mssoapinit(par_WSDLFile:="http://localhost/WebService.wsdl")
  
  ' Call the web service and load requested XML document in to MSXML DOM document structure
  Call oXML.LoadXml(objSClient.GetXMLString())
  
  ' open sream
  str.Open
  
  ' save xml document from web service to stream
  oXML.Save str
  
  ' set starting position to beginning of stream
  str.Position = 0
  
  ' open recordset from stream
  rst.Open str
    
  ' copy recordset to range of cells
  Range("A1").CopyFromRecordset rst
  
  Set oXML = Nothing
  Set objSClient = Nothing
  Set rst = Nothing
  Set stream = Nothing
  
End Sub

My next step is to figure out how to get the field names from the XML file.
 
Upvote 0
Hi There,

Did you have any luck with this? I am also quite interested in pointing excel at a wsdl and getting it to extract the web service field definitions - anyone have any ideas how to do this?

Cheers,
Rob
 
Upvote 0

Forum statistics

Threads
1,214,935
Messages
6,122,337
Members
449,078
Latest member
skydd

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