Microsoft Product Support

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

Thursday, 22 September 2011

Year-to-year Inventory Margin Report using the PIVOT operator in T-SQL

Posted on 08:41 by Unknown
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 from my fellow SQL Server MVPs. Very alike the Microsoft Dynamics GP MVPs, these folks are willing to resolve pretty much any T-SQL request that comes across the forum.

So long you follow some simple posting guides, like including your table definitions, providing some sample data and detailing your expected results, there's nothing these folks won't do for you.

I decided to put some of what I have learned to the test by creating a T-SQL query that would produce a Year-to-year Inventory Margin Report (in currency) by using the T-SQL PIVOT operator. My fellow MVP Mark Polino is very well versed with Microsoft Excel and PowerPivot and I thought this would be a way to demonstrate that you can still use T-SQL to resolve some very complex issues which otherwise would require the use of front-end tool or some back-end cubes.

The following query can be run against the Fabrikam test company and adjusted to meet your specific needs:

;WITH CTE AS (
SELECT YEAR(b.DOCDATE) AS TRXYEAR, a.ITEMNMBR, a.ITEMDESC, SUM(a.XTNDPRCE) AS XTNDPRCE, SUM(a.EXTDCOST) AS EXTDCOST, SUM(a.XTNDPRCE - a.EXTDCOST) AS MARGIN
FROM SOP30300 a LEFT OUTER JOIN SOP30200 b ON (a.SOPTYPE = b.SOPTYPE) AND (a.SOPNUMBE = b.SOPNUMBE)
WHERE (b.SOPTYPE = 3) AND (b.VOIDSTTS = 0)
GROUP BY YEAR(b.DOCDATE), a.ITEMNMBR, a.ITEMDESC
)
SELECT ITEMNMBR AS [Item Number], ITEMDESC AS [Item Description],
COALESCE([2014], 0) AS Y2014,
COALESCE([2015], 0) AS Y2015,
COALESCE([2016], 0) AS Y2016,
COALESCE([2017], 0) AS Y2017
FROM (
SELECT TRXYEAR, ITEMNMBR, ITEMDESC, MARGIN
FROM CTE
) p
PIVOT (
SUM(MARGIN)
FOR TRXYEAR IN ([2014], [2015], [2016], [2017])
) AS pvt
ORDER BY ITEMNMBR;

The script uses a query encapsulated in a Common Table Expression (CTE) to produce a temporary result for the sales data by item, grouped over each year. However, this result would produce rows of records for each year, as shown below:

SELECT YEAR(b.DOCDATE) AS TRXYEAR, a.ITEMNMBR, a.ITEMDESC, SUM(a.XTNDPRCE) AS XTNDPRCE, SUM(a.EXTDCOST) AS EXTDCOST, SUM(a.XTNDPRCE - a.EXTDCOST) AS MARGIN
FROM SOP30300 a LEFT OUTER JOIN SOP30200 b ON (a.SOPTYPE = b.SOPTYPE) AND (a.SOPNUMBE = b.SOPNUMBE)
WHERE (b.SOPTYPE = 3) AND (b.VOIDSTTS = 0)
GROUP BY YEAR(b.DOCDATE), a.ITEMNMBR, a.ITEMDESC

/* Results */

TRXYEAR ITEMNMBR ITEMDESC XTNDPRCE EXTDCOST MARGIN
2014 ACCS-CRD-12WH Phone Cord - 12' White 39.80000 13.16000 26.64000
2014 ACCS-RST-DXBK Shoulder Rest-Deluxe Black 29.85000 13.65000 16.20000
2014 ACCS-RST-DXWH Shoulder Rest - Deluxe White 39.80000 18.20000 21.60000
2014 ANSW-ATT-1000 Attractive Answering System 1000 119.95000 59.29000 60.66000
2014 ANSW-PAN-1450 Panache KX-T1450 answer 219.90000 100.50000 119.40000
2014 FAXX-CAN-9800 Cantata FaxPhone 9800 23999.50000 11970.00000 12029.50000
2014 FAXX-HLP-5433 Hewlett Packard FAX-310 854.50000 395.10000 459.40000
2014 FAXX-SLK-0172 Sleek UX-172 fax 2699.90000 1349.00000 1350.90000
2014 HDWR-PNL-0001 Control Panel 609.95000 303.85000 306.10000
2014 HDWR-PRO-4862 Processor 486/25MHz 5999.95000 2998.15000 3001.80000
2014 PHON-ATT-53BL Cordless-Attractive 5352-Blue 1139.70000 561.30000 578.40000
2014 PHON-ATT-53WH Cordless-Attractive 5352-White 189.95000 92.59000 97.36000
2014 PHON-BUS-1250 Handset,multi-line 359.95000 165.85000 194.10000
2014 PHON-PAN-2315 Panache KX-T231 wall 119.90000 59.50000 60.40000
2014 WIRE-SCD-0001 Single conductor wire 8.75000 4.00000 4.75000
2016 100XLG Green Phone 4136.55000 3829.50000 307.05000

But in order to produce the results we want, having a true year by year comparison, it is necessary to pivot the results of the above query. Here's where the PIVOT operator comes into play, as shown in the initial query. This is the output produced:

