From d3888e3c3266a03daed20a7032a04faa37cdf698 Mon Sep 17 00:00:00 2001 From: Paul Larsen Date: Tue, 29 Jul 2025 09:20:58 -0400 Subject: [PATCH] C2025-027-AnnotationsTypeSelect --- .../DlgAnnotationsSelect.cs | 22 ++-- PROMS/VEPROMS User Interface/PROMSFixes.Sql | 103 +++++++++--------- .../Minimal/AnnotationstypeSections.cs | 51 ++------- 3 files changed, 69 insertions(+), 107 deletions(-) diff --git a/PROMS/VEPROMS User Interface/DlgAnnotationsSelect.cs b/PROMS/VEPROMS User Interface/DlgAnnotationsSelect.cs index a13fa677..1786e97c 100644 --- a/PROMS/VEPROMS User Interface/DlgAnnotationsSelect.cs +++ b/PROMS/VEPROMS User Interface/DlgAnnotationsSelect.cs @@ -93,8 +93,8 @@ namespace VEPROMS // Save selected list to DB. private void btnUpdate_Click(object sender, EventArgs e) { - DataTable dt2 = coverToTable(UserID); - VEPROMS.CSLA.Library.AnnotationstypeSelections.Update(dt2); + DataTable dt2 = coverToTable(); + VEPROMS.CSLA.Library.AnnotationstypeSelections.Update(dt2, UserID); } public class AnnotataionItem { @@ -145,12 +145,10 @@ namespace VEPROMS lstSelected.DisplayMember = "NameStr"; lstSelected.ValueMember = "TypeID"; DataTable lstSelectedTbl = VEPROMS.CSLA.Library.AnnotationstypeSelections.Retrieve(UserID); - if (lstSelectedTbl.Rows.Count > 0) + + foreach (DataRow lstSelectedRow in lstSelectedTbl.Rows) { - foreach (DataRow lstSelectedRow in lstSelectedTbl.Rows) - { - lstSelected.Items.Add(new AnnotataionItem(lstSelectedRow["Name"].ToString(), (int)lstSelectedRow["TypeID"])); - } + lstSelected.Items.Add(new AnnotataionItem(lstSelectedRow["Name"].ToString(), (int)lstSelectedRow["TypeID"])); } } @@ -159,19 +157,15 @@ namespace VEPROMS this.Close(); } - private DataTable coverToTable(string userid) + private DataTable coverToTable() { - int RowID = 0; DataTable dt = new DataTable(); dt.Columns.Add("TypeID", typeof(Int32)); - dt.Columns.Add("NameStr", typeof(string)); - dt.Columns.Add("UserID", typeof(string)); - dt.Columns.Add("RowID", typeof(string)); + foreach (AnnotataionItem item in lstSelected.Items.OfType()) { - ++RowID; - dt.Rows.Add(item.TypeID, item.NameStr, userid, RowID); + dt.Rows.Add(item.TypeID); } return dt; } diff --git a/PROMS/VEPROMS User Interface/PROMSFixes.Sql b/PROMS/VEPROMS User Interface/PROMSFixes.Sql index f5ded9fc..d16b68c8 100644 --- a/PROMS/VEPROMS User Interface/PROMSFixes.Sql +++ b/PROMS/VEPROMS User Interface/PROMSFixes.Sql @@ -24074,10 +24074,6 @@ ELSE GO - - - - -- C2025-027 Annotation Type Filtering IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[AnnotationTypeSelections]') AND type in (N'U')) DROP TABLE [dbo].[AnnotationTypeSelections] @@ -24095,28 +24091,36 @@ GO -- Create date: 07/10/2025 -- Description: Store user Annotation selections for annotation filter. -- ============================================= +IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[AnnotationTypeSelections]') AND type in (N'U')) +BEGIN -CREATE TABLE [dbo].[AnnotationTypeSelections]( - [ASTypeID] [int] IDENTITY(1,1) NOT NULL, - [TypeID] [int] NULL, - [UsrID] [varchar](50) NULL, - [Name] [nvarchar](100) NULL, - [Config] [nvarchar](max) NULL, - [DTS] [datetime] NULL, - [UserID] [nvarchar](100) NULL, - [LastChanged] [timestamp] NULL -) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY] + CREATE TABLE [dbo].[AnnotationTypeSelections]( + [ASTypeID] [int] IDENTITY(1,1) NOT NULL, + [TypeID] [int] NULL, + [UserID] [varchar](50) NULL, + [LastChanged] [datetime] NULL, + CONSTRAINT [PK_AnnotationTypeSelections] PRIMARY KEY CLUSTERED + ([ASTypeID] ASC)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] + ) ON [PRIMARY] +END + +IF OBJECT_ID('DF_AnnotationTypeSelections_LastChanged', 'D') IS NULL + ALTER TABLE AnnotationTypeSelections ADD CONSTRAINT [DF_AnnotationTypeSelections_LastChanged] DEFAULT (getdate()) for [LastChanged]; GO -IF EXISTS (SELECT * FROM sys.indexes WHERE name='idx_AnnotationTypeSelections_UsrID' +IF EXISTS (SELECT * FROM sys.indexes WHERE name='idx_AnnotationTypeSelections_UserIDTypeID' AND object_id = OBJECT_ID('[dbo].[AnnotationTypeSelections]')) begin -DROP INDEX [idx_AnnotationTypeSelections_UsrID] ON [dbo].[AnnotationTypeSelections]; +DROP INDEX [idx_AnnotationTypeSelections_UserIDTypeID] ON [dbo].[AnnotationTypeSelections]; end -CREATE NONCLUSTERED INDEX idx_AnnotationTypeSelections_UsrID - ON [dbo].[AnnotationTypeSelections] (UsrID) -INCLUDE (TypeID, Name) +CREATE UNIQUE INDEX [idx_AnnotationTypeSelections_UserIDTypeID] ON [dbo].[AnnotationTypeSelections] +( +[UserID] ASC, +[TypeID] ASC +) +INCLUDE (ASTypeID) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY] GO -- C2025-027 Annotation Type Filtering @@ -24145,7 +24149,7 @@ AS (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[TypeID]= [TypeID]) [AnnotationCount], [IsEPAnnotationType] FROM [AnnotationTypes] --A - WHERE TypeID NOT IN (SELECT TypeID FROM AnnotationTypeSelections WHERE UsrID = @UserID) + WHERE TypeID NOT IN (SELECT TypeID FROM AnnotationTypeSelections ATS WHERE ATS.UserID = @UserID) GO -- C2025-027 Annotation Type Filtering @@ -24171,18 +24175,19 @@ AS BEGIN SELECT [ASTypeID] ,ATS.[TypeID] - ,[UsrID] + ,ATS.[UserID] ,AT.[Name] ,AT.[Config] - ,ATS.[DTS] + ,ATS.[LastChanged] ,AT.[UserID] ,AT.[IsEPAnnotationType] FROM [dbo].[AnnotationTypeSelections] ATS INNER JOIN AnnotationTypes AT ON AT.TypeID = ATS.TypeID - WHERE UsrID = @UsrID + WHERE ATS.UserID = @UsrID END GO + -- C2025-027 Annotation Type Filtering IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getAnnotationstypeFiltered]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getAnnotationstypeFiltered]; @@ -24200,19 +24205,19 @@ CREATE PROC [dbo].[getAnnotationstypeFiltered] ) AS BEGIN - IF((SELECT count(TypeID) FROM AnnotationTypeSelections WHERE UsrID = @UsrID) > 0) + IF((SELECT count(TypeID) FROM AnnotationTypeSelections WHERE UserID = @UsrID) > 0) BEGIN SELECT [ASTypeID] ,ATS.[TypeID] - ,[UsrID] + ,ATS.[UserID] ,AT.[Name] ,AT.[Config] - ,ATS.[DTS] + ,ATS.[LastChanged] ,AT.[UserID] ,AT.[IsEPAnnotationType] FROM [dbo].[AnnotationTypeSelections] ATS INNER JOIN AnnotationTypes AT ON AT.TypeID = ATS.TypeID - WHERE UsrID = @UsrID + WHERE ATS.UserID = @UsrID END ELSE BEGIN @@ -24241,14 +24246,8 @@ IF EXISTS( SELECT * FROM INFORMATION_SCHEMA.DOMAINS WHERE Domain_Name = 'TableVa DROP TYPE [dbo].[TableValAnnotTypeSelections] CREATE TYPE [dbo].[TableValAnnotTypeSelections] AS TABLE( - [TypeID] [int] NOT NULL, - [NameStr] [varchar](200) NULL, - [UserID] [varchar](50) NULL, - [RowID] [int] NOT NULL, - PRIMARY KEY CLUSTERED -( - [RowID] ASC -)WITH (IGNORE_DUP_KEY = OFF) + [TypeID] [int] NOT NULL + ) GO @@ -24261,28 +24260,30 @@ GO -- ============================================= CREATE PROC [dbo].[UpdateAnnotationstypeSelections] ( - @TempTable AS dbo.TableValAnnotTypeSelections READONLY + @TempTable AS dbo.TableValAnnotTypeSelections READONLY, + @UserID [varchar](50) NULL ) AS BEGIN + + - DECLARE @cnt integer = 0 - DECLARE @cnt2 integer = 0 - SET @cnt = (SELECT count(*) from @TempTable) - DECLARE @UserID VARCHAR(50) = (SELECT TOP 1 UserID FROM @TempTable) - DELETE FROM AnnotationTypeSelections WHERE usrID = @UserID; + DELETE FROM AnnotationTypeSelections where UserID = @UserID + AND + TypeID not in + (Select TypeID From @TempTable tmp) - declare @i int - select @i = min(RowID) from @TempTable - declare @max int - select @max = max(RowID) from @TempTable + --this would insert all the ones that are in the uploaded table and not already in AnnotationTypeSelections + Insert INTO AnnotationTypeSelections (TypeID, UserID) + Select tmp.TypeID, @UserID + FROM + @TempTable tmp + LEFT OUTER JOIN + AnnotationTypeSelections ATS on ATS.TypeID = tmp.TypeID + AND ATS.UserID = @UserID + where + ATS.ASTypeID IS NULL - WHILE @i <= @max - BEGIN - INSERT INTO AnnotationTypeSelections (TypeID, Name, Usrid) - select TypeID, NameStr, UserID from @TempTable where RowID = @i - set @i = @i + 1 - END END GO diff --git a/PROMS/VEPROMS.CSLA.Library/Minimal/AnnotationstypeSections.cs b/PROMS/VEPROMS.CSLA.Library/Minimal/AnnotationstypeSections.cs index 338c6276..0ef12337 100644 --- a/PROMS/VEPROMS.CSLA.Library/Minimal/AnnotationstypeSections.cs +++ b/PROMS/VEPROMS.CSLA.Library/Minimal/AnnotationstypeSections.cs @@ -41,8 +41,6 @@ namespace VEPROMS.CSLA.Library // if the user has not created a annotation sub-set list saved to AnnotationTypeSelections table. if (dt.Rows.Count < 1) { - //dt.Rows.Add(DataPortal.Fetch()); - //DataPortal.Fetch(); DataRow row; int rowflg = 0; foreach (AnnotationTypeInfo annosel in DataPortal.Fetch()) @@ -145,53 +143,22 @@ namespace VEPROMS.CSLA.Library } } } - //public static void Update(string UserID, int TypeID, int dltFlg, string Name = "") - //{ - // using (SqlConnection cn = Database.VEPROMS_SqlConnection) - // { - // using (SqlCommand cm = cn.CreateCommand()) - // { - // try - // { - // cm.CommandType = CommandType.StoredProcedure; - // cm.CommandText = "UpdateAnnotationstypeSelections"; - // cm.CommandTimeout = Database.DefaultTimeout; - // cm.Parameters.AddWithValue("@UserID", UserID); - // cm.Parameters.AddWithValue("@TypeID", TypeID); - // cm.Parameters.AddWithValue("@dltFlg", dltFlg); - // cm.Parameters.AddWithValue("@Name", Name); - // cm.ExecuteNonQuery(); - // } - // catch (Exception ex) - // { - - // } - // } - // } - - //} - public static void Update(DataTable dt) + public static void Update(DataTable dt, string UserID) { using (SqlConnection cn = Database.VEPROMS_SqlConnection) { using (SqlCommand cm = cn.CreateCommand()) { - try - { - cm.CommandType = CommandType.StoredProcedure; - cm.CommandText = "UpdateAnnotationstypeSelections"; - cm.CommandTimeout = Database.DefaultTimeout; + cm.CommandType = CommandType.StoredProcedure; + cm.CommandText = "UpdateAnnotationstypeSelections"; + cm.CommandTimeout = Database.DefaultTimeout; - //Pass table Valued parameter to Store Procedure - SqlParameter sqlParam = cm.Parameters.AddWithValue("@TempTable", dt); - sqlParam.SqlDbType = SqlDbType.Structured; - cm.ExecuteNonQuery(); - } - catch (Exception ex) - { - - } + //Pass table Valued parameter to Store Procedure + SqlParameter sqlParam = cm.Parameters.AddWithValue("@TempTable", dt); + sqlParam.SqlDbType = SqlDbType.Structured; + cm.Parameters.AddWithValue("@UserID", UserID); + cm.ExecuteNonQuery(); } } }