diff --git a/PurchasingTP.AzureDb/dbo/Functions/udf_GetEditAccessRecentOrdersForLogin_1.sql b/PurchasingTP.AzureDb/dbo/Functions/udf_GetEditAccessRecentOrdersForLogin_1.sql new file mode 100644 index 000000000..18e760f12 --- /dev/null +++ b/PurchasingTP.AzureDb/dbo/Functions/udf_GetEditAccessRecentOrdersForLogin_1.sql @@ -0,0 +1,131 @@ +-- *CA APPROVALS +-- *Specified as primary user +-- *Specified as secondary user +-- +-- Usage: +/* + select * from udf_GetEditAccessOrdersForLogin('bazemore') +*/ +-- ============================================= +CREATE FUNCTION udf_GetEditAccessRecentOrdersForLogin +( + -- Add the parameters for the function here + @LoginId varchar(50), + @Cutoff datetime +) +RETURNS +@EditAccessOrders TABLE +( + id int, + orderid int, + accessuserid varchar(10), + isadmin bit, + accesslevel char(2) +) +AS +BEGIN + INSERT INTO @EditAccessOrders + select ROW_NUMBER() over (order by orderid) id, * + from ( + -- regular permissions + 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 + else ap.userid + end accessuserid + , 0 isadmin + , ap.orderstatuscodeid accesslevel + from orders o + inner join orderstatuscodes osc on o.orderstatuscodeid = osc.id + left outer join approvals ap on o.id = ap.orderid + 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 o.DateLastAction > @Cutoff + 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 + ) + + union + + -- ad hoc permissons + select distinct o.id orderid + , ap.userid accessuserid + , 0 isadmin + , ap.orderstatuscodeid accesslevel + from orders o + inner join orderstatuscodes osc on o.orderstatuscodeid = osc.id + left outer join approvals ap on o.id = ap.orderid + inner join orderstatuscodes aposc on ap.OrderStatusCodeId = aposc.id + 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.DateLastAction > @Cutoff + + union + + -- override, provides admin permissions + select o.id orderid, userid, isadmin, wp.roleid + from orders o + inner join workgrouppermissions wp on o.workgroupid = wp.workgroupid and o.OrderStatusCodeId = wp.roleid + where + wp.userid = @LoginId + and wp.isadmin = 1 + and wp.IsFullFeatured = 0 + and o.DateLastAction > @Cutoff + + union + + -- secondary Conditional Approval + select ap.OrderId, ap.SecondaryUserId accessuserid, cast(0 as bit) isadmin, ap.OrderStatusCodeId + 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 + 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.DateLastAction > @Cutoff + + union + + -- Primary Conditional Approval + select ap.OrderId, ap.UserId accessuserid, cast(0 as bit) isadmin, ap.OrderStatusCodeId + 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 + where + ap.UserId = @LoginId + and ap.OrderStatusCodeId = 'CA' + and aposc.level = oosc.level + and ap.Completed = 0 + and o.DateLastAction > @Cutoff + ) veditaccess + where accessuserid is not null + + RETURN +END \ No newline at end of file diff --git a/PurchasingTP.AzureDb/dbo/Functions/udf_GetOpenOrdersForLogin_New_1.sql b/PurchasingTP.AzureDb/dbo/Functions/udf_GetOpenOrdersForLogin_New_1.sql new file mode 100644 index 000000000..0952ef9cc --- /dev/null +++ b/PurchasingTP.AzureDb/dbo/Functions/udf_GetOpenOrdersForLogin_New_1.sql @@ -0,0 +1,182 @@ +-- ============================================= +-- Author: Ken Taylor +-- Create date: February 5, 2014 +-- Description: Given a Kerberos/LoginId, Return a list of open orders that the user has access to. +-- Notes: +-- Replaces vOpenAccess. +-- Permissions access for open orders only. Orders that are not in the following status codes: ('CN', 'CP', 'OC', 'OD') +-- +-- 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_New] +( + -- Add the parameters for the function here + @LoginId varchar(50) +) +RETURNS +@OpenAccessOrders TABLE +( + id int, + orderid int, + accessuserid varchar(10), + isadmin bit, + accesslevel char(2), + Edit bit, + [Read] bit +) +AS +BEGIN + INSERT INTO @OpenAccessOrders + 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 + else ap.userid + end 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 in ( select userid from workgrouppermissions where workgroupid = o.workgroupid ) + or + ap.userid is null + ) + inner join orderstatuscodes aposc on ap.OrderStatusCodeId = aposc.id + 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 + ) + ) + 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 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 + -- 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 wp.roleId not in ('CN', 'CP', 'OC', 'OD') + and o.OrderStatusCodeId = wp.roleid + and wp.isadmin = 1 and wp.IsFullFeatured = 0 + where + userid = @LoginId + -- Moved remaining portion of where clause segments to individual joins. + + union + + -- secondary Conditional Approval + select ap.OrderId, ap.SecondaryUserId accessuserid, cast(0 as bit) isadmin, ap.OrderStatusCodeId + , 1 Edit, 1 [Read] + from approvals ap + inner join orders o on ap.OrderId = o.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.Completed = 0 + and ap.SecondaryUserId is not null + -- Moved remaining portion of where clause segments to individual joins. + + union + + -- Primary Conditional Approval + select ap.OrderId, ap.UserId accessuserid, cast(0 as bit) isadmin, ap.OrderStatusCodeId + , 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 + 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 ap.Completed = 0 + -- 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 + 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 + -- Moved remaining portion of where clause segments to individual joins. + + union + + -- reviewer role + select o.id orderid, wp.userid accessuserid + , cast (case when wp.isadmin = 1 and wp.isfullfeatured = 0 then 1 else 0 end as bit) [admin] + , wp.RoleId orderstatuscodeid + , 0 Edit, 1 [Read] + 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 + -- Moved remaining portion of where clause segments to individual joins. + + ) vopenaccess + where accessuserid is not null + + RETURN +END \ No newline at end of file diff --git a/PurchasingTP.AzureDb/dbo/Functions/udf_GetOpenOrdersForLogin_Old_1.sql b/PurchasingTP.AzureDb/dbo/Functions/udf_GetOpenOrdersForLogin_Old_1.sql new file mode 100644 index 000000000..6cc6a3afd --- /dev/null +++ b/PurchasingTP.AzureDb/dbo/Functions/udf_GetOpenOrdersForLogin_Old_1.sql @@ -0,0 +1,178 @@ +-- ============================================= +-- Author: Ken Taylor +-- Create date: February 5, 2014 +-- Description: Given a Kerberos/LoginId, Return a list of open orders that the user has access to. +-- Notes: +-- Replaces vOpenAccess. +-- Permissions access for open orders only. Orders that are not in the following status codes: ('CN', 'CP', 'OC', 'OD') +-- +-- Usage: +/* + select * from udf_GetOpenOrdersForLogin('bazemore') +*/ +-- 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. +-- ============================================= +CREATE FUNCTION [dbo].[udf_GetOpenOrdersForLogin_Old] + ( + -- Add the parameters for the function here + @LoginId varchar(50) + ) + RETURNS + @OpenAccessOrders TABLE + ( + id int, + orderid int, + accessuserid varchar(10), + isadmin bit, + accesslevel char(2), + Edit bit, + [Read] bit + ) +AS + BEGIN + INSERT INTO @OpenAccessOrders + select ROW_NUMBER() over (order by orderid) id, * + from ( + -- regular permissions + 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 + else ap.userid + end accessuserid, + 0 isadmin, + ap.orderstatuscodeid accesslevel, + 1 Edit, + 1 [Read] + from orders o + inner join orderstatuscodes osc on o.orderstatuscodeid = osc.id + left outer join approvals ap on o.id = ap.orderid + 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 ( + 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') + + union + + -- ad hoc permissons + 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 + left outer join approvals ap on o.id = ap.orderid + inner join orderstatuscodes aposc on ap.OrderStatusCodeId = aposc.id + 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') + + 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 + + where userid = @LoginId + and wp.isadmin = 1 + and wp.IsFullFeatured = 0 + and o.orderstatuscodeid not in ('CN', 'CP', 'OC', 'OD') + + union + + -- secondary Conditional Approval + select ap.OrderId, + ap.SecondaryUserId accessuserid, + cast(0 as bit) isadmin, + ap.OrderStatusCodeId, + 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 + 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') + + union + + -- Primary Conditional Approval + select ap.OrderId, ap.UserId accessuserid, cast(0 as bit) isadmin, ap.OrderStatusCodeId, 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 + 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') + + 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 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') + + union + + -- reviewer role + select o.id orderid, + wp.userid accessuserid, + cast(case when wp.isadmin = 1 and wp.isfullfeatured = 0 then 1 else 0 end as bit) [admin], + wp.RoleId orderstatuscodeid, + 0 Edit, + 1 [Read] + 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 + inner join OrderStatusCodes osc on o.orderstatuscodeid = osc.id + 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')) vopenaccess + where accessuserid is not null + + RETURN + END \ No newline at end of file diff --git a/PurchasingTP.AzureDb/dbo/Functions/udf_GetOrderInformationForUnex_1.sql b/PurchasingTP.AzureDb/dbo/Functions/udf_GetOrderInformationForUnex_1.sql new file mode 100644 index 000000000..6413f0fc7 --- /dev/null +++ b/PurchasingTP.AzureDb/dbo/Functions/udf_GetOrderInformationForUnex_1.sql @@ -0,0 +1,27 @@ +-- ============================================= +-- Author: Scott Kirkland +-- Create date: 3/21/2017 +-- Description: Downloads all order information for UNEX workgroups (under 3-UNEX org) for the last 2 years +-- ============================================= +CREATE FUNCTION [dbo].[udf_GetOrderInformationForUnex] +( +) + +RETURNS TABLE +AS +RETURN +( + select * from vorderhistory orders + where workgroupid in ( + select distinct workgroupid from vorganizationdescendants od + inner join workgroupsxorganizations wo on od.orgid = wo.organizationid + inner join workgroups w on wo.workgroupid = w.id + where od.rollupparentid = '3-UNEX' and od.isactive = 1 and w.isActive = 1 + ) + and datecreated > (getdate() - 730) and requesttype = 'Other' +) +GO +GRANT SELECT + ON OBJECT::[dbo].[udf_GetOrderInformationForUnex] TO [unex] + AS [dbo]; + diff --git a/PurchasingTP.AzureDb/dbo/Functions/udf_GetReadAccessRecentOrdersForLogin_1.sql b/PurchasingTP.AzureDb/dbo/Functions/udf_GetReadAccessRecentOrdersForLogin_1.sql new file mode 100644 index 000000000..881a9a984 --- /dev/null +++ b/PurchasingTP.AzureDb/dbo/Functions/udf_GetReadAccessRecentOrdersForLogin_1.sql @@ -0,0 +1,55 @@ +-- ============================================= +-- Author: Scott Kirkland +-- Create date: January 8 2021 +-- Description: Given a Kerberos/LoginId Return a list of orders that the user has read access to that were acted on since the given cutoff +-- Notes: +-- Replaces vReadAccess. +-- Determines read access based on order tracking or reviewer role, regardless of order status. +-- Usage: +/* + select * from udf_GetReadAccessRecentOrdersForLogin('kdani') +*/ +-- ============================================= +CREATE FUNCTION udf_GetReadAccessRecentOrdersForLogin +( + -- Add the parameters for the function here + @LoginId varchar(50), + @Cutoff datetime +) +RETURNS +@ReadAccessOrders TABLE +( + -- Add the column definitions for the TABLE variable here + orderid int, + accessuserid varchar(10), + isadmin bit, + accesslevel char(2) +) +AS +BEGIN + INSERT INTO @ReadAccessOrders + select access.orderid, access.UserId accessuserid, [admin] isadmin, OrderStatusCodeId accesslevel + from + ( + -- acted on order + select orderid, userid, OrderTracking.OrderStatusCodeId, 0 [admin] + from ordertracking + inner join orders on Orders.Id = OrderTracking.OrderId + where userid = @LoginId and Orders.DateLastAction > @Cutoff + + union + + -- reviewer role + select o.id orderid, wp.userid, wp.RoleId + , cast (case when wp.isadmin = 1 and wp.isfullfeatured = 0 then 1 else 0 end as bit) [admin] + 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 + where + wp.userid = @LoginId + and wp.roleid = 'RV' + and o.DateLastAction > @Cutoff +) access + + RETURN +END \ No newline at end of file diff --git a/PurchasingTP.AzureDb/dbo/Functions/udf_GetReadAndEditAccessRecentOrdersForLogin.sql b/PurchasingTP.AzureDb/dbo/Functions/udf_GetReadAndEditAccessRecentOrdersForLogin.sql new file mode 100644 index 000000000..9ddf75bab --- /dev/null +++ b/PurchasingTP.AzureDb/dbo/Functions/udf_GetReadAndEditAccessRecentOrdersForLogin.sql @@ -0,0 +1,47 @@ +-- ============================================= +-- Author: Scott Kirkland +-- Create date: January 12, 2021 +-- Description: Given a Kerberos/LoginId, Return a list of orders that the user has read access and edit access to and have been modified recently +-- Notes: +-- Replaces vAccess. +-- Determines access on any order (regardless of status). Uses udf_GetEditAccessRecentOrdersForLogin(@LoginId) and +-- udf_GetReadAccessRecentOrdersForLogin(@LoginId) user defined functions. +-- Usage: +/* + select * from udf_GetReadAndEditAccessRecentOrdersForLogin('bazemore', '1/1/2020') +*/ +-- ============================================= +CREATE FUNCTION udf_GetReadAndEditAccessRecentOrdersForLogin +( + -- Add the parameters for the function here + @LoginId varchar(50), + @Cutoff datetime +) +RETURNS +@ReadAndEditAccessOrders TABLE +( + id int, + orderid int, + accessuserid varchar(10), + readaccess bit, + editaccess bit, + isadmin bit, + accesslevel char(2) +) +AS +BEGIN + INSERT INTO @ReadAndEditAccessOrders + select ROW_NUMBER() over (order by orderid) id, access.orderid, access.accessuserid, cast(access.readaccess as bit) readaccess, cast(access.editaccess as bit) editaccess, access.isadmin, accesslevel +from + ( + select orderid, accessuserid, 1 readaccess, 1 editaccess, isadmin, accesslevel + from udf_GetEditAccessRecentOrdersForLogin(@LoginId, @Cutoff) + + union + + select orderid, accessuserid, 1 readaccess, 0 editaccess, isadmin, accesslevel + from udf_GetReadAccessRecentOrdersForLogin(@LoginId, @Cutoff) + ) access + + RETURN +END \ No newline at end of file diff --git a/PurchasingTP.AzureDb/dbo/Tables/ColumnPreferences.sql b/PurchasingTP.AzureDb/dbo/Tables/ColumnPreferences.sql index 7e4055231..7db42a43f 100644 --- a/PurchasingTP.AzureDb/dbo/Tables/ColumnPreferences.sql +++ b/PurchasingTP.AzureDb/dbo/Tables/ColumnPreferences.sql @@ -45,9 +45,13 @@ + + GO CREATE NONCLUSTERED INDEX [ColumnPreferences_UserId_IDX] - ON [dbo].[ColumnPreferences]([Id] ASC) WITH (STATISTICS_NORECOMPUTE = ON); + ON [dbo].[ColumnPreferences]([Id] ASC); + + diff --git a/PurchasingTP.AzureDb/dbo/Tables/ConditionalApproval.sql b/PurchasingTP.AzureDb/dbo/Tables/ConditionalApproval.sql index d64b129e8..98718181d 100644 --- a/PurchasingTP.AzureDb/dbo/Tables/ConditionalApproval.sql +++ b/PurchasingTP.AzureDb/dbo/Tables/ConditionalApproval.sql @@ -14,6 +14,8 @@ + + GO CREATE NONCLUSTERED INDEX [HistoryReceivedLineItems_UserID_IDX] ON [dbo].[ConditionalApproval]([PrimaryApproverId] ASC); @@ -21,14 +23,18 @@ CREATE NONCLUSTERED INDEX [HistoryReceivedLineItems_UserID_IDX] GO CREATE NONCLUSTERED INDEX [ConditionalApproval_WorkgroupId_IDX] - ON [dbo].[ConditionalApproval]([WorkgroupId] ASC) WITH (STATISTICS_NORECOMPUTE = ON); + ON [dbo].[ConditionalApproval]([WorkgroupId] ASC); + + GO CREATE NONCLUSTERED INDEX [ConditionalApproval_SecondaryApproverId_IDX] - ON [dbo].[ConditionalApproval]([SecondaryApproverId] ASC) WITH (STATISTICS_NORECOMPUTE = ON); + ON [dbo].[ConditionalApproval]([SecondaryApproverId] ASC); + + diff --git a/PurchasingTP.AzureDb/dbo/Tables/ControlledSubstanceInformation.sql b/PurchasingTP.AzureDb/dbo/Tables/ControlledSubstanceInformation.sql index 779cb098b..c155651f0 100644 --- a/PurchasingTP.AzureDb/dbo/Tables/ControlledSubstanceInformation.sql +++ b/PurchasingTP.AzureDb/dbo/Tables/ControlledSubstanceInformation.sql @@ -7,7 +7,7 @@ [EndUser] VARCHAR (200) NOT NULL, [OrderId] INT NOT NULL, [PharmaceuticalGrade] BIT DEFAULT ((0)) NOT NULL, - PRIMARY KEY CLUSTERED ([Id] ASC) WITH (STATISTICS_NORECOMPUTE = ON), + PRIMARY KEY CLUSTERED ([Id] ASC), CONSTRAINT [FK_AuthorizationNumbers_Orders] FOREIGN KEY ([OrderId]) REFERENCES [dbo].[Orders] ([Id]) ); @@ -17,6 +17,8 @@ + + GO CREATE NONCLUSTERED INDEX [ControlledSubstanceInformation_OrderId_IDX] ON [dbo].[ControlledSubstanceInformation]([OrderId] ASC); diff --git a/PurchasingTP.AzureDb/dbo/Tables/OrderRequestSaves.sql b/PurchasingTP.AzureDb/dbo/Tables/OrderRequestSaves.sql index 194bc81ba..e697bb151 100644 --- a/PurchasingTP.AzureDb/dbo/Tables/OrderRequestSaves.sql +++ b/PurchasingTP.AzureDb/dbo/Tables/OrderRequestSaves.sql @@ -17,6 +17,8 @@ + + GO CREATE NONCLUSTERED INDEX [OrderRequestSaves_PreparedById_IDX] ON [dbo].[OrderRequestSaves]([PreparedById] ASC); @@ -24,7 +26,9 @@ CREATE NONCLUSTERED INDEX [OrderRequestSaves_PreparedById_IDX] GO CREATE NONCLUSTERED INDEX [OrderRequestSaves_UserId_IDX] - ON [dbo].[OrderRequestSaves]([UserId] ASC) WITH (STATISTICS_NORECOMPUTE = ON); + ON [dbo].[OrderRequestSaves]([UserId] ASC); + + diff --git a/PurchasingTP.AzureDb/dbo/Tables/OrderTracking.sql b/PurchasingTP.AzureDb/dbo/Tables/OrderTracking.sql index 23d5b4e04..76be9b3e9 100644 --- a/PurchasingTP.AzureDb/dbo/Tables/OrderTracking.sql +++ b/PurchasingTP.AzureDb/dbo/Tables/OrderTracking.sql @@ -5,7 +5,7 @@ [DateCreated] DATETIME2 (7) CONSTRAINT [DF__OrderTrac__DateC__3E52440B] DEFAULT (getdate()) NOT NULL, [UserId] VARCHAR (10) NOT NULL, [OrderStatusCodeId] CHAR (2) NOT NULL, - PRIMARY KEY CLUSTERED ([Id] ASC) WITH (STATISTICS_NORECOMPUTE = ON), + PRIMARY KEY CLUSTERED ([Id] ASC), CONSTRAINT [FK_OrderTracking_Orders] FOREIGN KEY ([OrderId]) REFERENCES [dbo].[Orders] ([Id]), CONSTRAINT [FK_OrderTracking_OrderStatusCodes] FOREIGN KEY ([OrderStatusCodeId]) REFERENCES [dbo].[OrderStatusCodes] ([Id]), CONSTRAINT [FK_OrderTracking_Users] FOREIGN KEY ([UserId]) REFERENCES [dbo].[Users] ([Id]) @@ -20,6 +20,8 @@ + + GO CREATE NONCLUSTERED INDEX [OrderTracking_UserId_IDX] ON [dbo].[OrderTracking]([UserId] ASC) WITH (STATISTICS_NORECOMPUTE = ON); diff --git a/PurchasingTP.AzureDb/dbo/Tables/Orders.sql b/PurchasingTP.AzureDb/dbo/Tables/Orders.sql index f871cecd4..1f702a894 100644 --- a/PurchasingTP.AzureDb/dbo/Tables/Orders.sql +++ b/PurchasingTP.AzureDb/dbo/Tables/Orders.sql @@ -1,4 +1,4 @@ -CREATE TABLE [dbo].[Orders] ( +CREATE TABLE [dbo].[Orders] ( [Id] INT IDENTITY (1, 1) NOT NULL, [OrderTypeId] CHAR (3) NOT NULL, [WorkgroupVendorId] INT NULL, @@ -59,6 +59,8 @@ + + GO CREATE NONCLUSTERED INDEX [Orders_WorkgroupVendorId_IDX] ON [dbo].[Orders]([WorkgroupVendorId] ASC) WITH (STATISTICS_NORECOMPUTE = ON); @@ -124,5 +126,7 @@ CREATE NONCLUSTERED INDEX [Orders_OrderStatusCodeId_Incl_IdWorkgroupId_CVIDX] GO - +CREATE NONCLUSTERED INDEX [Orders_StatusCode_DateLastAction_IDX] + ON [dbo].[Orders]([OrderStatusCodeId] ASC, [DateLastAction] ASC) + INCLUDE([WorkgroupId]); diff --git a/PurchasingTP.AzureDb/dbo/Tables/UsersXOrganizations.sql b/PurchasingTP.AzureDb/dbo/Tables/UsersXOrganizations.sql index 3f0e40f53..791abfabc 100644 --- a/PurchasingTP.AzureDb/dbo/Tables/UsersXOrganizations.sql +++ b/PurchasingTP.AzureDb/dbo/Tables/UsersXOrganizations.sql @@ -1,7 +1,7 @@ CREATE TABLE [dbo].[UsersXOrganizations] ( [UserId] VARCHAR (10) NOT NULL, [OrganizationId] VARCHAR (10) NOT NULL, - PRIMARY KEY CLUSTERED ([UserId] ASC, [OrganizationId] ASC) WITH (STATISTICS_NORECOMPUTE = ON) + PRIMARY KEY CLUSTERED ([UserId] ASC, [OrganizationId] ASC) ); @@ -10,9 +10,13 @@ + + GO CREATE NONCLUSTERED INDEX [UsersXOrganizations_UserId_IDX] - ON [dbo].[UsersXOrganizations]([UserId] ASC) WITH (STATISTICS_NORECOMPUTE = ON); + ON [dbo].[UsersXOrganizations]([UserId] ASC); + + diff --git a/PurchasingTP.AzureDb/dbo/Tables/Workgroups.sql b/PurchasingTP.AzureDb/dbo/Tables/Workgroups.sql index ada506fd6..045edb3a7 100644 --- a/PurchasingTP.AzureDb/dbo/Tables/Workgroups.sql +++ b/PurchasingTP.AzureDb/dbo/Tables/Workgroups.sql @@ -21,6 +21,8 @@ + + GO CREATE NONCLUSTERED INDEX [Workgroups_SharedOrCluster_IDX] ON [dbo].[Workgroups]([IsFullFeatured] ASC); @@ -33,7 +35,9 @@ CREATE NONCLUSTERED INDEX [Workgroups_IsActive_IDX] GO CREATE NONCLUSTERED INDEX [Workgroups_Administrative_IDX] - ON [dbo].[Workgroups]([Administrative] ASC) WITH (STATISTICS_NORECOMPUTE = ON); + ON [dbo].[Workgroups]([Administrative] ASC); + + diff --git a/PurchasingTP.AzureDb/dbo/Tables/vBuildings.sql b/PurchasingTP.AzureDb/dbo/Tables/vBuildings.sql index f566bb945..d2a46b2fc 100644 --- a/PurchasingTP.AzureDb/dbo/Tables/vBuildings.sql +++ b/PurchasingTP.AzureDb/dbo/Tables/vBuildings.sql @@ -10,8 +10,10 @@ [IsActive] BIT NULL, [UpdateHash] VARBINARY (16) NULL, CONSTRAINT [PK_vBuildings2] PRIMARY KEY CLUSTERED ([CampusCode] ASC, [BuildingCode] ASC), - CONSTRAINT [vBuildings2_Id_UDX] UNIQUE NONCLUSTERED ([Id] ASC) WITH (STATISTICS_NORECOMPUTE = ON) + CONSTRAINT [vBuildings2_Id_UDX] UNIQUE NONCLUSTERED ([Id] ASC) ); + +