Files
SqlScripts/00_DB_SETUP_SINGLE/01_DD_ECM/Update/2.3.sql
2026-02-12 16:58:34 +01:00

137 lines
4.5 KiB
Transact-SQL

UPDATE TBDD_BASECONFIG SET DB_VERSION = '2.3.0';
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_SCHEMA = 'dbo' AND TABLE_NAME = 'MeinTabellenName')
BEGIN
DROP TABLE [TBDD_USER_KEY_VALUE_PAIR];
END
GO
CREATE TABLE [dbo].[TBDD_USER_KEY_VALUE_PAIR](
[PK_USER_KEY_VALUE_PAIR_ID] [bigint] IDENTITY(1,1) NOT NULL,
[FK_USER_ID] [int] NOT NULL,
[FK_MODULE_ID] [int] NOT NULL,
[KEY_NAME] [nvarchar](50) NOT NULL,
[VALUE_TEXT1] [nvarchar](900) NULL,
[VALUE_MAX] [nvarchar](MAX) NULL,
[COMMENT] [nvarchar](50) NULL,
[ADDED_WHEN] [datetime] NOT NULL,
[CHANGED_WHEN] [datetime] NULL,
CONSTRAINT [PK_TBDD_USER_KEY_VALUE_PAIR] PRIMARY KEY CLUSTERED
(
[PK_USER_KEY_VALUE_PAIR_ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
-- Unique-Index auf (MODULE, KEY_NAME)
CREATE UNIQUE INDEX UX_TBDD_USER_KEY_VALUE_PAIR_Module_Key
ON dbo.TBDD_USER_KEY_VALUE_PAIR ([FK_MODULE_ID], [KEY_NAME]);
GO
ALTER TABLE [dbo].[TBDD_USER_KEY_VALUE_PAIR] ADD CONSTRAINT [DF_TBDD_USER_KEY_VALUE_PAIR_ADDED_WHEN] DEFAULT (sysdatetime()) FOR [ADDED_WHEN]
GO
ALTER TABLE [dbo].[TBDD_USER_KEY_VALUE_PAIR] WITH CHECK ADD CONSTRAINT [FK_TBDD_USER_KEY_VALUE_PAIR_TBDD_USER] FOREIGN KEY([FK_USER_ID])
REFERENCES [dbo].[TBDD_USER] ([GUID])
GO
ALTER TABLE [dbo].[TBDD_USER_KEY_VALUE_PAIR] WITH CHECK ADD CONSTRAINT [FK_TBDD_USER_KEY_VALUE_PAIR_TBDD_MODULES] FOREIGN KEY([FK_MODULE_ID])
REFERENCES [dbo].[TBDD_MODULES] ([GUID])
GO
ALTER TABLE [dbo].[TBDD_USER_KEY_VALUE_PAIR] CHECK CONSTRAINT [FK_TBDD_USER_KEY_VALUE_PAIR_TBDD_USER]
GO
---------------------------------------------------------------------------------------------------------------------
CREATE OR ALTER TRIGGER [dbo].[TBDD_USER_KEY_VALUE_PAIR_KEY_VALUE_PAIR_AFT_UPD] ON [dbo].[TBDD_USER_KEY_VALUE_PAIR]
FOR UPDATE
AS
BEGIN
UPDATE [TBDD_USER_KEY_VALUE_PAIR]
SET [CHANGED_WHEN] = GETDATE()
FROM [INSERTED]
WHERE [TBDD_USER_KEY_VALUE_PAIR].[PK_USER_KEY_VALUE_PAIR_ID] = [INSERTED].[PK_USER_KEY_VALUE_PAIR_ID]
END
GO
ALTER TABLE [dbo].[TBDD_USER_KEY_VALUE_PAIR] ENABLE TRIGGER [TBDD_USER_KEY_VALUE_PAIR_KEY_VALUE_PAIR_AFT_UPD]
GO
CREATE OR ALTER PROCEDURE [dbo].[PRDD_TBDD_USER_KEY_VALUE_PAIR_Upsert]
@FK_USER_ID INT,
@KEY_NAME NVARCHAR(50),
@ValueText1 NVARCHAR(900),
@ModuleID INT,
@Out_PK_ID BIGINT OUTPUT -- gibt die betroffene PK zurück
AS
BEGIN
SET NOCOUNT ON;
DECLARE @now DATETIME = GETDATE(); -- statt SYSDATETIME() für Kompatibilität
BEGIN TRY
BEGIN TRAN;
DECLARE @ExistingPK BIGINT;
SELECT @ExistingPK = PK_USER_KEY_VALUE_PAIR_ID
FROM dbo.TBDD_USER_KEY_VALUE_PAIR WITH (UPDLOCK, HOLDLOCK)
WHERE FK_USER_ID = @FK_USER_ID
AND KEY_NAME = @KEY_NAME and [FK_MODULE_ID] = @ModuleID;
IF @ExistingPK IS NOT NULL
BEGIN
-- UPDATE
UPDATE dbo.TBDD_USER_KEY_VALUE_PAIR
SET VALUE_TEXT1 = @ValueText1,
CHANGED_WHEN = @now
WHERE PK_USER_KEY_VALUE_PAIR_ID = @ExistingPK;
SET @Out_PK_ID = @ExistingPK;
END
ELSE
BEGIN
-- INSERT
INSERT INTO dbo.TBDD_USER_KEY_VALUE_PAIR
(
FK_USER_ID,
KEY_NAME,
[FK_MODULE_ID],
VALUE_TEXT1)
VALUES
(
@FK_USER_ID,
@KEY_NAME,
@ModuleID,
@ValueText1
);
SET @Out_PK_ID = CONVERT(BIGINT, SCOPE_IDENTITY());
END
COMMIT TRAN;
END TRY
BEGIN CATCH
IF XACT_STATE() <> 0 ROLLBACK TRAN;
DECLARE
@ErrorNumber INT = ERROR_NUMBER(),
@ErrorSeverity INT = ERROR_SEVERITY(),
@ErrorState INT = ERROR_STATE(),
@ErrorLine INT = ERROR_LINE(),
@ErrorMessage NVARCHAR(4000) = ERROR_MESSAGE(),
@FullMessage NVARCHAR(4000);
-- klassische Verkettung statt CONCAT
SET @FullMessage = N'[PRDD_TBDD_USER_KEY_VALUE_PAIR_Upsert] failed at line '
+ CONVERT(NVARCHAR(10), @ErrorLine)
+ N': '
+ ISNULL(@ErrorMessage, N'');
-- Für ältere SQL Server-Versionen statt THROW:
RAISERROR (@FullMessage, @ErrorSeverity, @ErrorState);
RETURN;
END CATCH
END
GO