You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

257 lines
6.6 KiB

1 year ago
  1. USE [FastMoneyPro_Remit]
  2. GO
  3. /****** Object: StoredProcedure [dbo].[proc_applicationRoles] Script Date: 7/4/2019 11:35:48 AM ******/
  4. DROP PROCEDURE [dbo].[proc_applicationRoles]
  5. GO
  6. /****** Object: StoredProcedure [dbo].[proc_applicationRoles] Script Date: 7/4/2019 11:35:48 AM ******/
  7. SET ANSI_NULLS ON
  8. GO
  9. SET QUOTED_IDENTIFIER ON
  10. GO
  11. /*
  12. Invalid object name 'applicationRqoleFunctions'.
  13. proc_applicationRoles 's', 'user1', 0, 'a'
  14. exec [proc_applicationRoles] @flag = 's' ,@pageNumber='1', @pageSize='10', @sortBy='roleId',
  15. @sortOrder='ASC', @user = ''
  16. */
  17. CREATE proc [dbo].[proc_applicationRoles]
  18. @flag CHAR(1)
  19. ,@userName VARCHAR(30) = NULL
  20. ,@user VARCHAR(30) = NULL
  21. ,@roleId INT = NULL
  22. ,@roleName VARCHAR(50) = NULL
  23. ,@roleType VARCHAR(1) = NULL
  24. ,@isActive VARCHAR(1) = NULL
  25. ,@haschanged CHAR(1) = NULL
  26. ,@createdBy VARCHAR(50) = NULL
  27. ,@modifiedBy VARCHAR(50) = NULL
  28. ,@sortBy VARCHAR(50) = NULL
  29. ,@sortOrder VARCHAR(5) = NULL
  30. ,@pageSize INT = NULL
  31. ,@pageNumber INT = NULL
  32. AS
  33. /*
  34. @flag
  35. s = select all (with dynamic filters)
  36. i = insert
  37. u = update
  38. a = select by role id
  39. d = delete by role id
  40. */
  41. SET NOCOUNT ON
  42. BEGIN TRY
  43. DECLARE
  44. @sql VARCHAR(MAX)
  45. ,@oldValue VARCHAR(MAX)
  46. ,@newValue VARCHAR(MAX)
  47. CREATE TABLE #msg(errorCode INT, msg VARCHAR(100), id INT)
  48. IF @flag = 's'
  49. BEGIN
  50. DECLARE
  51. @selectFieldList VARCHAR(MAX)
  52. ,@extraFieldList VARCHAR(MAX)
  53. ,@table VARCHAR(MAX)
  54. ,@sqlFilter VARCHAR(MAX)
  55. --IF @sortBy IS NULL
  56. SET @sortBy = 'roleName'
  57. SET @table = '(
  58. SELECT
  59. ar.roleId
  60. ,ar.roleName
  61. ,roleType = CASE WHEN ar.roleType = ''H'' THEN ''HO/Admin''
  62. WHEN ar.roleType = ''A'' THEN ''Agent'' END
  63. ,ar.isActive
  64. ,ar.createdBy
  65. ,ar.createdDate
  66. ,modifiedBy = ISNULL(x.createdBy, ar.modifiedBy)
  67. ,modifiedDate = ISNULL(x.createdDate, ar.modifiedDate)
  68. ,hasChanged = CASE WHEN (x.roleId IS NOT NULL) THEN ''Y'' ELSE ''N'' END
  69. FROM applicationRoles ar WITH(NOLOCK)
  70. LEFT JOIN (
  71. SELECT --DISTINCT
  72. roleId
  73. ,createdBy = MAX(createdBy)
  74. ,createdDate = MAX(createdDate)
  75. FROM applicationRoleFunctionsMod arfm WITH(NOLOCK)
  76. GROUP BY roleId
  77. ) x ON ar.roleId = x.roleId
  78. ) x'
  79. SET @sqlFilter = ''
  80. SET @selectFieldList = '
  81. roleId, roleName, roleType, isActive,hasChanged, createdDate
  82. ,createdBy, modifiedDate, modifiedBy
  83. '
  84. IF @roleName IS NOT NULL
  85. SET @sqlFilter = @sqlFilter + ' AND roleName LIKE ''' + @roleName + '%'''
  86. IF @roleType IS NOT NULL
  87. SET @sqlFilter = @sqlFilter + ' AND roleType like ''' + @roleType + '%'''
  88. IF @createdBy IS NOT NULL
  89. SET @sqlFilter = @sqlFilter + ' AND createdBy LIKE ''' + @createdBy + '%'''
  90. IF @modifiedBy IS NOT NULL
  91. SET @sqlFilter = @sqlFilter + ' AND modifiedBy LIKE ''' + @modifiedBy + '%'''
  92. IF @haschanged IS NOT NULL
  93. SET @sqlFilter = @sqlFilter + ' AND haschanged = ''' + @haschanged + ''''
  94. EXEC dbo.proc_paging
  95. @table
  96. ,@sqlFilter
  97. ,@selectFieldList
  98. ,@extraFieldList
  99. ,@sortBy
  100. ,@sortOrder
  101. ,@pageSize
  102. ,@pageNumber
  103. END
  104. ELSE IF @flag = 'a'
  105. BEGIN
  106. SELECT
  107. roleId, roleName, roleType
  108. ,createdDate, createdBy, modifiedDate, modifiedBy, isActive
  109. FROM applicationRoles WITH (NOLOCK)
  110. WHERE roleId = @roleId
  111. END
  112. ELSE IF @flag = 'd'
  113. BEGIN
  114. IF EXISTS (SELECT 'X' FROM applicationRoleFunctions WITH(NOLOCK) WHERE roleId = @roleId)
  115. BEGIN
  116. SELECT 1 errorCode, 'This Role is in use.' mes, @roleId id
  117. RETURN
  118. END
  119. BEGIN TRANSACTION
  120. --------Audit data starts----------------
  121. SET @newValue = ''
  122. EXEC [dbo].proc_GetColumnToRow 'applicationRoles', 'roleId', @roleId, @oldValue OUTPUT
  123. INSERT INTO #msg(errorCode, msg, id)
  124. EXEC proc_applicationLogs 'i', NULL, 'Delete', 'Role Setup', @roleId, @user, @oldValue, @newValue
  125. IF EXISTS (SELECT 'X' FROM #msg WHERE errorCode <> 0 )
  126. BEGIN
  127. IF @@TRANCOUNT > 0
  128. ROLLBACK TRANSACTION
  129. SELECT 1 errorCode, 'Role can not be deleted.' mes, @roleId id
  130. RETURN
  131. END
  132. --------------Audit data ends-------------
  133. DELETE FROM applicationRoles WHERE roleId = @roleId
  134. COMMIT TRANSACTION
  135. SELECT 0 errorCode, 'Role successfully deleted.' mes, @roleId paramKey
  136. END
  137. ELSE IF @flag = 'i'
  138. BEGIN
  139. IF EXISTS(SELECT 'X' FROM applicationRoles WHERE roleName = @roleName)
  140. BEGIN
  141. SELECT 1 errorCode, 'Role Name already exists.' mes, NULL paramKey
  142. RETURN
  143. END
  144. BEGIN TRANSACTION
  145. INSERT INTO applicationRoles(
  146. roleName
  147. ,roleType
  148. ,createdDate
  149. ,createdBy
  150. ,isActive
  151. )
  152. SELECT
  153. @roleName
  154. ,@roleType
  155. ,GETDATE()
  156. ,@user
  157. ,@isActive
  158. SET @roleId = SCOPE_IDENTITY()
  159. --Audit data starts
  160. SET @oldValue = ''
  161. EXEC [dbo].proc_GetColumnToRow 'applicationRoles', 'roleId', @roleId, @newValue OUTPUT
  162. --Audit data ends
  163. INSERT INTO #msg(errorCode, msg, id)
  164. EXEC proc_applicationLogs 'i', NULL, 'Insert', 'Role Setup', @roleId, @user, @oldValue, @newValue
  165. IF EXISTS (SELECT 'X' FROM #msg WHERE errorCode <> 0 )
  166. BEGIN
  167. IF @@TRANCOUNT > 0
  168. ROLLBACK TRANSACTION
  169. SELECT 1 errorCode, 'Role can not be added.' mes, @roleId id
  170. RETURN
  171. END
  172. COMMIT TRANSACTION
  173. SELECT 0 errorCode, 'New role has been added successfully.' mes, @roleId paramKey
  174. END
  175. ELSE IF @flag = 'u'
  176. BEGIN
  177. IF EXISTS(SELECT 'X' FROM applicationRoles WHERE roleName = @roleName AND roleId <> @roleId)
  178. BEGIN
  179. SELECT 1 errorCode, 'Role Name already exists.' mes, NULL paramKey
  180. RETURN
  181. END
  182. BEGIN TRANSACTION
  183. --Audit data starts
  184. EXEC [dbo].proc_GetColumnToRow 'applicationRoles', 'roleId', @roleId, @oldValue OUTPUT
  185. --Audit data ends
  186. UPDATE applicationRoles SET
  187. roleName = @roleName
  188. ,roleType=@roleType
  189. ,modifiedDate = GETDATE()
  190. ,modifiedBy = @user
  191. WHERE roleId = @roleId
  192. --Audit data starts
  193. EXEC [dbo].proc_GetColumnToRow 'applicationRoles', 'roleId', @roleId, @newValue OUTPUT
  194. --Audit data ends
  195. INSERT INTO #msg(errorCode, msg, id)
  196. EXEC proc_applicationLogs 'i', NULL, 'Update', 'Role Setup', @roleId, @user, @oldValue, @newValue
  197. IF EXISTS (SELECT 'X' FROM #msg WHERE errorCode <> 0 )
  198. BEGIN
  199. IF @@TRANCOUNT > 0
  200. ROLLBACK TRANSACTION
  201. SELECT 1 errorCode, 'Role can not be added.' mes, @roleId id
  202. RETURN
  203. END
  204. COMMIT TRANSACTION
  205. SELECT 0 errorCode, 'Role has been updated successfully.' mes, @roleId paramKey
  206. END
  207. END TRY
  208. BEGIN CATCH
  209. IF @@TRANCOUNT > 0
  210. ROLLBACK TRANSACTION
  211. SELECT 1 errorCode, ERROR_MESSAGE() mes, @roleId paramKey
  212. END CATCH
  213. GO