USP_SYSTEMROLE_UPDATEFROMKPILIST
Updates KPI permissions for a given system role ID, xml for items updated, and xml for items deleted.
Parameters
Parameter | Parameter Type | Mode | Description |
---|---|---|---|
@ID | uniqueidentifier | IN | |
@CHANGEAGENTID | uniqueidentifier | IN | |
@CHANGEDATE | datetime | IN | |
@KPILIST | xml | IN | |
@KPILIST_DELETED | xml | IN |
Definition
Copy
create procedure dbo.USP_SYSTEMROLE_UPDATEFROMKPILIST
(
@ID uniqueidentifier,
@CHANGEAGENTID uniqueidentifier,
@CHANGEDATE datetime,
@KPILIST xml = null,
@KPILIST_DELETED xml = null
)
as
begin
if @CHANGEAGENTID is null
exec dbo.USP_CHANGEAGENT_GETORCREATECHANGEAGENT @CHANGEAGENTID output;
if @CHANGEDATE is null
set @CHANGEDATE = getdate();
if @KPILIST is not null
begin
declare @KPITABLE table
(
ID uniqueidentifier,
KPICATALOGID uniqueidentifier,
GRANTORDENY bit
)
insert into @KPITABLE
select
T.c.value('(ID)[1]','uniqueidentifier') AS 'ID',
T.c.value('(KPICATALOGID)[1]','uniqueidentifier') AS 'KPICATALOGID',
T.c.value('(GRANTORDENY)[1]','bit') AS 'GRANTORDENY'
from @KPILIST.nodes('/KPILIST/ITEM') T(c)
insert into dbo.SYSTEMROLEPERM_KPI
(
SYSTEMROLEID,
GRANTORDENY,
ID,
KPICATALOGID,
ADDEDBYID,
CHANGEDBYID,
DATEADDED,
DATECHANGED
)
select
@ID,
GRANTORDENY,
ID,
KPICATALOGID,
@CHANGEAGENTID,
@CHANGEAGENTID,
@CHANGEDATE,
@CHANGEDATE
from @KPITABLE as [temp]
where
not exists
(
select ID from dbo.SYSTEMROLEPERM_KPI as data
where data.ID = [temp].ID
)
update dbo.[SYSTEMROLEPERM_KPI] set
[SYSTEMROLEPERM_KPI].GRANTORDENY = temp.GRANTORDENY,
[SYSTEMROLEPERM_KPI].CHANGEDBYID = @CHANGEAGENTID,
[SYSTEMROLEPERM_KPI].DATECHANGED = @CHANGEDATE
from @KPITABLE as [temp]
where
[SYSTEMROLEPERM_KPI].ID = [temp].ID and
[SYSTEMROLEPERM_KPI].KPICATALOGID = [temp].KPICATALOGID and
[SYSTEMROLEPERM_KPI].GRANTORDENY <> [temp].GRANTORDENY
end
if @KPILIST_DELETED is not null
begin
declare @KPITABLE_DELETED table
(
ID uniqueidentifier
)
insert into @KPITABLE_DELETED
select
T.c.value('(ID)[1]','uniqueidentifier') AS 'ID'
from @KPILIST_DELETED.nodes('/KPILIST_DELETED/ITEM') T(c)
delete from dbo.[SYSTEMROLEPERM_KPI]
where
[SYSTEMROLEPERM_KPI].ID in
(
select ID from @KPITABLE_DELETED
)
end
end