Microsoft Product Support

  • Subscribe to our RSS feed.
  • Twitter
  • StumbleUpon
  • Reddit
  • Facebook
  • Digg

Tuesday, 26 June 2012

Extracting data from Microsoft Dynamics GP company databases using SQL Server FOR XML and XMLNAMESPACES

Posted on 16:01 by Unknown
I truly love what I do. Really!

My job takes me just about everywhere around this great country of ours and beyond its borders in the quest of helping clients and partners get the best out of their Microsoft Dynamics GP application and data.

In reference to the latter - data - I had been asked recently by a client how they could produce XML formatted data from their Microsoft Dynamics GP databases to be consumed by some web services applications they had developed. Some conditions around this request:
  • The client did not want to implement eConnect Requester, though I have to admit this would have been a slam dunk with MSMQ queues. 
  • The XML documents needed to be rather available and changeable very quickly to serve other needs.
  • No additional investments in third party products, middlewares or the likes could be suggested since budget was pretty tight.
In other words, no eConnect, no third party products, and lots of flexibility...

The answer could only be one: use the powerful XML capabilities of T-SQL to get data out in the format required by the client.

Some theory

There's a powerful option when querying data from SQL Server for use with third party applications and/or web services. You can execute SQL queries to return results as XML instead of standard rowsets. These queries can be executed directly or executed from within stored procedures and user-defined functions.

The FOR XML clause has some great benefits:

  • It allows a SQL Server developer of Microsoft Dynamics GP consultant to write critical pieces of integration architecture without having to learn the destination system's schema.
  • Additional table columns - pieces of data, if you will - can be added to the results with relative ease.
  • It's an efficient way to process data and reduces the number of components that must be developed.
  • It can be formatted to match target schemas in order to simplify mapping and/or middleware configuration.
There are a number of options related to using the FOR XML clause in SQL Server. The most appropriate way I have found - best practice, if you will - is to declare your own namespace using the WITH XMLNAMESPACES clause and to format the XML specifically as expected with the PATH mode.

Keep in mind that SQL Server has an AUTO mode which allows it to automatically format the XML document for you, relinquishing some control from you the developer or consultant.

For more information on SQL Server FOR XML and the WITH XMLNAMESPACES clauses, please take a look at SQL Server Books Online:

MSDN - FOR XML clause - http://msdn.microsoft.com/en-us/library/ms178107.aspx
MSDN - WITH XMLNAMESPACES clause - http://msdn.microsoft.com/en-us/library/ms177400.aspx

Now a practical application...

This is a simple example on how to implement all of it together. Let's take the case of a Customer with multiple addresses. The following query should produce XML data with our customer master (RM00101) and address master information (RM00102).

CustomerExtract.sql
-- Created by Mariano Gomez, MVP
-- This code is licensed under the Creative Commons
-- Attribution-NonCommercial-ShareAlike 2.5 Generic license.

WITH XMLNAMESPACES('http://sql.customer.extract' as "ce0")
SELECT NULL
, ( SELECT RM00101.CUSTNMBR AS [ce0:CustomerNumber]
,RM00101.CUSTNAME AS [ce0:CustomerName]
,RM00101.CHEKBKID AS [ce0:CheckbookID]
, ( SELECT RM00102.ADRSCODE AS [ce0:AddressCode]
, RM00102.ADDRESS1 AS [ce0:Address1]
, RM00102.ADDRESS2 AS [ce0:Address2]
, RM00102.CITY AS [ce0:City]
, RM00102.[STATE] AS [ce0:State]
, RM00102.ZIP AS [ce0:Zipcode]
FROM RM00102
WHERE RM00102.CUSTNMBR = RM00101.CUSTNMBR
FOR XML PATH('ce0:Addresses'), TYPE)
FROM RM00101
FOR XML PATH('ce0:Customer'), TYPE)
FOR XML PATH ('ce0:CustomerExtract'), TYPE

The results are pretty straight forward:

FOR XML output (formatted for display purposes only)

Nothing but XML greatness!

The above query could have been encapsulated in a stored procedure with a parameter for customer number, which could have driven the results displayed. As you can tell, getting the data you need for any destination, will depend on you specific requirements, but it's doable with the power of SQL Server and T-SQL.

Until next post!

MG.-
Mariano Gomez, MVP
IntellPartners, LLC
http://www.IntellPartners.com/
Email ThisBlogThis!Share to XShare to FacebookShare to Pinterest
Posted in Integration, SQL Scripting, SQL Server | No comments
Newer Post Older Post Home

0 comments:

Post a Comment

Subscribe to: Post Comments (Atom)