Item Number       Item Description      Y2014  Y2015  Y2016  Y2017
100XLG Green Phone 0.00000 0.00000 307.05000 40.05000
3-B3813A Keyboard 0.00000 0.00000 0.00000 40.00000
3-C2924A SCSI Cable, 2.5m. 68-pin HI-Density 0.00000 0.00000 0.00000 148.50000
3-C2924A T0101 - SCSI Cable, 2.5m. 68-pin HI-Density 0.00000 0.00000 0.00000 0.00000
3-C2924A T0102 - SCSI Cable, 2.5m. 68-pin HI-Density 0.00000 0.00000 0.00000 0.00000
3-D2657A T0101 - DB 15 Male Adapter 0.00000 0.00000 0.00000 0.00000
3-D2657A T0102 - DB 15 Male Adapter 0.00000 0.00000 0.00000 0.00000
3-D2659A T0101 - DB 25 Female Adapter 0.00000 0.00000 0.00000 0.00000
3-D2659A T0102 - DB 25 Female Adapter 0.00000 0.00000 0.00000 0.00000
3-E4471A HP Extractor Fan, 200-240V 0.00000 0.00000 0.00000 134.00000
3-E4592A SurgeArrest Plus 0.00000 0.00000 0.00000 180.00000
3-E4592A T0101 - SurgeArrest Plus 0.00000 0.00000 0.00000 0.00000
3-E4592A T0106 - SurgeArrest Plus 0.00000 0.00000 0.00000 0.00000
3-J2094A HP-PB 16 Channel RS-232C Modem Conn MUX 0.00000 0.00000 0.00000 473.00000
4-A3666A 4.2GB LP Disk Drive 0.00000 0.00000 0.00000 350.00000
5-FEE Per Call Fee 0.00000 0.00000 0.00000 0.00000
5-FEE T0101 - Per Call Fee 0.00000 0.00000 0.00000 0.00000
5-FEE T0102 - Per Call Fee 0.00000 0.00000 0.00000 0.00000
5-OVTLABOR T0101 - Overtime service labor 0.00000 0.00000 0.00000 0.00000
5-OVTLABOR T0102 - Overtime service labor 0.00000 0.00000 0.00000 0.00000
5-STDLABOR T0101 - Standard service labor 0.00000 0.00000 0.00000 0.00000
5-STDLABOR T0102 - Standard service labor 0.00000 0.00000 0.00000 0.00000
5-STDLABOR T0106 - Standard service labor 0.00000 0.00000 0.00000 0.00000
5-TVLLABOR T0101 - Travel Labor 0.00000 0.00000 0.00000 0.00000
5-TVLLABOR T0102 - Travel Labor 0.00000 0.00000 0.00000 0.00000
5-TVLLABOR T0106 - Travel Labor 0.00000 0.00000 0.00000 0.00000
ACCS-CRD-12WH Phone Cord - 12' White 26.64000 0.00000 199.80000 226.44000
ACCS-CRD-25BK Phone Cord - 25' Black 0.00000 0.00000 69.85000 83.82000
ACCS-HDS-1EAR Headset-Single Ear 0.00000 0.00000 1034.00000 813.35000
ACCS-HDS-2EAR Headset - Dual Ear 0.00000 0.00000 0.00000 527.67000
ACCS-RST-DXBK Shoulder Rest-Deluxe Black 16.20000 0.00000 226.80000 226.80000
ACCS-RST-DXWH Shoulder Rest - Deluxe White 21.60000 0.00000 163.20000 205.20000
ANSW-ATT-1000 Attractive Answering System 1000 60.66000 0.00000 242.64000 303.30000
ANSW-PAN-1450 Panache KX-T1450 answer 119.40000 0.00000 1194.00000 1134.30000
ANSW-PAN-2460 Panache KX-T2460 answer 0.00000 0.00000 149.60000 169.60000
FAXX-CAN-9800 Cantata FaxPhone 9800 12029.50000 0.00000 66987.41000 51129.85000
FAXX-HLP-5433 Hewlett Packard FAX-310 459.40000 0.00000 0.00000 0.00000
FAXX-RIC-060E Richelieu Fax 60E 0.00000 0.00000 2404.50000 2404.50000
FAXX-SLK-0172 Sleek UX-172 fax 1350.90000 0.00000 1350.90000 675.45000

Happy pivoting.

Until next post!

MG.-
Mariano Gomez, MVP
IntellPartners, LLC
http://www.IntellPartners.com/
Email ThisBlogThis!Share to XShare to FacebookShare to Pinterest
Posted in Code, Inventory, Sales Order Processing, SQL Scripting | 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)
    • ►  May (6)
    • ►  April (4)
    • ►  March (11)
    • ►  February (4)
    • ►  January (14)
  • ▼  2011 (158)
    • ►  December (7)
    • ►  November (17)
    • ►  October (7)
    • ▼  September (8)
      • Jumping on the Windows 8 Metro bandwagon
      • Year-to-year Inventory Margin Report using the PIV...
      • Year-to-year Inventory Margin Report using the PIV...
      • Running Fixed Assets Depreciation causes Microsoft...
      • Microsoft Dynamics GP, the next generation of end-...
      • Getting the Next Voucher Number for a Payables Tra...
      • Could not load file or assembly 'Microsoft.ReportV...
      • Wise up with Wiseguy
    • ►  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