How to Automatically Determine Employee Raise Eligibility In Microsoft Dynamics GP
Tight budgets and thin margins, along with a low unemployment rate, spur companies to search for better ways to retain their employees. While this is true for many organizations, it is especially true for those with seasonal employees. In order to incentivize seasonal employees to return the following season, a Dynamics GP client analyzes each seasonal employees’ tenure in their position, raise history, and salary data at the beginning and the end of each summer season. Working with the GP team at Stoneridge Software, they put in place a process within Dynamics GP that would generate data automatically and eliminate manual analysis.
To create this report within Dynamics GP, we first created a view of each employee’s position pay code with history reason codes.
create view [dbo].[SSPositionHistoryRecords] as select distinct c.PAYRCORD as [cPAYRCORD] ,c.DSCRIPTN ,c.INACTIVE ,c.PAYTYPE ,c.BSPAYRCD ,c.PAYRTAMT as [cPAYRTAMT] ,c.PAYUNIT as [cPAYUNIT] ,c.PAYUNPER as [cPAYUNPER] ,c.PAYPEROD as [cPAYPEROD] ,a.EMPLOYID ,b.PAYRCORD ,b.EFFECTIVEDATE_I ,b.SEQNUMBR ,b.PAYRTAMT ,b.PAYUNIT ,b.PAYUNPER ,b.PAYPEROD ,b.PAYPRPRD ,b.ANNUALSALARY_I ,b.CHANGEREASON_I ,b.USERID ,a.LASTNAME as [Last Name] ,a.FRSTNAME as [First Name] ,a.STRTDATE as [Hire Date] ,a.BENADJDATE as [Adjusted Hire Date] ,a.INACTIVe as [Inactive Employee] ,d.INACTIVE as [Inactive Pay Code] from UPR00100 as a join UPR00400 d on a.EMPLOYID = d.EMPLOYID and d.INACTIVE = 0 join UPR40600 c on d.PAYRCORD = c.PAYRCORD join HRPSLH01 b on a.EMPLOYID = b.EMPLOYID and b.PAYRCORD = d.PAYRCORD where a.INACTIVE = 0 and d.INACTIVE = 0 and CHANGEREASON_I <> 'Look-up' and c.INACTIVE = 0 and b.BSPAYRCD = '' GO GRANT INSERT, SELECT, DELETE, UPDATE ON [dbo].[SSPositionHistoryRecords] TO [DOMAIN\login] AS [dbo] GO
Next, we created a view of employee position pay codes.
create view [dbo].[SSPositionHistoryLessRecords] as select distinct c.PAYRCORD as [aPAYRCORD] ,c.DSCRIPTN ,c.INACTIVE ,c.PAYTYPE ,c.BSPAYRCD ,c.PAYRTAMT as [cPAYRTAMT] ,c.PAYUNIT as [cPAYUNIT] ,c.PAYUNPER as [cPAYUNPER] ,c.PAYPEROD as [cPAYPEROD] ,a.EMPLOYID ,b.PAYRCORD ,'2010-01-01' as EFFECTIVEDATE_I ,-1 as SEQNUMBR ,b.PAYRTAMT ,b.PAYUNIT ,b.PAYUNPER ,b.PAYPEROD ,b.PAYPRPRD ,0 as ANNUALSALARY_I ,'History' as CHANGEREASON_I ,'' as USERID ,a.LASTNAME as [Last Name] ,a.FRSTNAME as [First Name] ,a.STRTDATE as [Hire Date] ,a.BENADJDATE as [Adjusted Hire Date] ,a.INACTIVE as [Inactive Employee] ,a.INACTIVE as [Inactive Pay Code] from UPR00100 a join UPR00400 b on a.EMPLOYID = b.EMPLOYID and b.INACTIVE = 0 join UPR40600 c on b.PAYRCORD = c.PAYRCORD where a.INACTIVE = 0 and b.INACTIVE = 0 and c.INACTIVE = 0 and b.BSPAYRCD = '' GO GRANT INSERT, SELECT, DELETE, UPDATE ON [dbo].[SSPositionHistoryLessRecords] TO [DOMAIN\login] AS [dbo] GO
Then we created a view that combines these two views. This is the best view for making decisions, set of data with and without history records.
create view [dbo].[SSPositionHistory] as select EMPLOYID as [Employee ID] ,[Last Name] ,[First Name] ,DATEPART(m,[Hire Date]) as [Hire Month] ,DATEPART(d,[Hire Date]) as [Hire Day] ,DATEPART(yy,[Hire Date]) as [Hire Year] ,DATEPART(m,[Adjusted Hire Date]) as [Re-Hire Month] ,DATEPART(d,[Adjusted Hire Date]) as [Re-Hire Day] ,DATEPART(yy,[Adjusted Hire Date]) as [Re-Hire Year] ,PAYRCORD as [Pay Code] ,DSCRIPTN as [Pay Code Description] ,CHANGEREASON_I as [Reason] ,PAYRTAMT as [Pay Amount] ,DATEPART(m,EFFECTIVEDATE_I) as [Change Month] ,DATEPART(d,EFFECTIVEDATE_I) as [Change Day] ,DATEPART(yy,EFFECTIVEDATE_I) as [Change Year] from SSPositionHistoryRecords union all select EMPLOYID as [Employee ID] ,[Last Name] ,[First Name] ,DATEPART(m,[Hire Date]) as [Hire Month] ,DATEPART(d,[Hire Date]) as [Hire Day] ,DATEPART(yy,[Hire Date]) as [Hire Year] ,DATEPART(m,[Adjusted Hire Date]) as [Re-Hire Month] ,DATEPART(d,[Adjusted Hire Date]) as [Re-Hire Day] ,DATEPART(yy,[Adjusted Hire Date]) as [Re-Hire Year] ,PAYRCORD as [Pay Code] ,DSCRIPTN as [Pay Code Description] ,CHANGEREASON_I as [Reason] ,PAYRTAMT as [Pay Amount] ,DATEPART(m,EFFECTIVEDATE_I) as [Change Month] ,DATEPART(d,EFFECTIVEDATE_I) as [Change Day] ,DATEPART(yy,EFFECTIVEDATE_I) as [Change Year] from SSPositionHistoryLessRecords where EMPLOYID+PAYRCORD not in (select distinct EMPLOYID+PAYRCORD from SSPositionHistoryRecords) GO GRANT INSERT, SELECT, DELETE, UPDATE ON [dbo].[SSPositionHistory] TO [DOMAIN\login] AS [dbo] GO
From there, we created and populated a table that links pay codes to departments.
CREATE TABLE [dbo].[SSIDEPTCODE]( [DEPT] [varchar](6) NOT NULL, [CODE] [varchar](5) NOT NULL ) ON [PRIMARY] GO GRANT INSERT, SELECT, DELETE, UPDATE ON [dbo].[SSIDEPTCODE] TO [DOMAIN\login] AS [dbo] GO
Then we created a set of data-connected workbooks for each department. Department heads then received the report for the employees they supervise. Those managers then placed an X in the spreadsheet to indicate those employees who would receive a raise.
Then we created an application within Dynamics GP that read the employees marked for a raise and create a personnel change request
This update helped streamline raises for hundreds of seasonal employees and reduced the time it took department heads to determine if and when a raise should be awarded. If you’re using Dynamics GP but still completing manual processes, reach out to the team at Stoneridge Software. We can help set up your system to make data reporting user-friendly.
Under the terms of this license, you are authorized to share and redistribute the content across various mediums, subject to adherence to the specified conditions: you must provide proper attribution to Stoneridge as the original creator in a manner that does not imply their endorsement of your use, the material is to be utilized solely for non-commercial purposes, and alterations, modifications, or derivative works based on the original material are strictly prohibited.
Responsibility rests with the licensee to ensure that their use of the material does not violate any other rights.