Microsoft Product Support

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

Sunday, 21 November 2010

Granting Microsoft Dynamics GP user minimal access at the database level to setup additional users

Posted on 18:25 by Unknown
After the long title of this post, you probably already have the idea of what the article will be about. However, back in April of 2009, I wrote about the POWERUSER role and the Microsoft SQL Server sysadmin server role - see Microsoft Dynamics GP 10 POWERUSER role vs Microsoft SQL Server sysadmin role - and explained the key differences between the two. Among other things, I discussed how a GP user login that's assigned to the sysadmin server role on Microsoft SQL Server becomes able to setup new users in GP.

However, those of you who are database administrators have been quite reluctant to add logins to the sysadmin group, and quite understandably so. After all, logins added to the sysadmin server role can do anything on the database server, and we sure don't want that to happen either.

In response to this, and to the many requests lately on the forums, my friend Robert Cavill, with Emeco Group in Australia, has submitted the following script, which gives a specific user ID in Microsoft Dynamics GP, minimal but sufficient permissions at the Microsoft SQL Server level to create new users. In addition, this script allows Robert's first level support staff with access to Microsoft Dynamics GP, the ability to reset passwords for their user base.

GrantUserRights.sql
--Created by Robert Cavill
--This code is licensed under the Creative Commons
-- Attribution-NonCommercial-ShareAlike 2.5 Generic license.

DECLARE @sUSERID NVARCHAR(15)
SET @sUSERID = 'LESSONUSER1'

SET NOCOUNT ON;
SELECT 'EXEC master..sp_addsrvrolemember @loginame = ''' + @sUSERID + ''', @rolename = N''securityadmin'';'

SELECT
'USE [DYNAMICS];
GO
IF NOT EXISTS (SELECT * FROM sys.database_principals WHERE name = ' + QUOTENAME(@sUSERID, CHAR(39)) + ')
CREATE USER '+ QUOTENAME(@sUSERID) + ' FOR LOGIN ' + QUOTENAME( @sUSERID ) + ';
EXEC sp_addrolemember N''db_accessadmin'', ' + QUOTENAME(@sUSERID, CHAR(39)) + ';
EXEC sp_addrolemember N''db_securityadmin'',' + QUOTENAME(@sUSERID, CHAR(39)) + ';
EXEC sp_addrolemember N''DYNGRP'', ' + QUOTENAME(@sUSERID, CHAR(39)) + ';
GO'

SELECT
'USE [' + RTRIM(INTERID ) + '];
IF NOT EXISTS (SELECT * FROM sys.database_principals WHERE name = ' + QUOTENAME(@sUSERID, CHAR(39)) + ')
CREATE USER '+ QUOTENAME(@sUSERID) + ' FOR LOGIN ' + QUOTENAME( @sUSERID ) + ';
EXEC sp_addrolemember N''db_accessadmin'', ' + QUOTENAME(@sUSERID, CHAR(39)) + ';
EXEC sp_addrolemember N''db_securityadmin'',' + QUOTENAME(@sUSERID, CHAR(39)) + ';
EXEC sp_addrolemember N''DYNGRP'', ' + QUOTENAME(@sUSERID, CHAR(39)) + ';
GO'
FROM DYNAMICS..SY01500

When this script is executed against the DYNAMICS database for a specified Microsoft Dynamics GP user (@sUSERID variable), the result is another script granting the correct access to all the Microsoft Dynamics GP company databases.

Result
EXEC master..sp_addsrvrolemember @loginame = 'LESSONUSER1', @rolename = N'securityadmin';

USE [DYNAMICS];
GO
IF NOT EXISTS (SELECT * FROM sys.database_principals WHERE name = 'LESSONUSER1')
CREATE USER [LESSONUSER1] FOR LOGIN [LESSONUSER1];
EXEC sp_addrolemember N'db_accessadmin', 'LESSONUSER1';
EXEC sp_addrolemember N'db_securityadmin

USE [TWO];
IF NOT EXISTS (SELECT * FROM sys.database_principals WHERE name = 'LESSONUSER1')
CREATE USER [LESSONUSER1] FOR LOGIN [LESSONUSER1];
EXEC sp_addrolemember N'db_accessadmin', 'LESSONUSER1';
EXEC sp_addrolemember N'db_securityadmin','LESSON

Upon running the result script, the new database permissions will enable the Save button on the User Maintenance window, and allow users to be assigned to companies in the User Access window.

Here are a few additional tips:
  1. With this approach, the Microsoft Dynamics GP user is not a member of the sysadmin fixed server role.
  2. The user ID must already exist in Microsoft Dynamics GP with access to at least one company so they can log on.
  3. If, after executing this script, you attempt to delete the user ID from GP, it will fail.
In the following post, I will publish the script that will reverse the outcome to allow deletion of the user ID from Microsoft Dynamics GP.

Until next post!

MG.-
Mariano Gomez, MVP
Maximum Global Business, LLC
http://www.maximumglobalbusiness.com/
Email ThisBlogThis!Share to XShare to FacebookShare to Pinterest
Posted in Code, Security, SQL Scripting | No comments
Newer Post Older Post Home

0 comments:

Post a Comment

Subscribe to: Post Comments (Atom)

Popular Posts

  • 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...
  • Vote for your 2012 GPUG All Star
    The time has come again to vote for the next year's GPUG All Star awards. Surprisingly, I have been nominated to this award along with f...
  • 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...
  • Changing the metrics properties on the Microsoft Dynamics GP home page - Part 2
    Part 2 of 2 - Changing the metrics properties on the Microsoft Dynamics GP home page. In Part 1 of the series  I showed a couple cool things...
  • 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...
  • Extracting data from Microsoft Dynamics GP company databases using SQL Server FOR XML and XMLNAMESPACES
    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 ...
  • Windows 8 and the Microsoft Dynamics GP Web Client Series - Part 1
    Windows 8 and the Microsoft Dynamics GP Web Client Series Part 1 This series narrate my personal experiences of installing Microsoft Dynamic...
  • Extender Auto Open and Auto Close options not working in GP 2010
    Just recently, I came across an issue reported by a partner on Extender Auto Open and Auto Close options not working. Extender Auto Open a...
  • Microsoft Dynamics GP 2013 on Windows Azure: The Deployment Process
    Welcome to the third installment on Microsoft Dynamics GP 2013 on Windows Azure. In the previous article I showed how to provision the vario...

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)
    • ►  July (12)
    • ►  June (12)
    • ►  May (13)
    • ►  April (23)
    • ►  March (21)
    • ►  February (10)
    • ►  January (20)
  • ▼  2010 (168)
    • ►  December (15)
    • ▼  November (11)
      • Microsoft Dynamics GP - More than just Program Files!
      • Add-In Initialization Error when launching Microso...
      • Happy Thanksgiving!
      • Disabling Multiple Ledgers functionality in Micros...
      • Granting Microsoft Dynamics GP user minimal access...
      • And speaking about Conferences...
      • Dex - Why do memory tables seem to be slower in De...
      • How to change your Microsoft Dynamics GP 2010 Map ...
      • The Dynamics GP Blogster in Las Vegas, Nevada
      • Integration Manager: Integrating journal entries w...
      • Recovering missing eConnect stored procedures
    • ►  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