Microsoft Product Support

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

Monday, 8 August 2011

SQL: Assigning Microsoft Dynamics GP Users to SSRS Database Roles

Posted on 11:25 by Unknown
As I begin to wrap up a Microsoft Dynamics GP 2010 R2 production upgrade from Microsoft Dynamics GP 9.0, I ran into a small issue at my client. After deploying the new SSRS reports, and as users were getting ready to try them out, we realized that some 15 logins needed to be assigned to a number of the 24 default database security roles created for the SSRS reports.




User Mappings (some information blurred to protect the client's identity)

This would be a bit cumbersome giving the share number of clicks required to accomplish this feat. In addition, we had just setup Microsoft Dynamics GP security, and given that the SSRS database roles were similar to those in GP, something needed to be done to automate the assignment of these roles based on Microsoft Dynamics GP security roles.

As a result, I created the following script:

-- Created by Mariano Gomez, MVP

-- This code is licensed under the Creative Commons

-- Attribution-NonCommercial-ShareAlike 2.5 Generic license.

use DYNAMICS;

go



DECLARE @userid varchar(50), @companyid varchar(5), @securityroleid varchar(200), @ssrsRole varchar(200);

DECLARE @sqlStmt varchar(255);



DECLARE c_reportsecurity CURSOR FOR

SELECT a.USERID, b.INTERID, a.SECURITYROLEID FROM SY10500 a

LEFT OUTER JOIN SY01500 b ON (A.CMPANYID = b.CMPANYID)

WHERE a.USERID not in ('sa', 'DYNSA', 'LESSONUSER1', 'LESSONUSER2') and a.SECURITYROLEID NOT LIKE ('MBS%')

ORDER BY a.USERID;



OPEN c_reportsecurity;

FETCH NEXT FROM c_reportsecurity INTO @userid, @companyid, @securityroleid;



WHILE @@FETCH_STATUS = 0

BEGIN

SELECT @ssrsrole =

CASE

WHEN @securityroleid = 'ACCOUNTING MANAGER* ' THEN 'rpt_accounting manager'

WHEN @securityroleid = 'AP CLERK* ' THEN 'rpt_accounts payable coordinator'

WHEN @securityroleid = 'AR CLERK* ' THEN 'rpt_accounts receivable coordinator'

WHEN @securityroleid = 'BOOKKEEPER* ' THEN 'rpt_bookkeeper'

WHEN @securityroleid = 'CA AGENT* ' THEN ''

WHEN @securityroleid = 'CA MANAGER* ' THEN ''

WHEN @securityroleid = 'CA STAKEHOLDER* ' THEN ''

WHEN @securityroleid = 'CERTIFIED ACCOUNTANT* ' THEN 'rpt_certified accountant'

WHEN @securityroleid = 'CL AGENT* ' THEN ''

WHEN @securityroleid = 'CL DISPATCHER* ' THEN 'rpt_dispatcher'

WHEN @securityroleid = 'CL MANAGER* ' THEN ''

WHEN @securityroleid = 'CL STAKEHOLDER* ' THEN ''

WHEN @securityroleid = 'CUSTOMER SERVICE REP* ' THEN 'rpt_customer service rep'

WHEN @securityroleid = 'DP MANAGER* ' THEN ''

WHEN @securityroleid = 'DP STAKEHOLDER* ' THEN ''

WHEN @securityroleid = 'DP TECHNICIAN* ' THEN ''

WHEN @securityroleid = 'FA MANAGER* ' THEN 'rpt_accounting manager'

WHEN @securityroleid = 'FA STAKEHOLDER* ' THEN 'rpt_certified accountant'

WHEN @securityroleid = 'IT OPERATIONS MANAGER* ' THEN ''

WHEN @securityroleid = 'MBS DEBUGGER ADMIN ' THEN ''

WHEN @securityroleid = 'MBS DEBUGGER USER ' THEN ''

WHEN @securityroleid = 'OPERATIONS MANAGER* ' THEN 'rpt_operations manager'

WHEN @securityroleid = 'ORDER PROCESSOR* ' THEN 'rpt_order processor'

WHEN @securityroleid = 'PAYROLL CLERK* ' THEN 'rpt_payroll'

WHEN @securityroleid = 'PM AGENT* ' THEN ''

WHEN @securityroleid = 'PM MANAGER* ' THEN ''

WHEN @securityroleid = 'PM STAKEHOLDER* ' THEN ''

WHEN @securityroleid = 'POWERUSER ' THEN 'rpt_power user'

WHEN @securityroleid = 'PURCHASING AGENT* ' THEN 'rpt_purchasing agent'

WHEN @securityroleid = 'PURCHASING MANAGER* ' THEN 'rpt_purchasing manager'

WHEN @securityroleid = 'RT AGENT* ' THEN ''

WHEN @securityroleid = 'RT MANAGER* ' THEN ''

WHEN @securityroleid = 'RT STAKEHOLDER* ' THEN ''

WHEN @securityroleid = 'SHIPPING AND RECEIVING* ' THEN 'rpt_shipping and receiving'

WHEN @securityroleid = 'WAREHOUSE MANAGER* ' THEN 'rpt_warehouse manager'

WHEN @securityroleid = 'WENNSOFT SMS CONTRACTS* ' THEN ''

WHEN @securityroleid = 'WENNSOFT SMS DISPATCHER* ' THEN ''

WHEN @securityroleid = 'WENNSOFT SMS POWER USER* ' THEN ''

WHEN @securityroleid = 'WENNSOFT SMS SETUP* ' THEN ''

WHEN @securityroleid = 'WSJC ACCOUNTANT* ' THEN ''

WHEN @securityroleid = 'WSJC ACCOUNTING MANAGER* ' THEN ''

WHEN @securityroleid = 'WSJC ADMIN* ' THEN ''

WHEN @securityroleid = 'WSJC BILLING CLERK* ' THEN ''

WHEN @securityroleid = 'WSJC POWERUSER* ' THEN ''

WHEN @securityroleid = 'WSJC PROJECT MANAGER* ' THEN ''

WHEN @securityroleid = 'WSTT PAYROLL CLERK* ' THEN ''

WHEN @securityroleid = 'WSTT POWERUSER* ' THEN ''

END



IF (@ssrsRole <> '')

BEGIN

SET @sqlStmt = 'USE ' + rtrim(@companyid) + '; EXEC sp_addrolemember ' + QUOTENAME(@ssrsRole, '''') + ',' + QUOTENAME(rtrim(@userid), '''');

EXEC(@sqlStmt);

END

FETCH NEXT FROM c_reportsecurity INTO @userid, @companyid, @securityroleid;

END



CLOSE c_reportsecurity;

DEALLOCATE c_reportsecurity;


The script looks at the Security Assignment User Role table (SY10500) and retrieves the physical company database from the Company Master table (SY01500), then assign an SSRS database security role to each of the Microsoft Dynamics GP default roles. If a role does not exist, you can choose to leave the assignment blank.

The script then proceeds to evaluate the database security role obtained, then creates a SQL string that can be executed. The SQL string uses the sp_addrolemember system stored procedure to add the corresponding SQL login to the role. A cursor is used to loop through each user, company, and security role combination to obtain and assign the proper SSRS database role.

You can choose to add custom security roles or roles for third party applications that deploy their own SSRS reports to the above script.

This definitely helped saving some time... phew!

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, Dynamics GP 2010, Dynamics GP 2010 R2, Installation, Security, SQL Reporting Services, 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)
    • ▼  August (8)
      • "Object Reference Not Set" error when running Inte...
      • New Article on MSDynamicsWorld: When It’s Time to ...
      • Default Printer not 'sticking' when running Micros...
      • Cannot insert the value NULL into column 'CONTACT'...
      • Integration Manager for Microsoft Dynamics GP 2010...
      • Integration Manager for Microsoft Dynamics GP 2010...
      • SQL: Assigning Microsoft Dynamics GP Users to SSRS...
      • Cannot insert the value NULL into column 'BASEUOFM...
    • ►  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