Skip to content

Commit

Permalink
feat: Support company suspensions in database (#1130)
Browse files Browse the repository at this point in the history
  • Loading branch information
john-fletcher-aot authored Jan 31, 2024
1 parent 92077a8 commit a98346f
Show file tree
Hide file tree
Showing 5 changed files with 907 additions and 3 deletions.
2 changes: 2 additions & 0 deletions database/mssql/scripts/versions/revert/v_14_ddl_revert.sql
Original file line number Diff line number Diff line change
Expand Up @@ -9,7 +9,9 @@ SET XACT_ABORT ON

BEGIN TRY
BEGIN TRANSACTION
DROP TABLE [dbo].[ORBC_FEATURE_FLAG_HIST]
DROP TABLE [dbo].[ORBC_FEATURE_FLAG]
DROP SEQUENCE [dbo].[ORBC_FEATURE_FLAG_H_ID_SEQ]
COMMIT
END TRY

Expand Down
191 changes: 191 additions & 0 deletions database/mssql/scripts/versions/revert/v_15_ddl_revert.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,191 @@
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET NOCOUNT ON
GO

SET XACT_ABORT ON
GO
SET TRANSACTION ISOLATION LEVEL SERIALIZABLE
GO
BEGIN TRANSACTION
GO
IF @@ERROR <> 0 SET NOEXEC ON
GO

-- Revert history trigger
ALTER TRIGGER ORBC_COMPNY_A_S_IUD_TR ON [dbo].[ORBC_COMPANY]
FOR INSERT,
UPDATE,
DELETE
AS
SET NOCOUNT ON

BEGIN TRY
DECLARE @curr_date DATETIME;

SET @curr_date = getutcdate();

IF NOT EXISTS (
SELECT *
FROM inserted
)
AND NOT EXISTS (
SELECT *
FROM deleted
)
RETURN;

-- historical
IF EXISTS (
SELECT *
FROM deleted
)
UPDATE [dbo].[ORBC_COMPANY_HIST]
SET END_DATE_HIST = @curr_date
WHERE COMPANY_ID IN (
SELECT COMPANY_ID
FROM deleted
)
AND END_DATE_HIST IS NULL;

IF EXISTS (
SELECT *
FROM inserted
)
INSERT INTO [dbo].[ORBC_COMPANY_HIST] (
[COMPANY_ID],
[COMPANY_GUID],
[CLIENT_NUMBER],
[TPS_CLIENT_HASH],
[LEGAL_NAME],
[ALTERNATE_NAME],
[COMPANY_DIRECTORY],
[MAILING_ADDRESS_ID],
[PHONE],
[EXTENSION],
[FAX],
[EMAIL],
[PRIMARY_CONTACT_ID],
[ACCOUNT_REGION],
[ACCOUNT_SOURCE],
[APP_CREATE_TIMESTAMP],
[APP_CREATE_USERID],
[APP_CREATE_USER_GUID],
[APP_CREATE_USER_DIRECTORY],
[APP_LAST_UPDATE_TIMESTAMP],
[APP_LAST_UPDATE_USERID],
[APP_LAST_UPDATE_USER_GUID],
[APP_LAST_UPDATE_USER_DIRECTORY],
[CONCURRENCY_CONTROL_NUMBER],
[DB_CREATE_USERID],
[DB_CREATE_TIMESTAMP],
[DB_LAST_UPDATE_USERID],
[DB_LAST_UPDATE_TIMESTAMP],
[_COMPANY_HIST_ID],
[END_DATE_HIST],
[EFFECTIVE_DATE_HIST]
)
SELECT [COMPANY_ID],
[COMPANY_GUID],
[CLIENT_NUMBER],
[TPS_CLIENT_HASH],
[LEGAL_NAME],
[ALTERNATE_NAME],
[COMPANY_DIRECTORY],
[MAILING_ADDRESS_ID],
[PHONE],
[EXTENSION],
[FAX],
[EMAIL],
[PRIMARY_CONTACT_ID],
[ACCOUNT_REGION],
[ACCOUNT_SOURCE],
[APP_CREATE_TIMESTAMP],
[APP_CREATE_USERID],
[APP_CREATE_USER_GUID],
[APP_CREATE_USER_DIRECTORY],
[APP_LAST_UPDATE_TIMESTAMP],
[APP_LAST_UPDATE_USERID],
[APP_LAST_UPDATE_USER_GUID],
[APP_LAST_UPDATE_USER_DIRECTORY],
[CONCURRENCY_CONTROL_NUMBER],
[DB_CREATE_USERID],
[DB_CREATE_TIMESTAMP],
[DB_LAST_UPDATE_USERID],
[DB_LAST_UPDATE_TIMESTAMP],
(
NEXT value FOR [dbo].[ORBC_COMPANY_H_ID_SEQ]
) AS [_COMPANY_HIST_ID],
NULL AS [END_DATE_HIST],
@curr_date AS [EFFECTIVE_DATE_HIST]
FROM inserted;
END TRY

BEGIN CATCH
IF @@trancount > 0
ROLLBACK TRANSACTION

EXEC orbc_error_handling
END CATCH;
GO
IF @@ERROR <> 0 SET NOEXEC ON
GO

ALTER TABLE [dbo].[ORBC_COMPANY_HIST]
DROP COLUMN [IS_SUSPENDED]
IF @@ERROR <> 0 SET NOEXEC ON
GO

ALTER TABLE [dbo].[ORBC_COMPANY]
DROP CONSTRAINT [DF_ORBC_COMP_IS_SUSP_DEFAULT]
IF @@ERROR <> 0 SET NOEXEC ON
GO

ALTER TABLE [dbo].[ORBC_COMPANY]
DROP CONSTRAINT [DF_ORBC_COMP_IS_SUSP_DOMAIN]
IF @@ERROR <> 0 SET NOEXEC ON
GO

ALTER TABLE [dbo].[ORBC_COMPANY]
DROP COLUMN [IS_SUSPENDED]
IF @@ERROR <> 0 SET NOEXEC ON
GO

DROP TABLE [dbo].[ORBC_COMPANY_SUSPEND_ACTIVITY]
IF @@ERROR <> 0 SET NOEXEC ON
GO

DROP TABLE [dbo].[ORBC_COMPANY_SUSPEND_ACTIVITY_HIST]
IF @@ERROR <> 0 SET NOEXEC ON
GO

DROP SEQUENCE [dbo].[ORBC_COMPANY_SUSPEND_ACTIVITY_H_ID_SEQ]
IF @@ERROR <> 0 SET NOEXEC ON
GO

DROP TABLE [dbo].[ORBC_SUSPEND_ACTIVITY_TYPE]
IF @@ERROR <> 0 SET NOEXEC ON
GO

DECLARE @VersionDescription VARCHAR(255)
SET @VersionDescription = 'Reverting allowance for company suspensions'

INSERT [dbo].[ORBC_SYS_VERSION] ([VERSION_ID], [DESCRIPTION], [RELEASE_DATE]) VALUES (14, @VersionDescription, getutcdate())
IF @@ERROR <> 0 SET NOEXEC ON
GO

COMMIT TRANSACTION
GO
IF @@ERROR <> 0 SET NOEXEC ON
GO
DECLARE @Success AS BIT
SET @Success = 1
SET NOEXEC OFF
IF (@Success = 1) PRINT 'The database update succeeded'
ELSE BEGIN
IF @@TRANCOUNT > 0 ROLLBACK TRANSACTION
PRINT 'The database update failed'
END
GO
164 changes: 162 additions & 2 deletions database/mssql/scripts/versions/v_14_ddl.sql
Original file line number Diff line number Diff line change
Expand Up @@ -5,10 +5,19 @@ GO
SET NOCOUNT ON
GO

SET XACT_ABORT ON
GO
SET TRANSACTION ISOLATION LEVEL SERIALIZABLE
GO
BEGIN TRANSACTION
GO
IF @@ERROR <> 0 SET NOEXEC ON
GO

CREATE TABLE [dbo].[ORBC_FEATURE_FLAG](
[FEATURE_ID] [int] IDENTITY(1,1) NOT NULL,
[FEATURE_KEY] [nvarchar](50) NOT NULL,
[FEATURE_VALUE] [nvarchar](50) NOT NULL CHECK (FEATURE_VALUE IN ('ENABLED','DISABLED')),
[FEATURE_KEY] [nvarchar](50) NOT NULL,
[FEATURE_VALUE] [nvarchar](50) NOT NULL CHECK (FEATURE_VALUE IN ('ENABLED','DISABLED')),
[APP_CREATE_TIMESTAMP] [datetime2](7) DEFAULT (getutcdate()),
[APP_CREATE_USERID] [nvarchar](30) DEFAULT (user_name()),
[APP_CREATE_USER_GUID] [char](32) NULL,
Expand All @@ -28,6 +37,8 @@ CREATE TABLE [dbo].[ORBC_FEATURE_FLAG](
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
IF @@ERROR <> 0 SET NOEXEC ON
GO

EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'Unique auto-generated surrogate primary key' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'ORBC_FEATURE_FLAG', @level2type=N'COLUMN',@level2name=N'FEATURE_ID'
EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'The feature flag' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1Name=N'ORBC_FEATURE_FLAG', @level2type=N'COLUMN',@level2name=N'FEATURE_KEY'
Expand All @@ -38,8 +49,157 @@ EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'The date and t
EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'The user or proxy account that created the record.' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1Name=N'ORBC_FEATURE_FLAG', @level2type=N'COLUMN',@level2name=N'DB_CREATE_USERID'
EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'The date and time the record was created or last updated.' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1Name=N'ORBC_FEATURE_FLAG', @level2type=N'COLUMN',@level2name=N'DB_LAST_UPDATE_TIMESTAMP'
GO
IF @@ERROR <> 0 SET NOEXEC ON
GO

CREATE SEQUENCE [dbo].[ORBC_FEATURE_FLAG_H_ID_SEQ] AS [bigint] START
WITH 1 INCREMENT BY 1 MINVALUE 1 MAXVALUE 2147483647 CACHE 50;
IF @@ERROR <> 0 SET NOEXEC ON
GO

CREATE TABLE [dbo].[ORBC_FEATURE_FLAG_HIST] (
[_FEATURE_FLAG_HIST_ID] [bigint] DEFAULT(NEXT VALUE FOR [dbo].[ORBC_FEATURE_FLAG_H_ID_SEQ]) NOT NULL,
[EFFECTIVE_DATE_HIST] [datetime] NOT NULL DEFAULT getutcdate(),
[END_DATE_HIST] [datetime],
[FEATURE_ID] INT NOT NULL,
[FEATURE_KEY] NVARCHAR(50) NOT NULL,
[FEATURE_VALUE] NVARCHAR(50) NOT NULL,
[APP_CREATE_TIMESTAMP] DATETIME2 NULL,
[APP_CREATE_USERID] NVARCHAR(30) NULL,
[APP_CREATE_USER_GUID] CHAR(32) NULL,
[APP_CREATE_USER_DIRECTORY] NVARCHAR(30) NULL,
[APP_LAST_UPDATE_TIMESTAMP] DATETIME2 NULL,
[APP_LAST_UPDATE_USERID] NVARCHAR(30) NULL,
[APP_LAST_UPDATE_USER_GUID] CHAR(32) NULL,
[APP_LAST_UPDATE_USER_DIRECTORY] NVARCHAR(30) NULL,
[CONCURRENCY_CONTROL_NUMBER] INT NULL,
[DB_CREATE_USERID] VARCHAR(63) NULL,
[DB_CREATE_TIMESTAMP] DATETIME2 NULL,
[DB_LAST_UPDATE_USERID] VARCHAR(63) NULL,
[DB_LAST_UPDATE_TIMESTAMP] DATETIME2 NULL
)

ALTER TABLE [dbo].[ORBC_FEATURE_FLAG_HIST] ADD CONSTRAINT ORBC_8_H_PK PRIMARY KEY CLUSTERED (_FEATURE_FLAG_HIST_ID);

ALTER TABLE [dbo].[ORBC_FEATURE_FLAG_HIST] ADD CONSTRAINT ORBC_8_H_UK UNIQUE (
_FEATURE_FLAG_HIST_ID,
END_DATE_HIST
)
GO
IF @@ERROR <> 0 SET NOEXEC ON
GO

CREATE TRIGGER FEATFL_A_S_IUD_TR ON [dbo].[ORBC_FEATURE_FLAG]
FOR INSERT,
UPDATE,
DELETE
AS
SET NOCOUNT ON

BEGIN TRY
DECLARE @curr_date DATETIME;

SET @curr_date = getutcdate();

IF NOT EXISTS (
SELECT *
FROM inserted
)
AND NOT EXISTS (
SELECT *
FROM deleted
)
RETURN;

-- historical
IF EXISTS (
SELECT *
FROM deleted
)
UPDATE [dbo].[ORBC_FEATURE_FLAG_HIST]
SET END_DATE_HIST = @curr_date
WHERE FEATURE_ID IN (
SELECT FEATURE_ID
FROM deleted
)
AND END_DATE_HIST IS NULL;

IF EXISTS (
SELECT *
FROM inserted
)
INSERT INTO [dbo].[ORBC_FEATURE_FLAG_HIST] (
[FEATURE_ID],
[FEATURE_KEY],
[FEATURE_VALUE],
[APP_CREATE_TIMESTAMP],
[APP_CREATE_USERID],
[APP_CREATE_USER_GUID],
[APP_CREATE_USER_DIRECTORY],
[APP_LAST_UPDATE_TIMESTAMP],
[APP_LAST_UPDATE_USERID],
[APP_LAST_UPDATE_USER_GUID],
[APP_LAST_UPDATE_USER_DIRECTORY],
[CONCURRENCY_CONTROL_NUMBER],
[DB_CREATE_USERID],
[DB_CREATE_TIMESTAMP],
[DB_LAST_UPDATE_USERID],
[DB_LAST_UPDATE_TIMESTAMP],
[_FEATURE_FLAG_HIST_ID],
[END_DATE_HIST],
[EFFECTIVE_DATE_HIST]
)
SELECT [FEATURE_ID],
[FEATURE_KEY],
[FEATURE_VALUE],
[APP_CREATE_TIMESTAMP],
[APP_CREATE_USERID],
[APP_CREATE_USER_GUID],
[APP_CREATE_USER_DIRECTORY],
[APP_LAST_UPDATE_TIMESTAMP],
[APP_LAST_UPDATE_USERID],
[APP_LAST_UPDATE_USER_GUID],
[APP_LAST_UPDATE_USER_DIRECTORY],
[CONCURRENCY_CONTROL_NUMBER],
[DB_CREATE_USERID],
[DB_CREATE_TIMESTAMP],
[DB_LAST_UPDATE_USERID],
[DB_LAST_UPDATE_TIMESTAMP],
(
NEXT value FOR [dbo].[ORBC_FEATURE_FLAG_H_ID_SEQ]
) AS [_FEATURE_FLAG_HIST_ID],
NULL AS [END_DATE_HIST],
@curr_date AS [EFFECTIVE_DATE_HIST]
FROM inserted;
END TRY

BEGIN CATCH
IF @@trancount > 0
ROLLBACK TRANSACTION

EXEC orbc_error_handling
END CATCH;
GO
IF @@ERROR <> 0 SET NOEXEC ON
GO

DECLARE @VersionDescription VARCHAR(255)
SET @VersionDescription = 'Initial creation of entities for feature flag'

INSERT [dbo].[ORBC_SYS_VERSION] ([VERSION_ID], [DESCRIPTION], [UPDATE_SCRIPT], [REVERT_SCRIPT], [RELEASE_DATE]) VALUES (14, @VersionDescription, '$(UPDATE_SCRIPT)', '$(REVERT_SCRIPT)', getutcdate())
IF @@ERROR <> 0 SET NOEXEC ON
GO

COMMIT TRANSACTION
GO
IF @@ERROR <> 0 SET NOEXEC ON
GO
DECLARE @Success AS BIT
SET @Success = 1
SET NOEXEC OFF
IF (@Success = 1) PRINT 'The database update succeeded'
ELSE BEGIN
IF @@TRANCOUNT > 0 ROLLBACK TRANSACTION
PRINT 'The database update failed'
END
GO
Loading

0 comments on commit a98346f

Please sign in to comment.