Popular Posts

  • The Open XML SDK 2.0 for Microsoft Office
    Along with the introduction of Microsoft Dynamics GP 2010 Word Templates came a little known software development kit: Open XML SDK 2.0. Ope...
  • Year-to-year Inventory Margin Report using the PIVOT operator in T-SQL
    As of late I have been camping out at the SQL Developer Center's   Transact-SQL Forum  and I have to say, I have learned a great deal fr...
  • Web Client Wednesday - Browser Support
    Last week MVP Mark Polino started a series called Web Client Wednesdays, which is actually a Microsoft Dynamics GP community outreach to st...
  • SmartList Designer: a nice addition to Microsoft Dynamics GP 2013 SP2
    12.00.1482 - the build number for Microsoft Dynamics GP SP2 - brought with it a new list of awesome enhancements. The SmartList reporting to...
  • Granting Access and Binding Defaults when recreating SQL Tables: a follow up
    In his most recent article, Granting Access and Binding Defaults when recreating SQL Tables , my good friend, David Musgrave, points out how...
  • VBA - Suppressing CTRL+Break or CTRL+C in VBA Customizations
    VBA is by far one of the best customization tools available to Microsoft Dynamics GP developers and as such it is widely used across a numbe...
  • Printing to screen and PDF file causes default printer to change to Acrobat PDF Writer
    A user recently reported a strange Microsoft Dynamics GP behavior when trying to print any report in to file in PDF format, while simultaneo...
  • Rejecting duplicate checks during Bank Transactions import with Integration Manager
    One of the interesting things about checkbooks setup in Microsoft Dynamics GP is that you have the ability to prevent duplicate checks from ...
  • Microsoft Dynamics GP Add-In for Microsoft Word not enabling despite several attempts to install
    Just recently, I ran into a situation with the Microsoft Dynamics GP Add-In for Microsoft Word where, after following all the installation s...
  • Adobe PDF Converter error when sending report to PDF in Microsoft Dynamics GP
    Just recently, I was working on a few Report Writer reports for a client and assisting with installing the latest Adobe Acrobat Standard ver...

Categories

  • Ad Campaigns
  • ADO
  • Adobe Acrobat
  • Analytical Accounting
  • Architecture
  • Around the Blogosphere
  • Article
  • Azure
  • Bank Reconciliation
  • Best of 2009
  • Best of Series
  • Best Practices
  • Bing Maps Enterprise
  • Books
  • Business Alerts
  • Business Analyzer
  • C#
  • Code
  • COM
  • Community
  • Compliance
  • Connect
  • Continuum
  • Convergence
  • Corporate Performance Management
  • CRM
  • Database Maintenance Utility
  • Decisions Conference
  • DEX.INI
  • DEXSQL
  • Dexterity
  • Discussions
  • Drill-Down Builder
  • Dynamics GP 10
  • Dynamics GP 11
  • Dynamics GP 12
  • Dynamics GP 2010
  • Dynamics GP 2010 R2
  • Dynamics GP 2013
  • eConnect
  • EFT
  • Electronic Banking
  • Encumbrance
  • Events
  • Extender
  • Field Services
  • Fixed Assets
  • Forecaster
  • From the Newsgroups
  • FRx
  • Functionality
  • General Ledger
  • GPUG
  • Home Page
  • Human Resources
  • Humor
  • IMHO
  • Installation
  • Integration
  • Integration Manager
  • Internet Explorer
  • Inventory
  • Kinnect
  • Maintenance
  • Management Reporter
  • Manufacturing
  • Menus for Visual Studio Tools
  • Microsoft Office
  • Modifier
  • Multicurrency Management
  • Multitenancy
  • MVP Summit
  • MVPs
  • Named Printers
  • Navigation Pane
  • Notes
  • ODBC
  • Office Web Components
  • OLE Container
  • Online Services
  • OpenXML
  • Partner Connections
  • Payables Management
  • Payroll
  • Performance
  • PO Commitments
  • Printer Compatibility
  • Product Feedback
  • Project Accounting
  • Purchasing
  • Receivables Management
  • RemoteApp
  • Report Writer
  • Reporting
  • Roadmap
  • SafePay
  • Sales Order Processing
  • Season Greetings
  • Security
  • Service Call Management
  • SharePoint
  • SmartList and SmartList Builder
  • SQL Reporting Services
  • SQL Scripting
  • SQL Server
  • Support Debugging Tool
  • Tax Updates
  • Technical Conference
  • The Partner Event
  • The Technology Corner
  • Training
  • Translation
  • Troubleshooting
  • Upgrades
  • VAT
  • VB.NET
  • VBA
  • VBScript
  • Visual Studio 2008
  • Visual Studio Tools
  • Web Client
  • Web Services
  • Windows 7
  • Windows 8
  • Word Templates
  • XBox
  • XBRL

Blog Archive

  • ►  2013 (68)
    • ►  December (2)
    • ►  November (8)
    • ►  October (5)
    • ►  September (5)
    • ►  August (3)
    • ►  July (8)
    • ►  June (5)
    • ►  May (5)
    • ►  April (2)
    • ►  March (11)
    • ►  February (6)
    • ►  January (8)
  • ▼  2012 (101)
    • ►  December (8)
    • ►  November (6)
    • ►  October (15)
    • ►  September (16)
    • ►  August (9)
    • ►  July (4)
    • ▼  June (4)
      • Extracting data from Microsoft Dynamics GP company...
      • Errol Schoenfish: 25 years and still loving it
      • Leveraging Custom Links to track carrier shipments...
      • Microsoft West Coast Customs 67 Mustang
    • ►  May (6)
    • ►  April (4)
    • ►  March (11)
    • ►  February (4)
    • ►  January (14)
  • ►  2011 (158)
    • ►  December (7)
    • ►  November (17)
    • ►  October (7)
    • ►  September (8)
    • ►  August (8)
    • ►  July (12)
    • ►  June (12)
    • ►  May (13)
    • ►  April (23)
    • ►  March (21)
    • ►  February (10)
    • ►  January (20)
  • ►  2010 (168)
    • ►  December (15)
    • ►  November (11)
    • ►  October (12)
    • ►  September (24)
    • ►  August (13)
    • ►  July (12)
    • ►  June (8)
    • ►  May (17)
    • ►  April (14)
    • ►  March (9)
    • ►  February (16)
    • ►  January (17)
  • ►  2009 (5)
    • ►  December (5)
Powered by Blogger.

About Me

Unknown
View my complete profile