Skip to content
Open
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
100 changes: 52 additions & 48 deletions PurchasingTP.AzureDb/dbo/Functions/udf_GetOpenOrdersForLogin.sql
Original file line number Diff line number Diff line change
Expand Up @@ -11,10 +11,13 @@
-- Usage:
/*
select * from udf_GetOpenOrdersForLogin('bazemore')

select * from udf_GetOpenOrdersForLogin('rajahn')
*/
-- Modifications:
-- 2014-02-10 by kjt: Revised logic to reduce number of executions, i.e. loop iterations.
-- 2014-02-12 by kjt: Revised logic once again to maximize efficiency.
-- 2017-02-28 by kjt: Revised logic to improve performance.
-- =============================================
CREATE FUNCTION [dbo].[udf_GetOpenOrdersForLogin]
(
Expand All @@ -38,6 +41,7 @@ BEGIN
select ROW_NUMBER() over (order by orderid) id, *
from (
-- regular permissions
SELECT * FROM (
select distinct o.id orderid
, case when ap.userid is null then wp.userid
when ap.userid is not null and ouser.isaway = 1 then wp.userid
Expand All @@ -48,66 +52,65 @@ BEGIN
, 1 Edit, 1 [Read]
from orders o
inner join orderstatuscodes osc on o.orderstatuscodeid = osc.id
and osc.iscomplete = 0
and osc.id not in ('CN', 'CP', 'OC', 'OD')

left outer join approvals ap on o.id = ap.orderid
and ap.Completed = 0
and (
ap.userid in ( select userid from workgrouppermissions where workgroupid = o.workgroupid )
or
ap.userid is null
)
inner join orderstatuscodes aposc on ap.OrderStatusCodeId = aposc.id
left outer join workgrouppermissions wp on o.workgroupid = wp.workgroupid and ap.orderstatuscodeid = wp.roleid
left outer join users ouser on ouser.id = ap.userid
where
case when ap.userid is null then wp.userid
when ap.userid is not null and ouser.isaway = 1 then wp.userid
else ap.userid
end = @LoginId
and ap.Completed = 0
and osc.iscomplete = 0
and aposc.level = osc.Level
and (
and aposc.level = osc.Level
left outer join workgrouppermissions wp on o.workgroupid = wp.workgroupid and ap.orderstatuscodeid = wp.roleid
and (
wp.isadmin = 0
or
(
wp.isadmin = 1 and wp.isfullfeatured = 1
)
)
and (
ap.userid in ( select userid from workgrouppermissions where workgroupid = o.workgroupid )
or
ap.userid is null
)
and o.orderstatuscodeid not in ('CN', 'CP', 'OC', 'OD')
--and osc.id not in ('CN', 'CP', 'OC', 'OD')
)
left outer join users ouser on ouser.id = ap.userid
) t1
WHERE accessuserid = @LoginId
-- Moved remaining portion of where clause segments to individual joins.

union

-- ad hoc permissons
-- ad hoc permissions
select distinct o.id orderid
, ap.userid accessuserid
, 0 isadmin
, ap.orderstatuscodeid accesslevel
, 1 Edit, 1 [Read]
from orders o
inner join orderstatuscodes osc on o.orderstatuscodeid = osc.id
and osc.iscomplete = 0
and osc.id not in ('CN', 'CP', 'OC', 'OD')
left outer join approvals ap on o.id = ap.orderid
and ap.Completed = 0
and ap.userid not in ( select userid from workgrouppermissions where workgroupid = o.workgroupid )
inner join orderstatuscodes aposc on ap.OrderStatusCodeId = aposc.id
and aposc.level = osc.level
where
ap.userid = @LoginId
and ap.Completed = 0
and osc.iscomplete = 0
and aposc.level = osc.level
and ap.userid not in ( select userid from workgrouppermissions where workgroupid = o.workgroupid )
--and o.orderstatuscodeid not in ('CN', 'CP', 'OC', 'OD')
and osc.id not in ('CN', 'CP', 'OC', 'OD')
-- Moved remaining portion of where clause segments to individual joins.

union

-- override, provides admin permissions
select o.id orderid, userid, isadmin, wp.roleid
, 1 Edit, 1 [Read]
from orders o
inner join workgrouppermissions wp on o.workgroupid = wp.workgroupid and o.OrderStatusCodeId = wp.roleid

inner join workgrouppermissions wp on o.workgroupid = wp.workgroupid
and wp.roleId not in ('CN', 'CP', 'OC', 'OD')
and o.OrderStatusCodeId = wp.roleid
and wp.isadmin = 1 and wp.IsFullFeatured = 0
where
userid = @LoginId
and wp.isadmin = 1 and wp.IsFullFeatured = 0
and o.orderstatuscodeid not in ('CN', 'CP', 'OC', 'OD')
-- Moved remaining portion of where clause segments to individual joins.

union

Expand All @@ -116,16 +119,16 @@ BEGIN
, 1 Edit, 1 [Read]
from approvals ap
inner join orders o on ap.OrderId = o.id
inner join OrderStatusCodes aposc on ap.OrderStatusCodeId = aposc.id
inner join OrderStatusCodes oosc on o.orderstatuscodeid = oosc.id
and oosc.id not in ('CN', 'CP', 'OC', 'OD')
inner join OrderStatusCodes aposc on ap.OrderStatusCodeId = aposc.id
and aposc.level = oosc.level
where
ap.SecondaryUserId = @LoginId
and ap.OrderStatusCodeId = 'CA'
and ap.SecondaryUserId is not null
and aposc.level = oosc.level
and ap.Completed = 0
and o.orderstatuscodeid not in ('CN', 'CP', 'OC', 'OD')
--and oosc.id not in ('CN', 'CP', 'OC', 'OD')
and ap.SecondaryUserId is not null
-- Moved remaining portion of where clause segments to individual joins.

union

Expand All @@ -134,28 +137,29 @@ BEGIN
, 1 Edit, 1 [Read]
from approvals ap
inner join orders o on ap.OrderId = o.id
inner join OrderStatusCodes aposc on ap.OrderStatusCodeId = aposc.id
inner join OrderStatusCodes aposc on ap.OrderStatusCodeId = aposc.id
and aposc.id not in ('CN', 'CP', 'OC', 'OD')
inner join OrderStatusCodes oosc on o.orderstatuscodeid = oosc.id
and aposc.level = oosc.level
where
ap.UserId = @LoginId
and ap.OrderStatusCodeId = 'CA'
and aposc.level = oosc.level
and ap.Completed = 0
and o.orderstatuscodeid not in ('CN', 'CP', 'OC', 'OD')
--and oosc.id not in ('CN', 'CP', 'OC', 'OD')

-- Moved remaining portion of where clause segments to individual joins.

union

select orderid, userid accessuserid, 0 [admin], ordertracking.OrderStatusCodeId
, 0 Edit, 1 [Read]
from ordertracking
inner join orders o on ordertracking.orderid = o.id
inner join orders o on ordertracking.orderid = o.id
and o.orderstatuscodeid not in ('CN', 'CP', 'OC', 'OD')
-- This was a redundant join,
--inner join OrderStatusCodes osc on o.orderstatuscodeid = osc.id
where
userid = @LoginId
and o.orderstatuscodeid not in ('CN', 'CP', 'OC', 'OD')
--and osc.id not in ('CN', 'CP', 'OC', 'OD')

-- Moved remaining portion of where clause segments to individual joins.

union

-- reviewer role
Expand All @@ -166,14 +170,14 @@ BEGIN
from workgrouppermissions wp
inner join orders o on o.WorkgroupId = wp.WorkgroupId
inner join workgroups w on wp.workgroupid = w.id and w.IsActive = 1
and wp.roleid = 'RV'
inner join OrderStatusCodes osc on o.orderstatuscodeid = osc.id
and osc.id not in ('CN', 'CP', 'OC', 'OD')
where
wp.userid = @LoginId
and wp.roleid = 'RV'
--and o.orderstatuscodeid not in ('CN', 'CP', 'OC', 'OD')
and osc.id not in ('CN', 'CP', 'OC', 'OD')
-- Moved remaining portion of where clause segments to individual joins.

) vopenaccess
) vopenaccess
where accessuserid is not null

RETURN
Expand Down