9060 lines
367 KiB
Transact-SQL
9060 lines
367 KiB
Transact-SQL
--##################################
|
||
--1. Define Your AdminUsers via replacing YourAdministratorUserName with proper UserNames
|
||
DECLARE @ADMINUSER1 VARCHAR(100),@ADMINUSER2 VARCHAR(100)
|
||
SET @ADMINUSER1 = 'YOUR_ADMIN_USER'
|
||
-- 2. Define if IDB will be used! 0 if not/1 if true
|
||
-- Search for @IDB_AS_METADATA and replace with 1 if true,0 if false
|
||
-- 2. Add the ECM-Login Data
|
||
-- Search for @ECM_IP and replace it with IP or Name of MSSQL Server
|
||
-- Search for @ECM_USER and replace it with DB-Username for ECM-DB
|
||
-- Search for @ECM_PW and replace it with PW for ECM-User
|
||
-- Execute Script and cross fingers :)
|
||
-- ####################################
|
||
CREATE TABLE TBIMPORT_USER (USR_NAME VARCHAR(100));
|
||
INSERT INTO TBIMPORT_USER (USR_NAME) VALUES (@ADMINUSER1);
|
||
CREATE TABLE TBDD_BASECONFIG
|
||
(
|
||
GUID TINYINT,
|
||
WD_UNICODE BIT NOT NULL DEFAULT 1,
|
||
WM_DB_CONSTRING VARCHAR(1000) NOT NULL DEFAULT '',
|
||
WM_DRIVE VARCHAR(1) NOT NULL DEFAULT 'W',
|
||
DB_VERSION VARCHAR(10) NOT NULL DEFAULT '1.0.0.0',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_BASECONFIG_GUID PRIMARY KEY(GUID),
|
||
CONSTRAINT CH_TBDD_BASECONFIG_GUID CHECK(GUID = 1)
|
||
)
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
CREATE TRIGGER TBDD_BASECONFIG_AFT_UPD ON TBDD_BASECONFIG
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBDD_BASECONFIG SET CHANGED_WHEN = GETDATE() FROM INSERTED
|
||
WHERE TBDD_BASECONFIG.GUID = INSERTED.GUID
|
||
GO
|
||
INSERT INTO TBDD_BASECONFIG (GUID,WD_UNICODE,DB_VERSION) VALUES (1,1,'1.9.8.3')
|
||
GO
|
||
CREATE TABLE [dbo].[TBDD_3RD_PARTY_MODULES](
|
||
[GUID] [int] IDENTITY(1,1) NOT NULL,
|
||
[ACTIVE] BIT NOT NULL,
|
||
[NAME] [varchar](50) NOT NULL,
|
||
[DESCRIPTION] [varchar](500) NULL,
|
||
[LICENSE] [varchar](max) NOT NULL,
|
||
[VERSION] [varchar](20) NOT NULL,
|
||
[STRING1] [varchar](100) NULL,
|
||
[STRING2] [varchar](100) NULL,
|
||
[STRING3] [varchar](100) NULL,
|
||
[STRING4] [varchar](100) NULL,
|
||
[STRING5] [varchar](100) NULL,
|
||
[STRING6] [varchar](100) NULL,
|
||
[STRING7] [varchar](100) NULL,
|
||
[STRING8] [varchar](100) NULL,
|
||
[STRING9] [varchar](100) NULL,
|
||
[STRING10] [varchar](100) NULL,
|
||
[ADDED_WHO] [varchar](50) NULL,
|
||
[ADDED_WHEN] DATETIME NULL,
|
||
[CHANGED_WHO] [varchar](50) NULL,
|
||
[CHANGED_WHEN] DATETIME NULL
|
||
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
|
||
GO
|
||
ALTER TABLE [dbo].[TBDD_3RD_PARTY_MODULES] ADD CONSTRAINT [PK_TBDD_3RD_PARTY_MODULES] PRIMARY KEY CLUSTERED
|
||
(
|
||
[GUID] ASC
|
||
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY];
|
||
GO
|
||
ALTER TABLE [dbo].[TBDD_3RD_PARTY_MODULES] ADD CONSTRAINT [DF_TBDD_3RD_PARTY_MODULES_ACTIVE] DEFAULT ((0)) FOR [ACTIVE]
|
||
GO
|
||
|
||
ALTER TABLE [dbo].[TBDD_3RD_PARTY_MODULES] ADD CONSTRAINT [DF_TBDD_3RD_PARTY_MODULES_VERSION] DEFAULT ('1.0.0.0') FOR [VERSION]
|
||
GO
|
||
INSERT INTO TBDD_3RD_PARTY_MODULES (ACTIVE,NAME,LICENSE) VALUES (1,'GDPICTURE','21182889975216572111813147150675976632')
|
||
GO
|
||
INSERT INTO TBDD_3RD_PARTY_MODULES (NAME,LICENSE,[VERSION],ACTIVE) VALUES (
|
||
'GDPICTURE',
|
||
'kG1Qf9PwmqgR8aDmIW2zI_ebj48RzqAJegRxcystEmkbTGQqfkNBdFOXIb6C_A00Ra8zZkrHdfjqzOPXK7kgkF2YDhvrqKfqh4WDug2vOt0qO31IommzkANSuLjZ4zmraoubyEVd25rE3veQ2h_j7tGIoH_LyIHmy24GaXsxdG0yCzIBMdiLbMMMDwcPY-809KeZ83Grv76OVhFvcbBWyYc251vou1N-kGg5_ZlHDgfWoY85gTLRxafjD3KS_i9ARW4BMiy36y8n7UP2jN8kGRnW_04ubpFtfjJqvtsrP_J9D0x7bqV8xtVtT5JI6dpKsVTiMgDCrIcoFSo5gCC1fw9oUopX4TDCkBQttO4-WHBlOeq9dG5Yb0otonVmJKaQA2tP6sMR-lZDs3ql_WI9t91yPWgpssrJUxSHDd27_LMTH_owJIqkF3NOJd9mYQuAv22oNKFYbH8e41pVKb8cT33Y9CgcQ_sy6YDA5PTuIRi67mjKge_nD9rd0IN213Ir9M_EFWqg9e4haWzIdHXQUo0md70kVhPX4UIH_BKJnxEEnFfoFRNMh77bB0N4jkcBEHPl-ghOERv8dOztf4vCnNpzzWvcLD2cqWIm6THy8XGGq9h4hp8aEreRleSMwv9QQAC7mjLwhQ1rBYkpUHlpTjhTLnMwHknl6HH0Z6zzmsgkRKVyfquv94Pd7QbQfZrRka0ss_48pf9p8hAywEn81Q==',
|
||
'11.2024',
|
||
1);
|
||
GO
|
||
CREATE TABLE TBDD_CATALOG
|
||
(
|
||
GUID INTEGER NOT NULL IDENTITY (1, 1),
|
||
CAT_TITLE VARCHAR(100) NOT NULL,
|
||
CAT_STRING VARCHAR(900) NOT NULL,
|
||
ADDED_WHO VARCHAR(30) NOT NULL DEFAULT 'SYSTEM',
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT (GETDATE()),
|
||
CHANGED_WHO VARCHAR(30),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_CATALOG PRIMARY KEY (GUID),
|
||
CONSTRAINT UQ_TBDD_CATALOG_TITLE UNIQUE (CAT_TITLE)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBDD_CATALOG_USER_AFT_UPD ON TBDD_CATALOG
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBDD_CATALOG SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBDD_CATALOG.GUID = INSERTED.GUID
|
||
GO
|
||
INSERT INTO [TBDD_CATALOG] (CAT_TITLE,CAT_STRING) VALUES ('DDSUPPORT_PORTAL','https://digitaldata.works/support/');
|
||
GO
|
||
INSERT INTO [TBDD_CATALOG] (CAT_TITLE,CAT_STRING) VALUES ('USE_IDB_AS_METADATA','@IDB_AS_METADATA');
|
||
GO
|
||
|
||
CREATE TABLE TBDD_SERV_EXT_PROGRAMS
|
||
(
|
||
GUID TINYINT,
|
||
PDFTK_LOCATION VARCHAR(500) DEFAULT '',
|
||
PDFXCHANGE_LOCATION VARCHAR(500) DEFAULT '',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_SERV_EXT_PROGRAMS_GUID PRIMARY KEY(GUID),
|
||
CONSTRAINT CH_TBDD_SERV_EXT_PROGRAMS_GUID CHECK(GUID = 1)
|
||
)
|
||
GO
|
||
CREATE TABLE TBDD_EINGANGSARTEN
|
||
(
|
||
GUID TINYINT IDENTITY(1,1),
|
||
BEZEICHNUNG VARCHAR(100) NOT NULL,
|
||
BESCHREIBUNG VARCHAR(500),
|
||
ERSTELLTWER VARCHAR(50) DEFAULT 'DD_ECM DEFAULT' NOT NULL,
|
||
ERSTELLTWANN DATETIME DEFAULT GETDATE(),
|
||
GEANDERTWER VARCHAR(50),
|
||
GEAENDERTWANN DATETIME,
|
||
CONSTRAINT PK_TBDD_EINGANGSARTEN PRIMARY KEY (GUID),
|
||
CONSTRAINT UNIQUE_TBDD_EINGANGSARTEN UNIQUE(BEZEICHNUNG)
|
||
)
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
|
||
CREATE TRIGGER TBDD_EINGANGSARTEN_AFT_UPD ON TBDD_EINGANGSARTEN
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBDD_EINGANGSARTEN SET GEAENDERTWANN = GETDATE() FROM INSERTED WHERE TBDD_EINGANGSARTEN.GUID = INSERTED.GUID
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
|
||
INSERT INTO TBDD_EINGANGSARTEN(BEZEICHNUNG,BESCHREIBUNG) VALUES('manueller Scan','Dokumentarten die manuell gescannt werden')
|
||
GO
|
||
INSERT INTO TBDD_EINGANGSARTEN(BEZEICHNUNG,BESCHREIBUNG) VALUES('aus Anwendung','Dokumentarten die <20>ber Simple-Print abgelegt werden')
|
||
GO
|
||
INSERT INTO TBDD_EINGANGSARTEN(BEZEICHNUNG,BESCHREIBUNG) VALUES('manuelle Ablage','alle Dokumentarten die manuell abgelegt werden')
|
||
GO
|
||
|
||
CREATE TABLE TBDD_MODULES
|
||
(
|
||
GUID INTEGER NOT NULL IDENTITY(1,1),
|
||
NAME VARCHAR(50),
|
||
SHORT_NAME VARCHAR(20),
|
||
LICENSE VARCHAR(2000) NOT NULL DEFAULT '',
|
||
PRODUCT_VERSION VARCHAR(20) NOT NULL DEFAULT '1.0.0.0',
|
||
DB_VERSION VARCHAR(20) NOT NULL DEFAULT '1.0.0.0',
|
||
ACTIVE BIT NOT NULL DEFAULT 0,
|
||
VERSION_DELIMITER VARCHAR(1) NOT NULL DEFAULT '~',
|
||
FILE_DELIMITER VARCHAR(1) NOT NULL DEFAULT '_',
|
||
BIT1 BIT NOT NULL DEFAULT 0,
|
||
BIT2 BIT NOT NULL DEFAULT 0,
|
||
STRING1 VARCHAR(50),
|
||
STRING2 VARCHAR(50),
|
||
BACKGROUND_IMAGE VARBINARY(MAX),
|
||
PRODUCT_NAME1 VARCHAR(200) NOT NULL DEFAULT '',
|
||
PRODUCT_NAME2 VARCHAR(200),
|
||
VERSION_UPATE_PATH VARCHAR(500) NOT NULL DEFAULT '',
|
||
AUTO_LOGOUT_USER INTEGER NOT NULL DEFAULT 0,
|
||
WMSESSION_STARTSTOP_STARTUP BIT NOT NULL DEFAULT 0,
|
||
MIN_REQUIRED_VERSION VARCHAR(10) NOT NULL DEFAULT '1.0.0.0',
|
||
LICENSE_VALID BIT NOT NULL DEFAULT 1,
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_MODULE PRIMARY KEY (GUID),
|
||
CONSTRAINT UQ_TBDD_MODULE UNIQUE(NAME)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBDD_MODULE_AFT_UPD ON TBDD_MODULES
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBDD_MODULES SET CHANGED_WHEN = GETDATE() FROM INSERTED
|
||
WHERE TBDD_MODULES.GUID = INSERTED.GUID
|
||
GO
|
||
|
||
INSERT INTO TBDD_MODULES(NAME,SHORT_NAME,LICENSE,STRING1,ACTIVE) VALUES
|
||
('Record-Organizer','ADDI','a0c+ADsUcVQiOBrieIt5tEVrgl/P/ns5w9+A/ZdDo8k=','W',1)
|
||
GO
|
||
INSERT INTO TBDD_MODULES(NAME,SHORT_NAME,LICENSE,STRING1,ACTIVE) VALUES
|
||
('fileFLOW','fileFLOW','kc6j9HSv/UJVAzFjMZv2A3wHZFy+2nNLKP9Qs8g9EVY=','W',1)
|
||
GO
|
||
INSERT INTO TBDD_MODULES(NAME,SHORT_NAME,LICENSE,STRING1,DB_VERSION,PRODUCT_VERSION,ACTIVE) VALUES
|
||
('Process-Manager','PM','kc6j9HSv/UJVAzFjMZv2A3wHZFy+2nNLKP9Qs8g9EVY=','W','1.9.4.3','1.9.4.3',1)
|
||
GO
|
||
INSERT INTO TBDD_MODULES(NAME,SHORT_NAME,LICENSE,STRING1,ACTIVE) VALUES
|
||
('User-Manager','UM','kc6j9HSv/UJVAzFjMZv2A3wHZFy+2nNLKP9Qs8g9EVY=','W',1)
|
||
GO
|
||
INSERT INTO TBDD_MODULES(NAME,SHORT_NAME,LICENSE,STRING1,ACTIVE) VALUES
|
||
('Clipboard-Watcher','CW','kc6j9HSv/UJVAzFjMZv2A3wHZFy+2nNLKP9Qs8g9EVY=','W',1)
|
||
GO
|
||
INSERT INTO TBDD_MODULES(NAME,SHORT_NAME,LICENSE,STRING1,ACTIVE) VALUES
|
||
('Email-Profiler','EMLP','kc6j9HSv/UJVAzFjMZv2A3wHZFy+2nNLKP9Qs8g9EVY=','W',1)
|
||
GO
|
||
|
||
CREATE TABLE TBDD_USER
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
PRENAME VARCHAR(50),
|
||
NAME VARCHAR(50),
|
||
USERNAME VARCHAR(50) NOT NULL UNIQUE,
|
||
SHORTNAME VARCHAR(30),
|
||
EMAIL VARCHAR(100),
|
||
[LANGUAGE] VARCHAR(5) NOT NULL DEFAULT 'de-DE',
|
||
GENERAL_VIEWER VARCHAR(30) NOT NULL DEFAULT 'NONE',
|
||
COMMENT VARCHAR(500),
|
||
WAN_ENVIRONMENT BIT NOT NULL DEFAULT 0,
|
||
USERID_FK_INT_ECM INTEGER NOT NULL DEFAULT 0,
|
||
ATTR_CHAR1 VARCHAR(250),
|
||
ATTR_CHAR2 VARCHAR(250),
|
||
ATTR_CHAR3 VARCHAR(250),
|
||
ATTR_CHAR4 VARCHAR(250),
|
||
ATTR_CHAR5 VARCHAR(250),
|
||
ATTR_CHAR6 VARCHAR(250),
|
||
ATTR_CHAR7 VARCHAR(250),
|
||
ATTR_CHAR8 VARCHAR(250),
|
||
ATTR_CHAR9 VARCHAR(250),
|
||
ATTR_CHAR10 VARCHAR(250),
|
||
ATTR_CHAR11 VARCHAR(250),
|
||
ATTR_CHAR12 VARCHAR(250),
|
||
ATTR_CHAR13 VARCHAR(250),
|
||
ATTR_CHAR14 VARCHAR(250),
|
||
ATTR_CHAR15 VARCHAR(250),
|
||
ATTR_BIT1 BIT NOT NULL DEFAULT 0,
|
||
ATTR_BIT2 BIT NOT NULL DEFAULT 0,
|
||
ATTR_BIT3 BIT NOT NULL DEFAULT 0,
|
||
ATTR_BIT4 BIT NOT NULL DEFAULT 0,
|
||
ACTIVE BIT NOT NULL DEFAULT 1,
|
||
DELETED BIT NOT NULL DEFAULT 0,
|
||
DELETED_WHEN DATETIME,
|
||
DELETED_WHO DATETIME,
|
||
DATE_FORMAT VARCHAR(10) NOT NULL DEFAULT 'dd.MM.yyyy',
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DEFAULT' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_USER PRIMARY KEY (GUID)
|
||
)
|
||
GO
|
||
|
||
|
||
INSERT INTO TBDD_USER(PRENAME,NAME,USERNAME)
|
||
SELECT 'Prename','Surname',USR_NAME FROM TBIMPORT_USER;
|
||
GO
|
||
|
||
|
||
CREATE TABLE TBDD_GROUPS
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
NAME VARCHAR(50),
|
||
ECM_FK_ID INTEGER NOT NULL DEFAULT 0,
|
||
AD_SYNC BIT NOT NULL DEFAULT 0,
|
||
INTERNAL BIT NOT NULL DEFAULT 0,
|
||
ACTIVE BIT NOT NULL DEFAULT 1,
|
||
COMMENT VARCHAR(200),
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_GROUPS PRIMARY KEY (GUID),
|
||
CONSTRAINT UQ_TBDD_GROUPS UNIQUE(NAME)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBDD_GROUPS_AFT_UPD ON TBDD_GROUPS
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBDD_GROUPS SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_GROUPS.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
|
||
INSERT INTO TBDD_GROUPS (NAME,INTERNAL) VALUES ('PM_USER',1)
|
||
GO
|
||
INSERT INTO TBDD_GROUPS (NAME,INTERNAL) VALUES ('PM_ADMINS',1)
|
||
GO
|
||
INSERT INTO TBDD_GROUPS (NAME,INTERNAL) VALUES ('fileFLOW_USER',1)
|
||
GO
|
||
INSERT INTO TBDD_GROUPS (NAME,INTERNAL) VALUES ('fileFLOW_ADMINS',1)
|
||
GO
|
||
INSERT INTO TBDD_GROUPS (NAME,INTERNAL) VALUES ('ADDI_USER',1)
|
||
GO
|
||
INSERT INTO TBDD_GROUPS (NAME,INTERNAL) VALUES ('ADDI_ADMINS',1)
|
||
GO
|
||
INSERT INTO TBDD_GROUPS (NAME,INTERNAL) VALUES ('CW_USER',1)
|
||
GO
|
||
INSERT INTO TBDD_GROUPS (NAME,INTERNAL) VALUES ('CW_ADMINS',1)
|
||
GO
|
||
INSERT INTO TBDD_GROUPS (NAME,INTERNAL) VALUES ('UM_ADMINS',1)
|
||
GO
|
||
INSERT INTO TBDD_GROUPS (NAME,INTERNAL) VALUES ('SERVER_USER',1)
|
||
GO
|
||
|
||
CREATE TABLE TBDD_GROUPS_MODULES
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
MODULE_ID INT NOT NULL,
|
||
GROUP_ID INT NOT NULL,
|
||
COMMENT VARCHAR(200),
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DEFAULT' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_GROUPS_MODULES PRIMARY KEY (GUID),
|
||
CONSTRAINT UC_MODULE_GROUP UNIQUE (MODULE_ID,GROUP_ID),
|
||
CONSTRAINT FK_TBDD_GROUPS_MODULES_GROUP_ID FOREIGN KEY(GROUP_ID) REFERENCES TBDD_GROUPS(GUID),
|
||
CONSTRAINT FK_TBDD_GROUPS_MODULES_MODULE_ID FOREIGN KEY(MODULE_ID) REFERENCES TBDD_MODULES(GUID),
|
||
)
|
||
GO
|
||
CREATE TABLE dbo.TBDD_USER_REPRESENTATION (
|
||
GUID INTEGER IDENTITY(1,1) NOT NULL,
|
||
USER_ID INTEGER NOT NULL,
|
||
REPR_GROUP INTEGER,
|
||
RIGHT_GROUP INTEGER NOT NULL,
|
||
ADDED_WHO VARCHAR(50) DEFAULT ('DEFAULT') NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT getdate(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
REPR_USER INTEGER,
|
||
CONSTRAINT PK_TBDD_USER_REPRESENTATION PRIMARY KEY (GUID),
|
||
CONSTRAINT UC_TBDD_USER_REPRESENTATION UNIQUE (USER_ID,REPR_GROUP,RIGHT_GROUP),
|
||
CONSTRAINT FK_TBDD_USER_REPRESENTATION_REPR_USER FOREIGN KEY(USER_ID) REFERENCES TBDD_USER(GUID),
|
||
CONSTRAINT FK_TBDD_USER_REPRESENTATION_REPR_GROUP FOREIGN KEY(REPR_GROUP) REFERENCES TBDD_GROUPS(GUID),
|
||
CONSTRAINT FK_TBDD_USER_REPRESENTATION_RIGHT_GROUP FOREIGN KEY(RIGHT_GROUP) REFERENCES TBDD_GROUPS(GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBDD_USER_REPRESENTATION_AFT_UPD ON TBDD_USER_REPRESENTATION
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBDD_USER_REPRESENTATION SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_USER_REPRESENTATION.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
CREATE TABLE TBDD_CLIENT
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
CLIENT_NAME VARCHAR(50) NOT NULL UNIQUE,
|
||
SHORTNAME VARCHAR(30),
|
||
LICENSE_PMO VARCHAR(5000) NOT NULL DEFAULT '',
|
||
LICENSE_GI VARCHAR(5000) NOT NULL DEFAULT '',
|
||
LICENSE_PM VARCHAR(5000) NOT NULL DEFAULT '',
|
||
COMMENT VARCHAR(200),
|
||
ACTIVE BIT NOT NULL DEFAULT 0,
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DEFAULT' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_CLIENT PRIMARY KEY (GUID)
|
||
)
|
||
GO
|
||
INSERT INTO TBDD_CLIENT(CLIENT_NAME,SHORTNAME,ACTIVE) VALUES
|
||
('DEFAULT','DEF',1)
|
||
GO
|
||
|
||
CREATE TRIGGER TBDD_CLIENT_AFT_UPD ON TBDD_CLIENT
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBDD_CLIENT SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_CLIENT.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
CREATE TABLE TBDD_GROUPS_CLIENT
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
CLIENT_ID INT NOT NULL,
|
||
GROUP_ID INT NOT NULL,
|
||
COMMENT VARCHAR(200),
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DEFAULT' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_GROUPS_CLIENT PRIMARY KEY (GUID),
|
||
CONSTRAINT UC_CLIENT_GROUP UNIQUE (CLIENT_ID,GROUP_ID),
|
||
CONSTRAINT FK_TBDD_GROUPS_CLIENT_GROUP_ID FOREIGN KEY(GROUP_ID) REFERENCES TBDD_GROUPS(GUID),
|
||
CONSTRAINT FK_TBDD_GROUPS_CLIENT_CLIENT_ID FOREIGN KEY(CLIENT_ID) REFERENCES TBDD_CLIENT(GUID),
|
||
)
|
||
GO
|
||
|
||
|
||
CREATE TABLE TBDD_GROUPS_USER
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
[USER_ID] INT NOT NULL,
|
||
GROUP_ID INT NOT NULL,
|
||
COMMENT VARCHAR(200),
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DEFAULT' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_GROUPS_USER PRIMARY KEY (GUID),
|
||
CONSTRAINT UC_USER_GROUP UNIQUE (USER_ID,GROUP_ID),
|
||
CONSTRAINT FK_TBDD_GROUPS_USER_GROUP_ID FOREIGN KEY(GROUP_ID) REFERENCES TBDD_GROUPS(GUID),
|
||
CONSTRAINT FK_TBDD_GROUPS_USER_USER_ID FOREIGN KEY([USER_ID]) REFERENCES TBDD_USER(GUID),
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBDD_GROUPS_USER_AFT_UPD ON TBDD_GROUPS_USER
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBDD_GROUPS_USER SET CHANGED_WHEN = GETDATE() FROM INSERTED
|
||
WHERE TBDD_GROUPS_USER.GUID = INSERTED.GUID
|
||
GO
|
||
CREATE TRIGGER [dbo].[TBDD_GROUPS_USER_AFT_DEL] ON [dbo].[TBDD_GROUPS_USER]
|
||
FOR DELETE
|
||
AS
|
||
DECLARE @USER_ID INTEGER
|
||
SELECT @USER_ID = deleted.USER_ID FROM deleted
|
||
IF @USER_ID IS NOT NULL
|
||
BEGIN
|
||
if exists (select * from sysobjects where name='TBPMO_USER_RIGHTS_JOBS' and xtype='U')
|
||
INSERT INTO TBPMO_USER_RIGHTS_JOBS (USER_ID,COMMENT,ADDED_WHO) VALUES (@USER_ID,'USER DELETED FROM GROUP','TBDD_GROUPS_USER_AFT_DEL')
|
||
if exists (select * from sysobjects where name='TBPMO_LOG_ESSENTIALS' and xtype='U')
|
||
INSERT INTO TBPMO_LOG_ESSENTIALS (REFERENCE_KEY,REFERENCE_STRING,COMMENT,ADDED_WHO) VALUES (@USER_ID,'USER-ID','USER DELETED FROM USER-GROUP',(SELECT USERNAME FROM TBDD_USER WHERE GUID = @USER_ID ))
|
||
END
|
||
GO
|
||
CREATE TABLE TBDD_FUNCTION_REGEX
|
||
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
FUNCTION_NAME VARCHAR(250) NOT NULL,
|
||
REGEX VARCHAR(MAX) NOT NULL,
|
||
STRING1 VARCHAR(500),
|
||
STRING2 VARCHAR(500),
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'Digital Data',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_FUNCTION_REGEX PRIMARY KEY (GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBTBDD_FUNCTION_REGEX_AFT_UPD ON TBDD_FUNCTION_REGEX
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBDD_FUNCTION_REGEX SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_FUNCTION_REGEX.GUID = INSERTED.GUID
|
||
GO
|
||
|
||
|
||
INSERT INTO TBDD_FUNCTION_REGEX(FUNCTION_NAME,REGEX) VALUES
|
||
('FROM_EMAIL_HEADER','From:(?:\s*[\w\s\d.@&,|+%\)\(\-]*<|\s*=\?[\w\s\d.@&,|+%?=\)\(\-]+\?=\s*<|\s*""[\w\s\d.@&,|+%\)\(\-]+""\s*<|\s*)([A-Z0-9._%+-]+@[A-Z0-9.-]+\.[A-Z]{2,})>?')
|
||
GO
|
||
INSERT INTO TBDD_FUNCTION_REGEX(FUNCTION_NAME,REGEX) VALUES
|
||
('TO_EMAIL_HEADER','To:(?:\s*[\w\s\d.@&,|+%\)\(\-]+<|\s*=\?[\w\s\d.@&,|+%?=\)\(\-]+\?=\s*<|\s*""[\w\s\d.@&,|+%\)\(\-]+""\s*<|\s*)([A-Z0-9._%+-]+@[A-Z0-9.-]+\.[A-Z]{2,})>?')
|
||
GO
|
||
INSERT INTO TBDD_FUNCTION_REGEX(FUNCTION_NAME,REGEX) VALUES
|
||
('EMAIL_PROFILER - BODY REMOVE NewLine','[^\s]([\w\s\!\<5C>\$\%\&\/\(\)\=\?\[\]\,\.\-\<5C>\:\;\<\>\@\r\n\#]{1,})^[\#]{2}')
|
||
GO
|
||
|
||
CREATE TABLE TBDD_LANGUAGE_OBJECTS
|
||
(
|
||
GUID VARCHAR(50) NOT NULL,
|
||
MODULE_ID INTEGER NOT NULL,
|
||
FORM_NAME VARCHAR(100) NOT NULL,
|
||
[LANGUAGE] VARCHAR(20),
|
||
CONTENT VARCHAR(MAX),
|
||
COMMENT VARCHAR(200),
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DEFAULT' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_LANGUAGE_OBJECTS PRIMARY KEY (GUID),
|
||
CONSTRAINT FK_TBDD_LANGUAGE_OBJECTS_MODULE_ID FOREIGN KEY(MODULE_ID) REFERENCES TBDD_MODULES(GUID),
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBDD_LANGUAGE_OBJECTS_AFT_UPD ON TBDD_LANGUAGE_OBJECTS
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBDD_LANGUAGE_OBJECTS SET CHANGED_WHEN = GETDATE() FROM INSERTED
|
||
WHERE TBDD_LANGUAGE_OBJECTS.GUID = INSERTED.GUID
|
||
GO
|
||
|
||
|
||
CREATE TABLE TBDD_VERSION_USER_UPDATE_PATH(
|
||
GUID INTEGER NOT NULL IDENTITY(1,1),
|
||
USER_ID INT NOT NULL,
|
||
MODULE_NAME VARCHAR(30) NOT NULL,
|
||
UPDATE_PATH VARCHAR(500) NOT NULL DEFAULT '',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CONSTRAINT [PK_TBDD_VERSION_USER_UPDATE_PATH] PRIMARY KEY(GUID))
|
||
GO
|
||
CREATE TRIGGER TBDD_VERSION_USER_UPDATE_PATH_AFT_UPD ON TBDD_VERSION_USER_UPDATE_PATH
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBDD_VERSION_USER_UPDATE_PATH SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_VERSION_USER_UPDATE_PATH.GUID = INSERTED.GUID
|
||
|
||
GO
|
||
CREATE TABLE TBDD_VERSION_UPDATE(
|
||
GUID INTEGER NOT NULL IDENTITY(1,1),
|
||
ALL_USERS BIT NOT NULL DEFAULT 0,
|
||
FORCE_UPD BIT NOT NULL DEFAULT 0,
|
||
MODULE_NAME VARCHAR(30) NOT NULL,
|
||
VERSION_NO VARCHAR(20) NOT NULL,
|
||
VERSION_FORCE_UPD VARCHAR(100) NOT NULL DEFAULT '',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CONSTRAINT [PK_TBDD_VERSION_UPDATE] PRIMARY KEY(GUID))
|
||
GO
|
||
|
||
CREATE TRIGGER [dbo].[TBDD_VERSION_UPDATE_AFT_UPD] ON [dbo].[TBDD_VERSION_UPDATE]
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN TRY
|
||
DECLARE
|
||
@UPDATE_ID INTEGER,
|
||
@USER_ID INTEGER,
|
||
@ALL_USERS INT
|
||
SELECT @UPDATE_ID = GUID FROM INSERTED
|
||
|
||
IF UPDATE (ALL_USERS)
|
||
BEGIN
|
||
SELECT @ALL_USERS = ALL_USERS FROM INSERTED
|
||
DELETE FROM TBDD_VERSION_USER_UPDATE WHERE UPDATE_ID = @UPDATE_ID
|
||
IF @ALL_USERS = 1
|
||
BEGIN
|
||
DECLARE cursorUsers CURSOR FOR
|
||
select GUID FROM TBDD_USER
|
||
OPEN cursorUsers
|
||
FETCH NEXT FROM cursorUsers INTO @USER_ID
|
||
WHILE @@FETCH_STATUS = 0
|
||
BEGIN
|
||
INSERT INTO TBDD_VERSION_USER_UPDATE (USER_ID, UPDATE_ID) VALUES (@USER_ID,@UPDATE_ID)
|
||
|
||
FETCH NEXT FROM cursorUsers INTO @USER_ID
|
||
END
|
||
CLOSE cursorUsers
|
||
DEALLOCATE cursorUsers
|
||
END
|
||
END
|
||
--Generelle Updates (Datum und Recor-<2D>nderungen)
|
||
UPDATE TBDD_VERSION_UPDATE SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_VERSION_UPDATE.GUID = INSERTED.GUID
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'ERROR IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE())
|
||
+ ' - ERROR-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
END CATCH
|
||
GO
|
||
|
||
CREATE TABLE TBDD_VERSION_ITEMS(
|
||
GUID INTEGER NOT NULL IDENTITY(1,1),
|
||
UPDATE_ID INTEGER NOT NULL,
|
||
ITEM_INFO VARCHAR(100) NOT NULL,
|
||
INFO1 VARCHAR(100),
|
||
INFO2 VARCHAR(100),
|
||
INFO3 VARCHAR(100),
|
||
BIT1 BIT NOT NULL DEFAULT 0,
|
||
BIT2 BIT NOT NULL DEFAULT 0,
|
||
BIT3 BIT NOT NULL DEFAULT 0,
|
||
COMMENT VARCHAR(250),
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CONSTRAINT [PK_TBDD_VERSION_ITEMS] PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBDD_VERSION_ITEMS_UPDATE_ID FOREIGN KEY (UPDATE_ID) REFERENCES TBDD_VERSION_UPDATE (GUID))
|
||
GO
|
||
CREATE TABLE TBDD_VERSION_USER_UPDATE(
|
||
GUID INTEGER NOT NULL IDENTITY(1,1),
|
||
[USER_ID] INTEGER NOT NULL,
|
||
UPDATE_ID INTEGER NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CONSTRAINT [PK_TBDD_VERSION_USER_UPDATE] PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBDD_VERSION_USER_UPDATE_UPDATE_ID FOREIGN KEY (UPDATE_ID) REFERENCES TBDD_VERSION_UPDATE (GUID))
|
||
GO
|
||
|
||
|
||
CREATE TRIGGER TBDD_USER_AFT_UPD ON TBDD_USER
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBDD_USER SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_USER.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
|
||
CREATE TABLE TBDD_CLIENT_USER
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
[USER_ID] INT NOT NULL,
|
||
CLIENT_ID INT NOT NULL,
|
||
COMMENT VARCHAR(200),
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CONSTRAINT PK_TBDD_CLIENT_USER PRIMARY KEY (GUID),
|
||
CONSTRAINT FK_TBDD_CLIENT_USER_GROUP_ID FOREIGN KEY(CLIENT_ID) REFERENCES TBDD_CLIENT(GUID),
|
||
CONSTRAINT FK_TBDD_CLIENT_USER_USER_ID FOREIGN KEY([USER_ID]) REFERENCES TBDD_USER(GUID),
|
||
)
|
||
GO
|
||
CREATE TABLE TBDD_CLIENT_GROUP
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
[GROUP_ID] INT NOT NULL,
|
||
CLIENT_ID INT NOT NULL,
|
||
COMMENT VARCHAR(200),
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CONSTRAINT PK_TBDD_CLIENT_GROUP PRIMARY KEY (GUID),
|
||
CONSTRAINT FK_TBDD_CLIENT_GROUP_GROUP_ID FOREIGN KEY(GROUP_ID) REFERENCES TBDD_GROUPS(GUID),
|
||
CONSTRAINT FK_TBDD_CLIENT_GROUP_CLIENT_ID FOREIGN KEY(CLIENT_ID) REFERENCES TBDD_CLIENT(GUID),
|
||
)
|
||
GO
|
||
|
||
CREATE TABLE TBDD_USER_MODULES
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
[USER_ID] INT NOT NULL,
|
||
MODULE_ID INT NOT NULL,
|
||
IS_ADMIN BIT NOT NULL DEFAULT 0,
|
||
RIGHT1 BIT NOT NULL DEFAULT 0,
|
||
RIGHT2 BIT NOT NULL DEFAULT 0,
|
||
RIGHT3 BIT NOT NULL DEFAULT 0,
|
||
RIGHT4 BIT NOT NULL DEFAULT 0,
|
||
COMMENT VARCHAR(200),
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME ,
|
||
CONSTRAINT PK_TBDD_USER_MODULES PRIMARY KEY (GUID),
|
||
CONSTRAINT UQ_TBDD_USER_MODULES UNIQUE([USER_ID],MODULE_ID),
|
||
CONSTRAINT FK_TBDD_USER_MODULES_MODULE_ID FOREIGN KEY(MODULE_ID) REFERENCES TBDD_MODULES(GUID),
|
||
CONSTRAINT FK_TBDD_USER_MODULES2_USER_ID FOREIGN KEY([USER_ID]) REFERENCES TBDD_USER(GUID),
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBDD_USER_MODULES_AFT_UPD ON TBDD_USER_MODULES
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBDD_USER_MODULES SET CHANGED_WHEN = GETDATE() FROM INSERTED
|
||
WHERE TBDD_USER_MODULES.GUID = INSERTED.GUID
|
||
GO
|
||
|
||
INSERT INTO TBDD_USER_MODULES (USER_ID,MODULE_ID,IS_ADMIN) SELECT GUID,(SELECT GUID FROM TBDD_MODULES WHERE SHORT_NAME = 'UM'),1 FROM TBDD_USER where GUID NOT IN (
|
||
SELECT USER_ID FROM TBDD_USER_MODULES WHERE MODULE_ID = (SELECT GUID FROM TBDD_MODULES WHERE SHORT_NAME = 'UM'))
|
||
GO
|
||
|
||
CREATE TRIGGER [dbo].[TBDD_USER_AFT_DEL] ON [dbo].[TBDD_USER]
|
||
FOR DELETE
|
||
AS
|
||
DECLARE @USER_ID INTEGER
|
||
BEGIN
|
||
SELECT @USER_ID = GUID FROM DELETED
|
||
IF @USER_ID IN (0,1)
|
||
BEGIN
|
||
ROLLBACK TRANSACTION
|
||
RAISERROR('THIS USER CAN NOT BE DELETED!',16,10)
|
||
END
|
||
ELSE
|
||
BEGIN
|
||
INSERT INTO TBPMO_USER_RIGHTS_JOBS (USER_ID,COMMENT,ADDED_WHO) VALUES
|
||
(@USER_ID,'USER DELETED','TBDD_GROUPS_USER_AFT_DEL')
|
||
END
|
||
END
|
||
GO
|
||
CREATE TABLE TBDD_USER_MODULE_LOG_IN
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
CLIENT_ID INTEGER NOT NULL DEFAULT 0,
|
||
CONNECTION_STRING VARCHAR(500) NOT NULL DEFAULT '' ,
|
||
USER_ID INTEGER NOT NULL,
|
||
MACHINE_NAME VARCHAR(250) NOT NULL DEFAULT '',
|
||
MODULE VARCHAR(50),
|
||
VERSION_CLIENT VARCHAR(30),
|
||
LANGUAGE_OVERRIDE VARCHAR(5),
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE() NOT NULL,
|
||
CONSTRAINT PK_TBDD_USER_MODULE_LOG_IN PRIMARY KEY (GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBDD_USER_MODULE_LOG_IN_AFT_INS ON TBDD_USER_MODULE_LOG_IN
|
||
WITH EXECUTE AS CALLER
|
||
FOR INSERT
|
||
AS
|
||
BEGIN TRY
|
||
DECLARE
|
||
@USER_ID INTEGER,
|
||
@MODULE VARCHAR(50),
|
||
@CLIENT_ID INTEGER,
|
||
@VERSION_CLIENT VARCHAR(30),
|
||
@MACHINE_NAME VARCHAR(50),
|
||
@CONNECTION_STRING VARCHAR(500)
|
||
SELECT
|
||
@USER_ID = USER_ID,
|
||
@MODULE = MODULE,
|
||
@CLIENT_ID = CLIENT_ID,
|
||
@VERSION_CLIENT = VERSION_CLIENT,
|
||
@MACHINE_NAME = MACHINE_NAME,
|
||
@CONNECTION_STRING = CONNECTION_STRING
|
||
FROM INSERTED
|
||
|
||
IF @VERSION_CLIENT IS NULL
|
||
SET @VERSION_CLIENT = '1.0.0.0'
|
||
INSERT INTO TBDD_USER_LOGIN_OUT (MODULE,USER_ID,CLIENT_ID,VERSION_CLIENT,MACHINE_NAME,CONNECTION_STRING) VALUES (@MODULE,@USER_ID,@CLIENT_ID,@VERSION_CLIENT,@MACHINE_NAME,@CONNECTION_STRING)
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'FEHLER IN TRIGGER: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE()) + ' - ZEILE: ' + CONVERT(VARCHAR(10),ERROR_LINE())
|
||
+ ' - FEHLER-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
END CATCH
|
||
GO
|
||
CREATE TRIGGER TBDD_USER_MODULE_LOG_IN_AFT_DEL ON TBDD_USER_MODULE_LOG_IN
|
||
FOR DELETE
|
||
AS
|
||
BEGIN TRY
|
||
DECLARE
|
||
@USER_ID INTEGER,
|
||
@MODULE VARCHAR(50),
|
||
@CLIENT_ID INTEGER
|
||
SELECT
|
||
@USER_ID = USER_ID,
|
||
@MODULE = MODULE,
|
||
@CLIENT_ID = CLIENT_ID
|
||
FROM DELETED
|
||
|
||
UPDATE TBDD_USER_LOGIN_OUT SET LOGOUT = GETDATE() WHERE GUID = (
|
||
SELECT MAX(GUID) FROM TBDD_USER_LOGIN_OUT WHERE USER_ID = @USER_ID AND MODULE = @MODULE AND CLIENT_ID = @CLIENT_ID)
|
||
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'ERROR IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE())
|
||
+ ' - ERROR-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
END CATCH
|
||
GO
|
||
CREATE TABLE TBDD_CONNECTION
|
||
|
||
(
|
||
GUID SMALLINT IDENTITY(1,1),
|
||
BEZEICHNUNG VARCHAR(100),
|
||
SQL_PROVIDER VARCHAR(50),
|
||
SERVER VARCHAR(150),
|
||
DATENBANK VARCHAR(100),
|
||
USERNAME VARCHAR(100),
|
||
PASSWORD VARCHAR(100),
|
||
BEMERKUNG VARCHAR(400),
|
||
SYS_CONNECTION BIT DEFAULT 0 NOT NULL,
|
||
AKTIV BIT DEFAULT 1 NOT NULL, -- 1 - Connection aktiv, 0 - inaktiv
|
||
ERSTELLTWER VARCHAR(50) DEFAULT 'DD_ECM DEFAULT' NOT NULL,
|
||
ERSTELLTWANN DATETIME DEFAULT GETDATE(),
|
||
GEANDERTWER VARCHAR(50),
|
||
GEAENDERTWANN DATETIME,
|
||
CONSTRAINT PK_TBDD_CONNECTION PRIMARY KEY (GUID)
|
||
)
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
|
||
CREATE TRIGGER TBDD_CONNECTION_AFT_UPD ON TBDD_CONNECTION
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBDD_CONNECTION SET GEAENDERTWANN = GETDATE() FROM INSERTED WHERE TBDD_CONNECTION.GUID = INSERTED.GUID
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
INSERT INTO TBDD_CONNECTION(BEZEICHNUNG,SQL_PROVIDER,SERVER,DATENBANK,USERNAME,PASSWORD) VALUES ('DD_ECM','MS-SQL','@ECM_IP','DD_ECM','@ECM_USER','@ECM_PW')
|
||
GO
|
||
IF EXISTS (SELECT * FROM [TBDD_CATALOG] WHERE CAT_TITLE = 'USE_IDB_AS_METADATA' AND CAT_STRING = '1')
|
||
INSERT INTO TBDD_CONNECTION(BEZEICHNUNG,SQL_PROVIDER,SERVER,DATENBANK,USERNAME,PASSWORD) VALUES ('IDB','MS-SQL','@ECM_IP','IDB','@ECM_USER','@ECM_PW')
|
||
GO
|
||
|
||
|
||
CREATE TABLE TBDD_DOKUMENTART
|
||
(
|
||
GUID INT IDENTITY(1,1),
|
||
BEZEICHNUNG VARCHAR(50) NOT NULL,
|
||
OBJEKTTYP VARCHAR(50) NOT NULL,
|
||
EINGANGSART_ID TINYINT NOT NULL, -- Typ der die Entstehung der dokumnetart beschreibt
|
||
KURZNAME VARCHAR(50) NOT NULL,
|
||
ZIEL_PFAD VARCHAR(250) NOT NULL,
|
||
BESCHREIBUNG VARCHAR(250),
|
||
WINDREAM_DIRECT BIT DEFAULT 0 NOT NULL,
|
||
FOLDER_FOR_INDEX VARCHAR(500) DEFAULT '' NOT NULL,
|
||
DUPLICATE_HANDLING VARCHAR(30) NOT NULL DEFAULT 'Default',
|
||
AKTIV BIT DEFAULT 0 NOT NULL, -- 1 - Dokumentart aktiv und kann benutzt werden, 0 - inaktiv
|
||
[LANGUAGE] VARCHAR(5) NOT NULL DEFAULT 'de-DE',
|
||
SEQUENCE INT NOT NULL DEFAULT 1,
|
||
IDB_OBJECT_STORE_ID INT DEFAULT 0 NOT NULL,
|
||
NAMENKONVENTION VARCHAR(500) NOT NULL DEFAULT '',
|
||
ERSTELLTWER VARCHAR(50) DEFAULT 'DEFAULT' NOT NULL,
|
||
ERSTELLTWANN DATETIME DEFAULT GETDATE(),
|
||
GEANDERTWER VARCHAR(50),
|
||
GEAENDERTWANN DATETIME,
|
||
CONSTRAINT PK_TBDD_DOKUMENTART PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBDD_DOKUMENTART_EINGID FOREIGN KEY(EINGANGSART_ID) REFERENCES TBDD_EINGANGSARTEN(GUID),
|
||
CONSTRAINT UNIQUE_TBDD_DOKUMENTART UNIQUE(BEZEICHNUNG)
|
||
)
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
|
||
CREATE TRIGGER TBDD_DOKUMENTART_AFT_UPD ON TBDD_DOKUMENTART
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN TRY
|
||
DECLARE
|
||
@DA_TITLE VARCHAR(50),
|
||
@LANGUAGE VARCHAR(5),
|
||
@CHANGED_WHO VARCHAR(50),
|
||
@GUID INTEGER,
|
||
@SCREEN_ID INTEGER,
|
||
@PMO_OBJECT_NAME VARCHAR(100)
|
||
SELECT
|
||
@GUID = GUID,
|
||
@DA_TITLE = BEZEICHNUNG,
|
||
@SCREEN_ID = 1,
|
||
@CHANGED_WHO = GEANDERTWER
|
||
FROM INSERTED
|
||
SELECT @LANGUAGE = [LANGUAGE] FROM TBDD_USER WHERE UPPER(USERNAME) = UPPER(@CHANGED_WHO)
|
||
SET @PMO_OBJECT_NAME = 'DOCTYPE_TITLE' + CONVERT(VARCHAR(5),@GUID)
|
||
|
||
UPDATE TBDD_DOKUMENTART SET GEAENDERTWANN = GETDATE() FROM INSERTED
|
||
WHERE TBDD_DOKUMENTART.GUID = INSERTED.GUID
|
||
IF UPDATE (BEZEICHNUNG)
|
||
BEGIN
|
||
IF OBJECT_ID(N'dbo.TBPMO_WD_OBJECTTYPE', N'U') IS NOT NULL
|
||
BEGIN
|
||
If exists(SELECT * FROM TBPMO_LANGUAGE_OBJECT WHERE PMO_OBJECT_NAME = @PMO_OBJECT_NAME AND
|
||
LANGUAGE_TYPE = @LANGUAGE AND SCREEN_ID = @SCREEN_ID)
|
||
UPDATE TBPMO_LANGUAGE_OBJECT SET CAPTION = @DA_TITLE,CHANGED_WHO = @CHANGED_WHO WHERE
|
||
PMO_OBJECT_NAME = @PMO_OBJECT_NAME AND
|
||
LANGUAGE_TYPE = @LANGUAGE AND SCREEN_ID = @SCREEN_ID
|
||
ELSE
|
||
INSERT INTO TBPMO_LANGUAGE_OBJECT (LANGUAGE_TYPE,SCREEN_ID,PMO_OBJECT_NAME,CAPTION) VALUES
|
||
(@LANGUAGE,@SCREEN_ID,@PMO_OBJECT_NAME,@DA_TITLE)
|
||
END
|
||
END
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'ERROR IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE())
|
||
+ ' - ERROR-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
END CATCH
|
||
GO
|
||
|
||
CREATE TRIGGER [dbo].[TBDD_DOKUMENTART_AFT_INS] ON [dbo].[TBDD_DOKUMENTART]
|
||
WITH EXECUTE AS CALLER
|
||
FOR INSERT
|
||
AS
|
||
BEGIN TRY
|
||
DECLARE
|
||
@DA_TITLE VARCHAR(50),
|
||
@LANGUAGE VARCHAR(5),
|
||
@ADDED_WHO VARCHAR(50),
|
||
@GUID INTEGER,
|
||
@SCREEN_ID INTEGER,
|
||
@PMO_OBJECT_NAME VARCHAR(100)
|
||
SELECT
|
||
@GUID = GUID,
|
||
@DA_TITLE = BEZEICHNUNG,
|
||
@LANGUAGE = [LANGUAGE],
|
||
@SCREEN_ID = 1,
|
||
@ADDED_WHO = ERSTELLTWER
|
||
FROM INSERTED
|
||
|
||
SET @PMO_OBJECT_NAME = 'DOCTYPE_TITLE' + CONVERT(VARCHAR(5),@GUID)
|
||
IF OBJECT_ID(N'dbo.TBPMO_WD_OBJECTTYPE', N'U') IS NOT NULL
|
||
INSERT INTO TBPMO_LANGUAGE_OBJECT (LANGUAGE_TYPE,SCREEN_ID,PMO_OBJECT_NAME,CAPTION,ADDED_WHO) VALUES
|
||
(@LANGUAGE,@SCREEN_ID,@PMO_OBJECT_NAME,@DA_TITLE,@ADDED_WHO)
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'ERROR IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE())
|
||
+ ' - ERROR-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
END CATCH
|
||
GO
|
||
|
||
CREATE TRIGGER TBDD_DOKUMENTART_AFT_INS2 ON TBDD_DOKUMENTART
|
||
WITH EXECUTE AS CALLER
|
||
FOR INSERT
|
||
AS
|
||
BEGIN TRY
|
||
DECLARE
|
||
@ADDED_WHO VARCHAR(50),
|
||
@OBJEKTTYP VARCHAR(50),
|
||
@GUID INTEGER
|
||
SELECT
|
||
@GUID = GUID,
|
||
@ADDED_WHO = ERSTELLTWER,
|
||
@OBJEKTTYP = OBJEKTTYP
|
||
FROM INSERTED
|
||
IF OBJECT_ID(N'dbo.TBPMO_CLIENT_DOCTYPE', N'U') IS NOT NULL
|
||
INSERT INTO TBPMO_CLIENT_DOCTYPE (CLIENT_ID,DOCTYPE_ID)
|
||
SELECT T.CLIENT_ID,@GUID FROM TBDD_CLIENT_USER T, TBDD_USER T1 WHERE T.USER_ID = T1.GUID AND UPPER(T1.USERNAME) = UPPER(@ADDED_WHO)
|
||
|
||
IF OBJECT_ID(N'dbo.TBPMO_WD_OBJECTTYPE', N'U') IS NOT NULL
|
||
IF @OBJEKTTYP IS NOT NULL
|
||
IF @OBJEKTTYP <> ''
|
||
BEGIN
|
||
DECLARE @IDX_DOC VARCHAR(50),@IDX_REC VARCHAR(50)
|
||
SELECT @IDX_DOC = IDXNAME_DOCTYPE,
|
||
@IDX_REC = IDXNAME_RECORDID FROM TBPMO_WD_OBJECTTYPE WHERE OBJECT_TYPE = @OBJEKTTYP
|
||
IF @IDX_REC IS NOT NULL
|
||
INSERT INTO TBDD_INDEX_AUTOM (DOCTYPE_ID,INDEXNAME,VALUE,ACTIVE,ADDED_WHO) VALUES
|
||
(@GUID,@IDX_REC,'@Record-ID',1,@ADDED_WHO)
|
||
IF @IDX_DOC IS NOT NULL
|
||
INSERT INTO TBDD_INDEX_AUTOM (DOCTYPE_ID,INDEXNAME,VALUE,ACTIVE,ADDED_WHO) VALUES
|
||
(@GUID,@IDX_DOC,'@Dokart',1,@ADDED_WHO)
|
||
END
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'ERROR IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE())
|
||
+ ' - ERROR-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
END CATCH
|
||
GO
|
||
|
||
CREATE TABLE TBDD_DOKUMENTART_MODULE
|
||
(
|
||
GUID INT IDENTITY(1,1),
|
||
DOKART_ID INT NOT NULL,
|
||
MODULE_ID INT NOT NULL,
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'Digital Data' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PKTBDD_DOKART_MODULE PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBDD_DOKART_MODULE_DOKART_ID FOREIGN KEY(DOKART_ID) REFERENCES TBDD_DOKUMENTART(GUID),
|
||
CONSTRAINT FK_TBDD_DOKART_MODULE_MODULE_ID FOREIGN KEY(MODULE_ID) REFERENCES TBDD_MODULES(GUID),
|
||
)
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
|
||
CREATE TRIGGER TBDD_DOKUMENTART_MODULE_AFT_UPD ON TBDD_DOKUMENTART_MODULE
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBDD_DOKUMENTART_MODULE SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_DOKUMENTART_MODULE.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
CREATE TABLE TBDD_USER_DOKTYPE
|
||
(
|
||
GUID INT IDENTITY(10000,1),
|
||
DOCTYPE_ID INT NOT NULL,
|
||
USER_ID INT NOT NULL,
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'Digital Data' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PKTBDD_USER_DOKTYPE PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBDD_USER_DOKTYPE_DTID FOREIGN KEY(DOCTYPE_ID) REFERENCES TBDD_DOKUMENTART(GUID),
|
||
CONSTRAINT FK_TBDD_USER_DOKTYPE_USRID FOREIGN KEY(USER_ID) REFERENCES TBDD_USER(GUID),
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBDD_USER_DOKTYPE_AFT_UPD ON TBDD_USER_DOKTYPE
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBDD_USER_DOKTYPE SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_USER_DOKTYPE.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
CREATE TABLE TBDD_INDEX_MAN
|
||
(
|
||
GUID INT IDENTITY(1,1),
|
||
DOK_ID INT NOT NULL,
|
||
NAME VARCHAR(50) NOT NULL,
|
||
WD_INDEX VARCHAR(50),
|
||
--SAVE_VALUE BIT NOT NULL DEFAULT 0,
|
||
COMMENT VARCHAR(150),
|
||
DATATYPE VARCHAR(50),
|
||
SUGGESTION BIT DEFAULT 0 NOT NULL, -- 1 - Es wird Eingabe vorgeschlagen, bei 0 - manuelle Eingabe.
|
||
DEFAULT_VALUE VARCHAR(50) NOT NULL DEFAULT '',
|
||
CONNECTION_ID SMALLINT DEFAULT 0,
|
||
SEQUENCE INTEGER NOT NULL DEFAULT 1,
|
||
SQL_RESULT VARCHAR(2000) NOT NULL DEFAULT '',
|
||
SQL_CHECK VARCHAR(2000) NOT NULL DEFAULT '',
|
||
OPTIONAL BIT DEFAULT 0 NOT NULL,
|
||
SAVE_VALUE BIT DEFAULT 0 NOT NULL,
|
||
VKT_ADD_ITEM BIT NOT NULL DEFAULT 0,
|
||
VKT_PREVENT_MULTIPLE_VALUES BIT NOT NULL DEFAULT 0,
|
||
MULTISELECT BIT NOT NULL DEFAULT 0,
|
||
ACTIVE BIT DEFAULT 1 NOT NULL, -- 1 - Index aktiv, bei 0 - inaktiv.
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DD_ECM DEFAULT' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE() ,
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_INDEX_MAN PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBDD_INDEX_MAN_DAID FOREIGN KEY(DOK_ID) REFERENCES TBDD_DOKUMENTART(GUID),
|
||
CONSTRAINT FK_TBDD_INDEX_MAN_CID FOREIGN KEY(CONNECTION_ID) REFERENCES TBDD_CONNECTION(GUID)
|
||
)
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
CREATE TRIGGER TBINDEX_MAN_AFT_UPD ON TBDD_INDEX_MAN
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBDD_INDEX_MAN SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_INDEX_MAN.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
|
||
CREATE TABLE TBDD_INDEX_AUTOM
|
||
(
|
||
GUID INT IDENTITY(1,1),
|
||
DOCTYPE_ID INT NOT NULL,
|
||
[ENTITY_ID] INTEGER DEFAULT 0 NOT NULL,
|
||
INDEXNAME VARCHAR(50) NOT NULL,
|
||
[VALUE] VARCHAR(2000),
|
||
CONNECTION_ID SMALLINT NOT NULL DEFAULT 0,
|
||
[SQL_RESULT] VARCHAR(2000) DEFAULT '' NOT NULL,
|
||
SQL_ACTIVE BIT DEFAULT 0 NOT NULL,
|
||
VKT_PREVENT_MULTIPLE_VALUES BIT DEFAULT 0,
|
||
VKT_OVERWRITE BIT DEFAULT 0,
|
||
COMMENT VARCHAR(400),
|
||
ACTIVE BIT DEFAULT 1 NOT NULL, -- 1 - Index aktiv, bei 0 - inaktiv.
|
||
SEQUENCE INT DEFAULT 1 NOT NULL,
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DEFAULT' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE() ,
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_INDEX_AUTOM PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBDD_INDEX_AUTOM_DOCID FOREIGN KEY(DOCTYPE_ID) REFERENCES TBDD_DOKUMENTART(GUID)
|
||
)
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
|
||
CREATE TRIGGER TBDD_INDEX_AUTOM_AFT_UPD ON TBDD_INDEX_AUTOM
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBDD_INDEX_AUTOM SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_INDEX_AUTOM.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
|
||
|
||
CREATE TABLE TBDD_INDEX_MAN_POSTPROCESSING
|
||
(
|
||
GUID INT IDENTITY(1,1),
|
||
IDXMAN_ID INT NOT NULL,
|
||
VARIANT VARCHAR(20) NOT NULL DEFAULT 'FILE AND INDEX',
|
||
COMMENT VARCHAR(250),
|
||
[TYPE] VARCHAR(50), -- Beschreibt intern welche Funktion genutzt wird:SPLIT,REPLACE
|
||
FUNCTION1 VARCHAR(250), -- Funktionen wie RegexExpressions
|
||
FUNCTION2 VARCHAR(250), -- Funktionen wie RegexExpressions
|
||
TEXT1 VARCHAR(100), -- Option1 zB: Replace1
|
||
TEXT2 VARCHAR(100), -- Option2 zB: Replace_with
|
||
TEXT3 VARCHAR(100), -- Option2
|
||
SEQUENCE INT NOT NULL DEFAULT 1,
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'Digital Data' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PKTBDD_INDEX_MAN_POSTPROCESSING PRIMARY KEY(GUID),
|
||
CONSTRAINT FKTBDD_INDEX_MAN_POSTPROCESSING_IDXID FOREIGN KEY(IDXMAN_ID) REFERENCES TBDD_INDEX_MAN(GUID)
|
||
)
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
|
||
CREATE TRIGGER TBDD_INDEX_MAN_POSTPROCESSING_AFT_UPD ON TBDD_INDEX_MAN_POSTPROCESSING
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBDD_INDEX_MAN_POSTPROCESSING SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED WHERE TBDD_INDEX_MAN_POSTPROCESSING.GUID = INSERTED.GUID
|
||
GO
|
||
CREATE TABLE TBDD_EMAIL_ACCOUNT
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
NAME VARCHAR(50),
|
||
EMAIL_NAME VARCHAR(100) DEFAULT '',
|
||
EMAIL_FROM VARCHAR(100) NOT NULL,
|
||
EMAIL_FROM_NAME VARCHAR(100) DEFAULT '',
|
||
EMAIL_SMTP VARCHAR(100) NOT NULL,
|
||
EMAIL_USER VARCHAR(100) NOT NULL,
|
||
EMAIL_PW VARCHAR(250) NOT NULL DEFAULT '',
|
||
AUTH_TYPE VARCHAR(20) NOT NULL DEFAULT 'SSL',
|
||
SSL_AUTH BIT NOT NULL DEFAULT 0,
|
||
PORT INTEGER NOT NULL DEFAULT '25',
|
||
PORT_IN INT NOT NULL DEFAULT 25,
|
||
ACTIVE BIT NOT NULL DEFAULT 1,
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_EMAIL_ACCOUNT PRIMARY KEY (GUID)
|
||
)
|
||
GO
|
||
|
||
CREATE TRIGGER TBDD_EMAIL_ACCOUNT_AFT_UPD ON TBDD_EMAIL_ACCOUNT
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBDD_EMAIL_ACCOUNT SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_EMAIL_ACCOUNT.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
|
||
CREATE TABLE TBDD_USER_LOGIN_OUT(
|
||
GUID INT IDENTITY(1,1) NOT NULL,
|
||
CONNECTION_STRING VARCHAR(500) NOT NULL DEFAULT '',
|
||
CLIENT_ID INT NOT NULL,
|
||
MACHINE_NAME VARCHAR(250) NOT NULL DEFAULT '',
|
||
MODULE VARCHAR(30) NOT NULL,
|
||
[USER_ID] INT NOT NULL,
|
||
VERSION_CLIENT VARCHAR(30),
|
||
[LOGIN] DATETIME DEFAULT (GETDATE()),
|
||
[LOGOUT] DATETIME,
|
||
CONSTRAINT [PK_TBDD_USER_LOGIN_OUT] PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBDD_USER_LOGIN_OUT_USER_ID FOREIGN KEY ([USER_ID]) REFERENCES TBDD_USER (GUID))
|
||
GO
|
||
CREATE TABLE TBDD_USRGRP_DOKTYPE
|
||
(
|
||
GUID INT IDENTITY(100,1),
|
||
DOCTYPE_ID INT NOT NULL,
|
||
GROUP_ID INT NOT NULL,
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'Digital Data' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PKTBDD_USRGRP_DOKTYPE PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBDD_USRGRP_DOKTYPE_DOCTYPE_ID FOREIGN KEY(DOCTYPE_ID) REFERENCES TBDD_DOKUMENTART(GUID),
|
||
CONSTRAINT FK_TBDD_USRGRP_DOKTYPE_GROUP_ID FOREIGN KEY(GROUP_ID) REFERENCES TBDD_GROUPS(GUID),
|
||
)
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
|
||
CREATE TRIGGER TBDD_USRGRP_DOKTYPE_AFT_UPD ON TBDD_USRGRP_DOKTYPE
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBDD_USRGRP_DOKTYPE SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_USRGRP_DOKTYPE.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
|
||
CREATE TABLE TBDD_LICENSE_ADD_ON(
|
||
[GUID] INT IDENTITY(1,1) NOT NULL,
|
||
[CLIENT_ID] INT NOT NULL,
|
||
[MODULE] VARCHAR(100) NOT NULL,
|
||
[NAME] VARCHAR(100) NOT NULL,
|
||
[VALID_DATE] VARCHAR(2000) NOT NULL,
|
||
[ADDED_WHO] VARCHAR(50) NOT NULL DEFAULT ('DEFAULT'),
|
||
[ADDED_WHEN] DATETIME DEFAULT (getdate()),
|
||
[CHANGED_WHO] VARCHAR(50),
|
||
[CHANGED_WHEN] DATETIME
|
||
CONSTRAINT [PK_TBDD_LICENSE_ADD_ON] PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBDD_LICENSE_ADD_ON_CLIENT_ID FOREIGN KEY ([CLIENT_ID]) REFERENCES TBDD_CLIENT (GUID))
|
||
GO
|
||
--INSERT INTO TBDD_LICENSE_ADD_ON (CLIENT_ID, MODULE, NAME, VALID_DATE) VALUES (0,'Record-Organizer', 'Proxy-Server', '+bk8oAbbQP1AzoHtvZUbd+Mbok2f8Fl4miEx1qssJ5yEaEWoQJ9prg4L14fURpPncZwT1S0JUXDWEzuCTBqgpd20QM74AAN6')
|
||
--GO
|
||
--INSERT INTO TBDD_LICENSE_ADD_ON (CLIENT_ID, MODULE, NAME, VALID_DATE) VALUES (1,'Record-Organizer', 'Site-AddOn', '+bk8oAbbQP1AzoHtvZUbd+Mbok2f8Fl4miEx1qssJ5yEaEWoQJ9prg4L14fURpPncZwT1S0JUXDWEzuCTBqgpd20QM74AAN6')
|
||
--GO
|
||
|
||
-- END CREATE TABLES
|
||
CREATE TABLE TBDD_EMAIL_TEMPLATE
|
||
(
|
||
GUID INTEGER NOT NULL IDENTITY (1, 1),
|
||
TITLE VARCHAR(100) NOT NULL,
|
||
EMAIL_SUBJECT VARCHAR(900) NOT NULL,
|
||
EMAIL_BODY1 VARCHAR(MAX) NOT NULL,
|
||
EMAIL_BODY2 VARCHAR(MAX) NOT NULL DEFAULT '',
|
||
EMAIL_BODY3 VARCHAR(MAX) NOT NULL DEFAULT '',
|
||
[LANGUAGE] VARCHAR(5) NOT NULL DEFAULT 'de-DE',
|
||
CONNECTED_TEMPLATE INTEGER NOT NULL DEFAULT 0,
|
||
ADDED_WHO VARCHAR(30) NOT NULL DEFAULT 'Digital Data',
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT (GETDATE()),
|
||
CHANGED_WHO VARCHAR(30),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBCUST_EMAIL_TEMPLATE PRIMARY KEY (GUID),
|
||
CONSTRAINT UQ_TBCUST_EMAIL_TEMPLATE_TITLE UNIQUE (TITLE)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBCUST_EMAIL_TEMPLATE_AFT_UPD ON [dbo].[TBDD_EMAIL_TEMPLATE]
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBDD_EMAIL_TEMPLATE SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_EMAIL_TEMPLATE.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
CREATE TABLE TBDD_SQL_COMMANDS
|
||
(
|
||
GUID INTEGER NOT NULL IDENTITY (1, 1),
|
||
TITLE VARCHAR(100) NOT NULL,
|
||
SQL_COMMAND VARCHAR(MAX) NOT NULL,
|
||
ADDED_WHO VARCHAR(30) NOT NULL DEFAULT 'Digital Data',
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT (GETDATE()),
|
||
CHANGED_WHO VARCHAR(30),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_SQL_COMMANDS PRIMARY KEY (GUID),
|
||
CONSTRAINT UQ_TBDD_SQL_COMMANDS UNIQUE (TITLE)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBDD_SQL_COMMANDS_AFT_UPD ON [dbo].TBDD_SQL_COMMANDS
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBDD_SQL_COMMANDS SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_SQL_COMMANDS.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
INSERT INTO TBDD_SQL_COMMANDS (TITLE,SQL_COMMAND) VALUES ('PM_IDB_DOC_DATA',
|
||
'select * from IDB.dbo.VWIDB_DOC_DATA T, TBPM_PROFILE_FILES T1 WHERE T.IDB_OBJ_ID = T1.DOC_ID AND T1.GUID = @DOC_GUID')
|
||
GO
|
||
INSERT INTO TBDD_SQL_COMMANDS (TITLE,SQL_COMMAND) VALUES ('GHOST_SELECT','
|
||
SELECT T.USERNAME,T.NAME, T.[PRENAME],T.EMAIL FROM TBDD_USER T ORDER BY USERNAME')
|
||
GO
|
||
INSERT INTO TBDD_SQL_COMMANDS (TITLE,SQL_COMMAND) VALUES
|
||
('VWDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE_ITEMS','
|
||
SELECT * FROM [dbo].[FNDD_ZUGFERD_VIEW_RECEIPT_CUST_RESULT] (''@MSG_ID'') ORDER BY ORDER_SEQ')
|
||
GO
|
||
CREATE TABLE TBDD_GUI_LANGUAGE_PHRASE
|
||
(
|
||
GUID INTEGER NOT NULL IDENTITY (1, 1),
|
||
MODULE VARCHAR(50) NOT NULL,
|
||
INTERNAL BIT NOT NULL DEFAULT 0,
|
||
OBJ_NAME VARCHAR(100) NOT NULL,
|
||
TITLE VARCHAR(100) NOT NULL,
|
||
[LANGUAGE] VARCHAR(5) NOT NULL,
|
||
CAPT_TYPE VARCHAR(50) NOT NULL,
|
||
STRING1 VARCHAR(900) NOT NULL,
|
||
STRING2 VARCHAR(900) NOT NULL,
|
||
STRING3 VARCHAR(900) ,
|
||
STRING4 VARCHAR(900),
|
||
STRING5 VARCHAR(900),
|
||
STRING6 VARCHAR(900),
|
||
ACTIVE BIT NOT NULL DEFAULT 1,
|
||
ADDED_WHO VARCHAR(30) NOT NULL DEFAULT 'Digital Data',
|
||
ADDED_WHEN DATETIME DEFAULT (GETDATE()),
|
||
CHANGED_WHO VARCHAR(30),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_GUI_LANGUAGE_PHRASE PRIMARY KEY (GUID),
|
||
CONSTRAINT UQ_TBDD_GUI_LANGUAGE_PHRASE UNIQUE (MODULE,OBJ_NAME,TITLE,[LANGUAGE])
|
||
)
|
||
GO
|
||
|
||
CREATE TRIGGER TBDD_GUI_LANGUAGE_PHRASE_AFT_UPD ON [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBDD_GUI_LANGUAGE_PHRASE SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_GUI_LANGUAGE_PHRASE.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
(OBJ_NAME,[MODULE],[TITLE],[LANGUAGE],[CAPT_TYPE],[STRING1],STRING2)
|
||
VALUES('frmValidator','PM','frmValidator.MissingInput','de-DE','Information','Bitte validieren Sie die rot markierten Felder!','')
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
(OBJ_NAME,[MODULE],[TITLE],[LANGUAGE],[CAPT_TYPE],[STRING1],STRING2)
|
||
VALUES('frmValidator','PM','frmValidator.MissingInput','en-US','Information','Please validate red marked fields!','')
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
(OBJ_NAME,[MODULE],[TITLE],[LANGUAGE],[CAPT_TYPE],[STRING1],STRING2)
|
||
VALUES('frmValidator','PM','frmValidator.ValidationButton','de-DE','Button','Validierung speichern - N<>chstes Dokument (F2)','')
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
(OBJ_NAME,[MODULE],[TITLE],[LANGUAGE],[CAPT_TYPE],[STRING1],STRING2)
|
||
VALUES('frmValidator','PM','frmValidator.ValidationButton','en-US','Button','Save validation - Next document (F2)','')
|
||
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
(OBJ_NAME,[MODULE],[TITLE],[LANGUAGE],[CAPT_TYPE],[STRING1],STRING2)
|
||
VALUES('frmValidator','PM','frmValidator.NoMoreDocument','de-DE','MsgBox','No more document! End of profile!','')
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
(OBJ_NAME,[MODULE],[TITLE],[LANGUAGE],[CAPT_TYPE],[STRING1],STRING2)
|
||
VALUES('frmValidator','PM','frmValidator.NoMoreDocument','en-US','MsgBox','Kein weiteres Dokuemnt gefunden - Ende des Profils!','Hinweis')
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
(OBJ_NAME,[MODULE],[TITLE],[LANGUAGE],[CAPT_TYPE],[STRING1],STRING2)
|
||
VALUES('frmValidator','PM','frmValidator.WrongInputControl','de-DE','Information','Falsche Eingabe','')
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
(OBJ_NAME,[MODULE],[TITLE],[LANGUAGE],[CAPT_TYPE],[STRING1],STRING2)
|
||
VALUES('frmValidator','PM','frmValidator.WrongInputControl','en-US','Information','Wrong input','')
|
||
GO
|
||
CREATE TABLE TBDD_GUI_LANGUAGE
|
||
(
|
||
GUID INTEGER NOT NULL IDENTITY(1,1),
|
||
LANG_CODE VARCHAR(5) NOT NULL,
|
||
IS_DEFAULT BIT NOT NULL DEFAULT 0,
|
||
ADDED_WHO VARCHAR(50) NOT NULL DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT GETDATE(),
|
||
ACTIVE BIT NOT NULL DEFAULT 0,
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME
|
||
CONSTRAINT PK_TBDD_GUI_LANGUAGE PRIMARY KEY (GUID)
|
||
)
|
||
GO
|
||
INSERT INTO TBDD_GUI_LANGUAGE (LANG_CODE,IS_DEFAULT,ACTIVE) VALUES ('de-DE',1,1);
|
||
INSERT INTO TBDD_GUI_LANGUAGE (LANG_CODE) VALUES ('en-US');
|
||
INSERT INTO TBDD_GUI_LANGUAGE (LANG_CODE) VALUES ('fr-FR');
|
||
GO
|
||
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE]
|
||
,[TITLE]
|
||
,[LANGUAGE]
|
||
,[CAPT_TYPE]
|
||
,[STRING1]
|
||
,[STRING2]
|
||
,[ADDED_WHO]
|
||
,[OBJ_NAME]
|
||
,[INTERNAL])
|
||
VALUES
|
||
('All Modules'
|
||
,'No Userconfig'
|
||
,'de-DE'
|
||
,'Information'
|
||
,'Achtung: Sie sind nicht in der Userverwaltung hinterlegt!'
|
||
,'Bitte setzen Sie sich mit dem Systembetreuer in Verbindung!'
|
||
,'SYSTEM'
|
||
,'General'
|
||
,1)
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE]
|
||
,[TITLE]
|
||
,[LANGUAGE]
|
||
,[CAPT_TYPE]
|
||
,[STRING1]
|
||
,[STRING2]
|
||
,[ADDED_WHO]
|
||
,[OBJ_NAME]
|
||
,[INTERNAL])
|
||
VALUES
|
||
('All Modules'
|
||
,'No Userconfig'
|
||
,'en-US'
|
||
,'Information'
|
||
,'Achtung: Sie sind nicht in der Userverwaltung hinterlegt!'
|
||
,'Bitte setzen Sie sich mit dem Systembetreuer in Verbindung!'
|
||
,'SYSTEM'
|
||
,'General'
|
||
,1)
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE]
|
||
,[TITLE]
|
||
,[LANGUAGE]
|
||
,[CAPT_TYPE]
|
||
,[STRING1]
|
||
,[STRING2]
|
||
,[ADDED_WHO]
|
||
,[OBJ_NAME]
|
||
,[INTERNAL])
|
||
VALUES
|
||
('All Modules'
|
||
,'No Client relation'
|
||
,'de-DE'
|
||
,'Information'
|
||
,'You are not related to a client!'
|
||
,'Please contact the system administrator!!'
|
||
,'SYSTEM'
|
||
,'General'
|
||
,1)
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE]
|
||
,[TITLE]
|
||
,[LANGUAGE]
|
||
,[CAPT_TYPE]
|
||
,[STRING1]
|
||
,[STRING2]
|
||
,[ADDED_WHO]
|
||
,[OBJ_NAME]
|
||
,[INTERNAL])
|
||
VALUES
|
||
('All Modules'
|
||
,'No Client relation'
|
||
,'en-US'
|
||
,'Information'
|
||
,'You are not related to a client!'
|
||
,'Please contact the system administrator!!'
|
||
,'SYSTEM'
|
||
,'General'
|
||
,1)
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE]
|
||
,[TITLE]
|
||
,[LANGUAGE]
|
||
,[CAPT_TYPE]
|
||
,[STRING1]
|
||
,[STRING2]
|
||
,[ADDED_WHO]
|
||
,[OBJ_NAME]
|
||
,[INTERNAL])
|
||
VALUES
|
||
('All Modules'
|
||
,'No Module Configuration'
|
||
,'de-DE'
|
||
,'Information'
|
||
,'Achtung: Sie sind nicht f<>r die Nutzung von ProcessManager freigegeben!'
|
||
,'Bitte setzen Sie sich mit dem Systembetreuer in Verbindung!!'
|
||
,'SYSTEM'
|
||
,'General'
|
||
,1)
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE]
|
||
,[TITLE]
|
||
,[LANGUAGE]
|
||
,[CAPT_TYPE]
|
||
,[STRING1]
|
||
,[STRING2]
|
||
,[ADDED_WHO]
|
||
,[OBJ_NAME]
|
||
,[INTERNAL])
|
||
VALUES
|
||
('All Modules'
|
||
,'No Module Configuration'
|
||
,'en-US'
|
||
,'Information'
|
||
,'Achtung: Sie sind nicht f<>r die Nutzung von ProcessManager freigegeben!'
|
||
,'Bitte setzen Sie sich mit dem Systembetreuer in Verbindung!!'
|
||
,'SYSTEM'
|
||
,'General'
|
||
,1)
|
||
GO
|
||
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
(OBJ_NAME,[MODULE],[TITLE],[LANGUAGE],[CAPT_TYPE],[STRING1],STRING2,INTERNAL)
|
||
VALUES('Application','PM','App.ReminderPipeline','de-DE','Information','Es befinden sich noch unerledigte Aufgaben in Ihrem Verantwortungsbereich','',1);
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
(OBJ_NAME,[MODULE],[TITLE],[LANGUAGE],[CAPT_TYPE],[STRING1],STRING2,INTERNAL)
|
||
VALUES('Application','PM','App.ReminderPipeline','en-US','Information','There are some tasks in your responsibility!','',1);
|
||
GO
|
||
Insert Into TBDD_GUI_LANGUAGE_PHRASE (MODULE,TITLE,LANGUAGE,CAPT_TYPE,STRING1,STRING2,OBJ_NAME) VALUES ('PM','frmValidator.Conversation_Delete','de-DE','MsgboxResult','Wollen Sie die Konversation beenden?','Nachfrage','frmValidator');
|
||
Insert Into TBDD_GUI_LANGUAGE_PHRASE (MODULE,TITLE,LANGUAGE,CAPT_TYPE,STRING1,STRING2,OBJ_NAME) VALUES ('PM','frmValidator.Conversation_Delete','en-US','MsgboxResult','Would You like to end this conversation?','Question','frmValidator');
|
||
GO
|
||
CREATE TABLE [dbo].[TBDD_MONITORING_RESULT](
|
||
[USR_ID] INTEGER NULL,
|
||
[GUID] INTEGER NULL,
|
||
[PARENT_ID] INTEGER NULL,
|
||
[STATE] VARCHAR(100) DEFAULT 'DEFAULT',
|
||
[ICON] VARCHAR(100) NULL,
|
||
[COLUMN1] VARCHAR(500) NULL,
|
||
[COLUMN2] VARCHAR(500) NULL,
|
||
[COLUMN3] VARCHAR(500) NULL,
|
||
[ADDED_WHEN] DATETIME NULL,
|
||
[SELECT1] NVARCHAR(max) NULL,
|
||
[SELECT2] NVARCHAR(max) NULL,
|
||
[SELECT3] NVARCHAR(max) NULL,
|
||
[SELECT4] NVARCHAR(max) NULL,
|
||
[DOCVIEW1] NVARCHAR(512) NULL,
|
||
[DOCVIEW2] NVARCHAR(512) NULL,
|
||
[HTML1] NVARCHAR(max) NULL,
|
||
[HTML2] NVARCHAR(max) NULL
|
||
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
|
||
|
||
GO
|
||
CREATE TABLE TBDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE
|
||
(
|
||
GUID INT IDENTITY(1,1),
|
||
SPECNAME VARCHAR(100) NOT NULL,
|
||
Row_Caption VARCHAR(250) NOT NULL,
|
||
Area VARCHAR(100) NOT NULL,
|
||
xPosition INTEGER NOT NULL DEFAULT 10,
|
||
--yPosition INTEGER NOT NULL,
|
||
SequenceItem INTEGER NOT NULL DEFAULT 1,
|
||
Y_eq_lastrow BIT NOT NULL DEFAULT 0,
|
||
Display BIT NOT NULL DEFAULT 1,
|
||
Active BIT NOT NULL DEFAULT 1,
|
||
AddedWho VARCHAR(50) DEFAULT 'DD_ECM DEFAULT' NOT NULL,
|
||
AddedWhen DATETIME DEFAULT GETDATE(),
|
||
ChangedWho VARCHAR(50),
|
||
ChangedWhen DATETIME,
|
||
CONSTRAINT PK_TBDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE PRIMARY KEY (GUID),
|
||
CONSTRAINT UNIQUE_TBDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE UNIQUE(SPECNAME)
|
||
)
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
|
||
CREATE TRIGGER TBDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE_AFT_UPD ON TBDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE SET ChangedWhen = GETDATE() FROM INSERTED WHERE TBDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE.GUID = INSERTED.GUID
|
||
GO
|
||
|
||
SET ANSI_NULLS ON
|
||
GO
|
||
|
||
SET QUOTED_IDENTIFIER ON
|
||
GO
|
||
CREATE TABLE [dbo].[TBEDMI_ITEM_VALUE](
|
||
[GUID] [bigint] IDENTITY(1,1) NOT NULL,
|
||
[REFERENCE_GUID] NVARCHAR(max) NOT NULL,
|
||
[ITEM_DESCRIPTION] NVARCHAR(max) NOT NULL,
|
||
[ITEM_VALUE] NVARCHAR(max) NULL,
|
||
[CREATEDWHEN] DATETIME NOT NULL,
|
||
[CREATEDWHO] NVARCHAR(max) NULL,
|
||
[CHANGEDWHEN] DATETIME NULL,
|
||
[GROUP_COUNTER] [int] NULL,
|
||
[SPEC_NAME] [varchar](250) NULL,
|
||
[IS_REQUIRED] BIT NOT NULL
|
||
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
|
||
GO
|
||
|
||
ALTER TABLE [dbo].[TBEDMI_ITEM_VALUE] ADD DEFAULT (getdate()) FOR [CREATEDWHEN]
|
||
GO
|
||
|
||
ALTER TABLE [dbo].[TBEDMI_ITEM_VALUE] ADD DEFAULT ((0)) FOR [IS_REQUIRED]
|
||
GO
|
||
|
||
|
||
|
||
--PROCEDURES
|
||
|
||
-- 20.09.2024 MS @MODULE_SHORT eingesetzt
|
||
CREATE OR ALTER PROCEDURE [dbo].[PRDD_CHECK_REL_DOCTYPE_MODULE] (@MODULE_SHORT VARCHAR(20),@DOCTYPE_ID INTEGER)
|
||
AS
|
||
DECLARE @MODULEID INTEGER
|
||
SELECT @MODULEID = GUID FROM TBDD_MODULES WHERE SHORT_NAME = @MODULE_SHORT
|
||
GO
|
||
CREATE PROCEDURE [dbo].[PRDD_MONITORING_GET_TREEVIEW_RESULT] @TYPE VARCHAR(100),@PARAM1 NVARCHAR(500),@PARAM2 NVARCHAR(500),@PARAM3 NVARCHAR(500),@USR_ID INTEGER
|
||
AS
|
||
BEGIN
|
||
DECLARE @TBResult TABLE (
|
||
GUID INTEGER,
|
||
PARENT_ID INTEGER,
|
||
--
|
||
-- STATE
|
||
-- Options: SUCCESS, FAILURE, WARNING, WAITING, DEFAULT
|
||
--
|
||
STATE VARCHAR(100) DEFAULT 'DEFAULT',
|
||
--
|
||
-- ICON
|
||
-- Options: MAIL, PDF, HTML
|
||
--
|
||
ICON VARCHAR(100),
|
||
COLUMN1 VARCHAR(500),
|
||
COLUMN2 VARCHAR(500),
|
||
COLUMN3 VARCHAR(500),
|
||
ADDED_WHEN DATETIME,
|
||
SELECT1 NVARCHAR(MAX),
|
||
SELECT2 NVARCHAR(MAX),
|
||
SELECT3 NVARCHAR(MAX),
|
||
SELECT4 NVARCHAR(MAX),
|
||
DOCVIEW1 NVARCHAR(512),
|
||
DOCVIEW2 NVARCHAR(512),
|
||
HTML1 NVARCHAR(MAX),
|
||
HTML2 NVARCHAR(MAX)
|
||
)
|
||
|
||
INSERT INTO @TBResult (GUID,PARENT_ID,ADDED_WHEN,COLUMN1,STATE) VALUES (1,0,GETDATE()-10,'EMAIL-EINGANG','SUCCESS')
|
||
INSERT INTO @TBResult (GUID,PARENT_ID,COLUMN1,COLUMN2) VALUES (2,1,'Datum/Uhrzeit','2021-05-11 07:28:25')
|
||
INSERT INTO @TBResult (GUID,PARENT_ID,COLUMN1,COLUMN2) VALUES (3,1,'Email-Versender','m.schreiber@digitaldata.works')
|
||
INSERT INTO @TBResult (GUID,PARENT_ID,COLUMN1,COLUMN2) VALUES (4,1,'Betreff','Das Subject aus der Mail')
|
||
INSERT INTO @TBResult (GUID,PARENT_ID,ADDED_WHEN,COLUMN1,STATE) VALUES (5,0,GETDATE()-8,'ZUGFeRD-Parser gestartet','SUCCESS')
|
||
INSERT INTO @TBResult (GUID,PARENT_ID,ICON,COLUMN1,SELECT1) VALUES (6,5,'SQL','Click for Result','SELECT * FROM TBEDMI_ITEM_VALUE WHERE REFERENCE_GUID = ''350614162.18783.1593150528181@W2K8SRV0036030008840''|EDMI_ITEM_VALUE')
|
||
INSERT INTO @TBResult (GUID,PARENT_ID,ICON,COLUMN1,DOCVIEW1) VALUES (7,5,'MAIL','OriginalMail','\\Windream\Objects\SWE_157906_Neggers~4-21_01_28.msg|Original Email')
|
||
INSERT INTO @TBResult (GUID,PARENT_ID,ADDED_WHEN,COLUMN1,STATE) VALUES (8,5,GETDATE()-6,'Beleg Abgelehnt','WARNING')
|
||
INSERT INTO @TBResult (GUID,PARENT_ID,ICON,COLUMN1,HTML1) VALUES (9,8,'MAIL','Ablehnungsmail','<!DOCTYPE html><html><body style=''font-family:"Arial";font-size:10.0pt''">Sehr geehrte Damen und Herren,<br> das WISAG-Portal zur Verarbeitung der Eingangsrechnungen
|
||
im ZUGFeRD-Format konnte die von Ihnen gesandte Rechnung 5403008595 leider nicht verarbeiten! <br> Letzter Bearbeiter in unserem Hause: Melanie Leilich - Melanie.Leilich@wisag.de <p>
|
||
Ablehnung, da die Rechnung mit der Gutschrift 5403008596 verrechnet wird.<br> Letzter Bearbeiter in unserem Hause: Melanie Leilich<p>Bitte pr<70>fen Sie die Datei und nehmen Sie bei Bedarf mit uns Kontakt auf. <p>
|
||
Vielen Dank f<>r Ihr Verst<73>ndnis.<br>Mit freundlichen Gr<47><72>en<br>Ihre IT-Abteilung</body></html>|Ablehnungsmail')
|
||
INSERT INTO @TBResult (GUID,PARENT_ID,ADDED_WHEN,COLUMN1,STATE) VALUES (10,0,GETDATE()-5,'Finale Freigabe','SUCCESS')
|
||
INSERT INTO @TBResult (GUID,PARENT_ID,COLUMN1,COLUMN2) VALUES (11,10,'Finaler Freigaber','d.schipper')
|
||
INSERT INTO @TBResult (GUID,PARENT_ID,ADDED_WHEN,COLUMN1,STATE) VALUES (12,0,GETDATE()-5,'Ergebnisbericht erzeugt','SUCCESS')
|
||
INSERT INTO @TBResult (GUID,PARENT_ID,ICON,COLUMN1,DOCVIEW1) VALUES (13,12,'FILE','Ergebnisbericht','\\Windream\Objects\fileFLOW-Test\4-20_06_08~8.pdf|Ergebnisbericht')
|
||
INSERT INTO @TBResult (GUID,PARENT_ID,ADDED_WHEN,COLUMN1,STATE) VALUES (14,0,GETDATE()-4,'An SAP <20>bergeben','WAITING')
|
||
|
||
SELECT * FROM @TBResult
|
||
END
|
||
GO
|
||
|
||
CREATE TABLE TBDD_MONITORING_PROFILE(
|
||
GUID INTEGER NOT NULL IDENTITY(1,1),
|
||
TITLE VARCHAR(30) NOT NULL,
|
||
DESCRIPTION VARCHAR(100),
|
||
ACTIVE BIT NOT NULL DEFAULT 1,
|
||
SEQUENCE TINYINT NOT NULL DEFAULT 1,
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT GETDATE(),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT [PK_TBDD_MONITORING_PROFILE] PRIMARY KEY(GUID))
|
||
GO
|
||
|
||
CREATE TRIGGER [dbo].[TBDD_MONITORING_PROFILE_AFT_UPD] ON [dbo].[TBDD_MONITORING_PROFILE]
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBDD_MONITORING_PROFILE SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_MONITORING_PROFILE.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
CREATE TABLE TBDD_MONITORING_PROFILE_ATTRIBUTES(
|
||
GUID INTEGER NOT NULL IDENTITY(1,1),
|
||
MONITOR_PROFILE_ID INTEGER NOT NULL,
|
||
[CAPTION] VARCHAR(100) NOT NULL,
|
||
DESCRIPTION VARCHAR(100),
|
||
ACTIVE BIT NOT NULL DEFAULT 1,
|
||
SEQUENCE TINYINT NOT NULL DEFAULT 1,
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT GETDATE(),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT [PK_TBDD_MONITORING_PROFILE_ATTRIBUTES] PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBDD_MONITORING_PROF_ATTR_MPID FOREIGN KEY (MONITOR_PROFILE_ID) REFERENCES TBDD_MONITORING_PROFILE (GUID))
|
||
GO
|
||
|
||
CREATE TRIGGER [dbo].[TBDD_MONITORING_PROFILE_ATTRIBUTES_AFT_UPD] ON [dbo].TBDD_MONITORING_PROFILE_ATTRIBUTES
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBDD_MONITORING_PROFILE_ATTRIBUTES SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBDD_MONITORING_PROFILE_ATTRIBUTES.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
--############################################
|
||
--##########PROCEDURES########################
|
||
--############################################
|
||
|
||
CREATE PROCEDURE [dbo].[PRDD_DELETE_USER](@pUSER_ID INT)
|
||
AS
|
||
BEGIN TRY
|
||
-- COMMON
|
||
IF OBJECT_ID(N'dbo.TBDD_USER_MODULES', N'U') IS NOT NULL
|
||
DELETE FROM TBDD_USER_MODULES WHERE USER_ID = @pUSER_ID
|
||
IF OBJECT_ID(N'dbo.TBDD_CLIENT_USER', N'U') IS NOT NULL
|
||
DELETE FROM TBDD_CLIENT_USER WHERE USER_ID = @pUSER_ID
|
||
IF OBJECT_ID(N'dbo.TBDD_GROUPS_USER', N'U') IS NOT NULL
|
||
DELETE FROM TBDD_GROUPS_USER WHERE USER_ID = @pUSER_ID
|
||
IF OBJECT_ID(N'dbo.TBDD_VERSION_USER_UPDATE', N'U') IS NOT NULL
|
||
DELETE FROM TBDD_VERSION_USER_UPDATE WHERE USER_ID = @pUSER_ID
|
||
IF OBJECT_ID(N'dbo.TBDD_VERSION_USER_UPDATE_PATH', N'U') IS NOT NULL
|
||
DELETE FROM TBDD_VERSION_USER_UPDATE_PATH WHERE USER_ID = @pUSER_ID
|
||
IF OBJECT_ID(N'dbo.TBDD_USER_LOGIN_OUT', N'U') IS NOT NULL
|
||
DELETE FROM TBDD_USER_LOGIN_OUT WHERE USER_ID = @pUSER_ID
|
||
IF OBJECT_ID(N'dbo.TBDD_USER_MODULE_LOG_IN', N'U') IS NOT NULL
|
||
DELETE FROM TBDD_USER_MODULE_LOG_IN WHERE USER_ID = @pUSER_ID
|
||
|
||
-- PROCESS MANAGER
|
||
IF OBJECT_ID(N'dbo.TBPM_PROFILE_USER', N'U') IS NOT NULL
|
||
DELETE FROM TBPM_PROFILE_USER WHERE USER_ID = @pUSER_ID
|
||
IF OBJECT_ID(N'dbo.TBPMO_FOLDERWATCH_USER', N'U') IS NOT NULL
|
||
DELETE FROM TBPMO_FOLDERWATCH_USER WHERE USER_ID = @pUSER_ID
|
||
|
||
-- GLOBAL INDEXER
|
||
IF OBJECT_ID(N'dbo.TBGI_FOLDERWATCH_USER', N'U') IS NOT NULL
|
||
DELETE FROM TBGI_FOLDERWATCH_USER WHERE USER_ID = @pUSER_ID
|
||
IF OBJECT_ID(N'dbo.TBHOTKEY_USER_PROFILE', N'U') IS NOT NULL
|
||
DELETE FROM TBHOTKEY_USER_PROFILE WHERE USER_ID = @pUSER_ID
|
||
-- CLIPBOARD WATCHER
|
||
IF OBJECT_ID(N'dbo.TBCW_USER_PROFILE', N'U') IS NOT NULL
|
||
DELETE FROM TBCW_USER_PROFILE WHERE USER_ID = @pUSER_ID
|
||
|
||
--_ADDI
|
||
IF OBJECT_ID(N'dbo.TBPMO_CONSTRUCTOR_USER', N'U') IS NOT NULL
|
||
DELETE FROM TBPMO_CONSTRUCTOR_USER WHERE USER_ID = @pUSER_ID
|
||
IF OBJECT_ID(N'dbo.TBPMO_USER_CONSTR_VIEW_TYPE', N'U') IS NOT NULL
|
||
DELETE FROM TBPMO_USER_CONSTR_VIEW_TYPE WHERE USER_ID = @pUSER_ID
|
||
|
||
-- FINALLY
|
||
DELETE FROM TBDD_USER WHERE GUID = @pUSER_ID
|
||
|
||
RETURN 0
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'FEHLER IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE()) + ' - ZEILE: ' + CONVERT(VARCHAR(10),ERROR_LINE())
|
||
+ ' - FEHLER-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
RETURN -1
|
||
END CATCH
|
||
GO
|
||
|
||
|
||
CREATE TABLE TBDD_EXTATTRIBUTES_MATCHING
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
EXT_ATTRIBUTE VARCHAR(250),
|
||
TBDD_USER_COLUMN VARCHAR(150),
|
||
FB_SYS_KEY VARCHAR(150) DEFAULT ''
|
||
CONSTRAINT PK_TBAD_EXTATTRIBUTES_MATCHING_GUID PRIMARY KEY(GUID)
|
||
)
|
||
GO
|
||
CREATE TABLE TBDD_NOTIFICATIONS_SYSTEM
|
||
(
|
||
GUID INTEGER NOT NULL IDENTITY (1, 1),
|
||
TITLE VARCHAR(250) NOT NULL,
|
||
MODULE VARCHAR(250) NOT NULL,
|
||
DISPLAY_TYPE VARCHAR(100) NOT NULL,
|
||
MSG_STRING NVARCHAR(MAX) NOT NULL,
|
||
LANG_CODE VARCHAR(5) NOT NULL DEFAULT 'ALL',
|
||
DISPLAY_UNTIL DATE,
|
||
VALIDATE_READ BIT NOT NULL DEFAULT 0,
|
||
ADDED_WHO VARCHAR(100),
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(100),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_NOTIFICATIONS_SYSTEM PRIMARY KEY (GUID),
|
||
)
|
||
GO
|
||
CREATE TRIGGER TTBDD_NOTIFICATIONS_SYSTEM_AFT_UPD ON TBDD_NOTIFICATIONS_SYSTEM
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBDD_NOTIFICATIONS_SYSTEM SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBDD_NOTIFICATIONS_SYSTEM .GUID = INSERTED.GUID
|
||
GO
|
||
|
||
CREATE TABLE TBDD_NOTIFICATIONS_USER_HISTORY
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
NOTIFY_ID INT NOT NULL,
|
||
USR_ID INT NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CONSTRAINT PK_TBDD_NOTIFICATIONS_USER_HISTORY PRIMARY KEY (GUID),
|
||
CONSTRAINT FK_TBDD_NOTIFICATIONS_USER_HISTORY_NID FOREIGN KEY(NOTIFY_ID) REFERENCES TBDD_NOTIFICATIONS_SYSTEM(GUID),
|
||
)
|
||
GO
|
||
--###### VIEWS #####
|
||
CREATE VIEW VWDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE_ITEMS AS
|
||
SELECT
|
||
A.SPEC_NAME,
|
||
A.ITEM_VALUE,
|
||
B.Area,
|
||
B.Row_Caption,
|
||
B.xPosition,
|
||
B.Y_eq_lastrow,
|
||
B.SequenceItem,
|
||
B.Display,
|
||
A.REFERENCE_GUID
|
||
FROM
|
||
(SELECT * FROM TBEDMI_ITEM_VALUE ) A INNER JOIN
|
||
(SELECT * FROM TBDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE WHERE Active = 1) B ON A.SPEC_NAME = B.SPECNAME
|
||
GO
|
||
|
||
|
||
CREATE VIEW [dbo].[VWDD_CUST_USER_LAST30Days] as
|
||
SELECT DISTINCT USER_ID
|
||
--Count(USER_ID), MONTH()
|
||
FROM TBDD_USER_LOGIN_OUT WHERE UPPER(MODULE) = UPPER('Process-Manager') and DATEDIFF(DAY,LOGIN,GETDATE()) <= 90
|
||
GO
|
||
|
||
CREATE VIEW VWDD_LOGIN_USER_HISTORY AS
|
||
SELECT TOP (5000)
|
||
T.GUID,
|
||
T.MODULE,
|
||
T1.USERNAME,
|
||
T1.NAME,
|
||
T1.PRENAME,
|
||
T1.GUID as USER_ID,
|
||
T.CLIENT_ID,
|
||
T2.CLIENT_NAME,
|
||
T.LOGIN,
|
||
T.LOGOUT,
|
||
T.VERSION_CLIENT,
|
||
T.MACHINE_NAME
|
||
FROM
|
||
TBDD_USER_LOGIN_OUT T,
|
||
TBDD_USER T1,
|
||
TBDD_CLIENT T2
|
||
WHERE
|
||
T.USER_ID = T1.GUID
|
||
AND T.CLIENT_ID = T2.GUID
|
||
ORDER BY GUID DESC
|
||
GO
|
||
CREATE VIEW VWDD_USER2GROUP AS
|
||
SELECT TOP 100 PERCENT T.GUID, T.USERNAME, T2.GUID as GROUP_ID, T2.NAME, T2.COMMENT
|
||
FROM TBDD_USER T, TBDD_GROUPS_USER T1, TBDD_GROUPS T2
|
||
WHERE
|
||
T.GUID = T1.USER_ID AND
|
||
T1.GROUP_ID = T2.GUID
|
||
ORDER BY T.USERNAME
|
||
GO
|
||
CREATE VIEW VWDDINDEX_MAN
|
||
AS
|
||
SELECT TOP 2000
|
||
T.GUID,
|
||
T.NAME INDEXNAME,
|
||
T.WD_INDEX,
|
||
T.COMMENT,
|
||
T.DATATYPE,
|
||
T.DOK_ID,
|
||
T1.BEZEICHNUNG DOKUMENTART,
|
||
T1.KURZNAME,
|
||
T.SUGGESTION,
|
||
T.CONNECTION_ID,
|
||
T2.BEZEICHNUNG CONNECTION,
|
||
T2.SQL_PROVIDER,
|
||
T2.SERVER,
|
||
T2.DATENBANK,
|
||
T2.USERNAME,
|
||
T2.PASSWORD,
|
||
T.SQL_RESULT,
|
||
T.SQL_CHECK,
|
||
T.OPTIONAL,
|
||
T.SAVE_VALUE,
|
||
T.DEFAULT_VALUE,
|
||
T.MULTISELECT,
|
||
T.SEQUENCE
|
||
|
||
FROM
|
||
TBDD_INDEX_MAN T
|
||
INNER JOIN TBDD_DOKUMENTART T1 ON T.DOK_ID = T1.GUID AND T1.AKTIV = 1
|
||
LEFT JOIN TBDD_CONNECTION T2 ON T.CONNECTION_ID = T2.GUID AND T2.AKTIV = 1
|
||
WHERE
|
||
T.ACTIVE = 1
|
||
ORDER BY
|
||
T.DOK_ID,
|
||
T.GUID
|
||
GO
|
||
|
||
CREATE VIEW [dbo].[VWDDINDEX_AUTOM]
|
||
AS
|
||
SELECT TOP 100 PERCENT
|
||
T.GUID,
|
||
T.INDEXNAME,
|
||
T.COMMENT,
|
||
T.DOCTYPE_ID,
|
||
T1.BEZEICHNUNG DOKUMENTART,
|
||
T1.KURZNAME,
|
||
T.CONNECTION_ID,
|
||
T2.BEZEICHNUNG CONNECTION,
|
||
T2.SQL_PROVIDER,
|
||
T2.SERVER,
|
||
T2.DATENBANK,
|
||
T2.USERNAME,
|
||
T2.PASSWORD,
|
||
T.SQL_RESULT,
|
||
T.SQL_ACTIVE,
|
||
T.VALUE,
|
||
T.[SEQUENCE],
|
||
T.VKT_OVERWRITE,
|
||
T.VKT_PREVENT_MULTIPLE_VALUES
|
||
FROM
|
||
TBDD_INDEX_AUTOM T
|
||
INNER JOIN TBDD_DOKUMENTART T1 ON T.DOCTYPE_ID = T1.GUID AND T1.AKTIV = 1
|
||
LEFT JOIN TBDD_CONNECTION T2 ON T.CONNECTION_ID = T2.GUID AND T2.AKTIV = 1
|
||
WHERE
|
||
T.ACTIVE = 1
|
||
ORDER BY
|
||
T.DOCTYPE_ID,
|
||
T.GUID
|
||
|
||
GO
|
||
|
||
CREATE VIEW VWDDINDICES_MAN_AUTO_ACTIVE AS
|
||
SELECT TOP 100 PERCENT
|
||
DOK_ID AS DOCTYPE_ID,
|
||
'm' + NAME AS NAME
|
||
FROM TBDD_INDEX_MAN WHERE ACTIVE = 1
|
||
UNION
|
||
SELECT TOP 100 PERCENT
|
||
DOCTYPE_ID AS DOCTYPE_ID,
|
||
'a' + INDEXNAME AS NAME
|
||
FROM TBDD_INDEX_AUTOM WHERE ACTIVE = 1
|
||
ORDER BY
|
||
DOCTYPE_ID
|
||
GO
|
||
CREATE VIEW VWDD_USER_CLIENT
|
||
AS
|
||
SELECT
|
||
T1.GUID AS CLIENT_ID
|
||
,T1.CLIENT_NAME
|
||
,T.USER_ID
|
||
,T2.USERNAME
|
||
FROM
|
||
TBDD_CLIENT_USER T
|
||
,TBDD_CLIENT T1
|
||
,TBDD_USER T2
|
||
WHERE
|
||
T1.ACTIVE = 1
|
||
AND T.CLIENT_ID = T1.GUID
|
||
AND T.USER_ID = T2.GUID
|
||
|
||
GO
|
||
--####Functions
|
||
CREATE OR ALTER FUNCTION [dbo].[FNDD_ZUGFERD_VIEW_RECEIPT_TAX] (@pMSGID VARCHAR(100))
|
||
RETURNS @TABLE TABLE(SPEC_NAME VARCHAR(100),ITEM_VALUE VARCHAR(250),Area VARCHAR(60),Row_Caption Varchar(100), SequenceItem INT,Display BIT)
|
||
AS
|
||
BEGIN
|
||
DECLARE @GROUP_COUNTER INT,@INDEX INT = 402
|
||
DECLARE cursGroupCounter CURSOR FOR
|
||
select GROUP_COUNTER from TBEDMI_ITEM_VALUE WHERE REFERENCE_GUID = @pMSGID And SPEC_NAME = 'INVOICE_TAXPOS_RATE' ORDER BY GROUP_COUNTER
|
||
OPEN cursGroupCounter
|
||
FETCH NEXT FROM cursGroupCounter INTO @GROUP_COUNTER
|
||
WHILE @@FETCH_STATUS = 0
|
||
BEGIN
|
||
DECLARE @SPEC_NAME VARCHAR(100),@ITEM_VALUE VARCHAR(100),@Row_Caption VARCHAR(100),@Display BIT
|
||
DECLARE cursPosItems CURSOR FOR
|
||
select A.SPEC_NAME,ITEM_VALUE, B.Row_Caption, B.Display from TBEDMI_ITEM_VALUE A INNER JOIN TBDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE B ON A.SPEC_NAME = B.SPECNAME WHERE REFERENCE_GUID = @pMSGID And A.SPEC_NAME IN ('INVOICE_TAXPOS_AMOUNT',
|
||
'INVOICE_TAXPOS_RATE','INVOICE_TAXPOS_TYPE') AND GROUP_COUNTER = @GROUP_COUNTER ORDER BY B.SequenceItem
|
||
OPEN cursPosItems
|
||
FETCH NEXT FROM cursPosItems INTO @SPEC_NAME,@ITEM_VALUE,@Row_Caption,@Display
|
||
WHILE @@FETCH_STATUS = 0
|
||
BEGIN
|
||
SET @INDEX += 1
|
||
INSERT INTO @TABLE (SPEC_NAME,ITEM_VALUE,Area,Row_Caption,SequenceItem,Display) VALUES
|
||
(@SPEC_NAME,@ITEM_VALUE,'TAXPOS',@Row_Caption,@INDEX,@Display)
|
||
FETCH NEXT FROM cursPosItems INTO @SPEC_NAME,@ITEM_VALUE, @Row_Caption,@Display
|
||
END
|
||
CLOSE cursPosItems
|
||
DEALLOCATE cursPosItems
|
||
FETCH NEXT FROM cursGroupCounter INTO @GROUP_COUNTER
|
||
END
|
||
CLOSE cursGroupCounter
|
||
DEALLOCATE cursGroupCounter
|
||
RETURN
|
||
END
|
||
GO
|
||
|
||
--CHANGED 06.03.2025 INVOICE_POS_NOTE integriert
|
||
CREATE OR ALTER FUNCTION [dbo].[FNDD_ZUGFERD_VIEW_RECEIPT_POSITIONS] (@pMSGID VARCHAR(100))
|
||
RETURNS @TABLE TABLE(SPEC_NAME VARCHAR(100),ITEM_VALUE VARCHAR(250),Area VARCHAR(60),SequenceItem INT,Display BIT)
|
||
AS
|
||
BEGIN
|
||
DECLARE @GROUP_COUNTER INT,@INDEX INT = 15
|
||
DECLARE cursGroupCounter CURSOR FOR
|
||
select GROUP_COUNTER from TBEDMI_ITEM_VALUE WHERE REFERENCE_GUID = @pMSGID And SPEC_NAME = 'INVOICE_POSITION_AMOUNT' ORDER BY GROUP_COUNTER
|
||
OPEN cursGroupCounter
|
||
FETCH NEXT FROM cursGroupCounter INTO @GROUP_COUNTER
|
||
WHILE @@FETCH_STATUS = 0
|
||
BEGIN
|
||
DECLARE @SPEC_NAME VARCHAR(100),@ITEM_VALUE VARCHAR(100),@Display BIT
|
||
DECLARE cursPosItems CURSOR FOR
|
||
select A.SPEC_NAME,ITEM_VALUE,Display from TBEDMI_ITEM_VALUE A INNER JOIN TBDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE B ON A.SPEC_NAME = B.SPECNAME WHERE REFERENCE_GUID = @pMSGID And A.SPEC_NAME IN ('INVOICE_POSITION_AMOUNT',
|
||
'INVOICE_TAXPOS_TAX_RATE','INVOICE_POSITION_NOTE','INVOICE_POSITION_ARTICLE','INVOICE_POSITION_TAX_AMOUNT') AND GROUP_COUNTER = @GROUP_COUNTER ORDER BY B.SequenceItem
|
||
OPEN cursPosItems
|
||
FETCH NEXT FROM cursPosItems INTO @SPEC_NAME,@ITEM_VALUE,@Display
|
||
WHILE @@FETCH_STATUS = 0
|
||
BEGIN
|
||
SET @INDEX += 1
|
||
INSERT INTO @TABLE (SPEC_NAME,ITEM_VALUE,Area,SequenceItem,Display) VALUES
|
||
(@SPEC_NAME,@ITEM_VALUE,'POSITION',@INDEX,@Display)
|
||
FETCH NEXT FROM cursPosItems INTO @SPEC_NAME,@ITEM_VALUE,@Display
|
||
END
|
||
CLOSE cursPosItems
|
||
DEALLOCATE cursPosItems
|
||
FETCH NEXT FROM cursGroupCounter INTO @GROUP_COUNTER
|
||
END
|
||
CLOSE cursGroupCounter
|
||
DEALLOCATE cursGroupCounter
|
||
RETURN
|
||
END
|
||
GO
|
||
--CHANGED 06.03.2025 INVOICE_POS_NOTE integriert
|
||
CREATE OR ALTER FUNCTION [dbo].[FNDD_ZUGFERD_VIEW_RECEIPT_CUST_RESULT] (@pMSGID VARCHAR(100))
|
||
RETURNS TABLE
|
||
AS RETURN
|
||
(
|
||
SELECt A.SPEC_NAME,A.ITEM_VALUE,A.Area,A.Row_Caption,A.xPosition,A.Y_eq_lastrow,A.SequenceItem ORDER_SEQ,A.Display FROM VWDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE_ITEMS A
|
||
WHERE REFERENCE_GUID = @pMSGID
|
||
AND A.SPEC_NAME NOT IN ('INVOICE_POSITION_AMOUNT','INVOICE_POSITION_NOTE',
|
||
'INVOICE_TAXPOS_TAX_RATE','INVOICE_POSITION_ARTICLE','INVOICE_TAXPOS_AMOUNT',
|
||
'INVOICE_TAXPOS_RATE','INVOICE_TAXPOS_TYPE','INVOICE_POSITION_TAX_AMOUNT')
|
||
UNION
|
||
SELECT SPEC_NAME,ITEM_VALUE,Area,'' Row_Caption,10 xPosition, 0 Y_eq_lastrow,SequenceItem ORDER_SEQ, Display FROM [dbo].[FNDD_ZUGFERD_VIEW_RECEIPT_POSITIONS] (@pMSGID)
|
||
UNION
|
||
SELECT SPEC_NAME,ITEM_VALUE,Area,'' Row_Caption,10 xPosition, 0 Y_eq_lastrow,SequenceItem ORDER_SEQ, Display FROM [dbo].[FNDD_ZUGFERD_VIEW_RECEIPT_TAX] (@pMSGID)
|
||
UNION
|
||
SELECT SPECNAME SPEC_NAME,Row_Caption,Area,Row_Caption Row_Caption,10 xPosition, 0 Y_eq_lastrow,SequenceItem ORDER_SEQ, Display FROM TBDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE WHERE Area = 'INTERNAL'
|
||
)
|
||
GO
|
||
-- =============================================
|
||
-- Author: DD MS
|
||
-- Creation date: 25.06.20200
|
||
-- =============================================
|
||
CREATE FUNCTION [dbo].[FNDD_GET_DECIMAL_FOR_VARCHAR] (@INPUT VARCHAR(100))
|
||
RETURNS DECIMAL(19,2)
|
||
AS
|
||
BEGIN
|
||
DECLARE @DEC_VALUE DECIMAL(19,2)
|
||
DECLARE @INPUT_SS_15 VARCHAR(5)
|
||
SELECT @INPUT_SS_15 = SUBSTRING(@INPUT,1,5)
|
||
IF @INPUT_SS_15 LIKE ('%.%')
|
||
BEGIN
|
||
DECLARE @REP_SS_15 VARCHAR(5)
|
||
SET @REP_SS_15 = REPLACE(@INPUT_SS_15,'.','')
|
||
SET @INPUT = REPLACE(@INPUT,@INPUT_SS_15,@REP_SS_15)
|
||
END
|
||
SELECT @INPUT = REPLACE(@INPUT,',','.')
|
||
SELECT @DEC_VALUE = convert(DECIMAL(19,2),@INPUT)
|
||
|
||
RETURN @DEC_VALUE
|
||
END
|
||
|
||
--SELECT [dbo].[FNDD_GET_DECIMAL_FOR_VARCHAR] ('15681444,56')
|
||
--GO
|
||
GO
|
||
-- [FNDD_CONVERT_RTF2Text]
|
||
-- =================================================================
|
||
-- Converts a RTF text to a regular text
|
||
--
|
||
-- Returns: NVARCHAR - text
|
||
-- =================================================================
|
||
-- Copyright (c) 2024 by Digital Data GmbH
|
||
--
|
||
-- Digital Data GmbH <20> Ludwig-Rinn-Strasse 16 <20> D-35452 Heuchelheim
|
||
-- Tel.: 0641/202360 <20> E-Mail: info-flow@digitaldata.works
|
||
-- =================================================================
|
||
-- Creation Date / Author: 26.09.2024 / HE,MK
|
||
-- Version Date / Editor: 14.12.2024 / HE,MK
|
||
-- Version Number: 1.1.0.0
|
||
-- =================================================================
|
||
-- History:
|
||
-- 26.09.2024 / HE,MK - First Version
|
||
-- 14.12.2024 / MK - code optimisation, new additional parameters
|
||
|
||
CREATE OR ALTER FUNCTION [dbo].[FNDD_CONVERT_RTF2Text](
|
||
@pRTF nvarchar(max), -- Give the RTF text, you want to convert
|
||
@pREMOVE_LINE_WRAP BIT = 1, -- Set to 1 to remove line wraps
|
||
@pREMOVE_DOUBLE_BLANKS BIT = 1 -- Set to 1 to remove unnecessary blanks
|
||
)
|
||
RETURNS nvarchar(max)
|
||
AS
|
||
BEGIN
|
||
|
||
-- decalare new vars because of parameter sniffing
|
||
DECLARE @RTF NVARCHAR(256) = ISNULL(@pRTF,''),
|
||
@REMOVE_LINE_WRAP BIT = ISNULL(@pREMOVE_LINE_WRAP,1),
|
||
@REMOVE_DOUBLE_BLANKS BIT = ISNULL(@pREMOVE_DOUBLE_BLANKS,1);
|
||
|
||
-- decalare runtime vars
|
||
DECLARE @Pos1 int,
|
||
@Pos2 int,
|
||
@hex varchar(316);
|
||
|
||
DECLARE @Stage table ([Char] char(1), [Pos] int);
|
||
|
||
IF (LEN(@RTF) > 1) BEGIN
|
||
|
||
INSERT @Stage ([Char], [Pos])
|
||
|
||
SELECT SUBSTRING(@rtf, [Number], 1),
|
||
[Number]
|
||
FROM [master]..[spt_values]
|
||
WHERE ([Type] = 'p')
|
||
AND (SUBSTRING(@rtf, Number, 1) IN ('{', '}'));
|
||
|
||
SELECT @Pos1 = MIN([Pos])
|
||
, @Pos2 = MAX([Pos])
|
||
FROM @Stage;
|
||
|
||
DELETE
|
||
FROM @Stage
|
||
WHERE ([Pos] IN (@Pos1, @Pos2));
|
||
|
||
WHILE (1 = 1) BEGIN
|
||
SELECT TOP 1 @Pos1 = s1.[Pos]
|
||
, @Pos2 = s2.[Pos]
|
||
FROM @Stage s1
|
||
INNER JOIN @Stage s2 ON s2.[Pos] > s1.[Pos]
|
||
WHERE (s1.[Char] = '{')
|
||
AND (s2.[Char] = '}')
|
||
ORDER BY s2.[Pos] - s1.[Pos];
|
||
|
||
IF @@ROWCOUNT = 0
|
||
BREAK
|
||
|
||
DELETE
|
||
FROM @Stage
|
||
WHERE ([Pos] IN (@Pos1, @Pos2));
|
||
|
||
UPDATE @Stage
|
||
SET [Pos] = [Pos] - @Pos2 + @Pos1 - 1
|
||
WHERE ([Pos] > @Pos2);
|
||
|
||
SET @rtf = STUFF(@rtf, @Pos1, @Pos2 - @Pos1 + 1, '');
|
||
END;
|
||
|
||
SET @rtf = REPLACE(@rtf, '\pard', '');
|
||
SET @rtf = REPLACE(@rtf, '\par', '');
|
||
SET @rtf = STUFF(@rtf, 1, CHARINDEX(' ', @rtf), '');
|
||
|
||
WHILE (Right(@rtf, 1) IN (' ', CHAR(13), CHAR(10), '}')) BEGIN
|
||
SELECT @rtf = SUBSTRING(@rtf, 1, (LEN(@rtf + 'x') - 2));
|
||
IF LEN(@rtf) = 0 BREAK
|
||
END;
|
||
|
||
SET @Pos1 = CHARINDEX('\''', @rtf);
|
||
|
||
WHILE (@Pos1 > 0) BEGIN
|
||
IF (@Pos1 > 0) BEGIN
|
||
SET @hex = '0x' + SUBSTRING(@rtf, @Pos1 + 2, 2);
|
||
SET @rtf = REPLACE(@rtf, SUBSTRING(@rtf, @Pos1, 4),CHAR(CONVERT(int, CONVERT (binary(1), @hex,1))));
|
||
SET @Pos1 = CHARINDEX('\''', @rtf);
|
||
END;
|
||
END;
|
||
|
||
SET @rtf = @rtf + ' ';
|
||
SET @Pos1 = PATINDEX('%\%[0123456789][\ ]%', @rtf);
|
||
|
||
WHILE (@Pos1 > 0) BEGIN
|
||
|
||
SET @Pos2 = CHARINDEX(' ', @rtf, @Pos1 + 1);
|
||
|
||
IF (@Pos2 < @Pos1) BEGIN
|
||
SET @Pos2 = CHARINDEX('\', @rtf, @Pos1 + 1);
|
||
END;
|
||
|
||
IF (@Pos2 < @Pos1) BEGIN
|
||
SET @rtf = SUBSTRING(@rtf, 1, @Pos1 - 1);
|
||
SET @Pos1 = 0;
|
||
END; ELSE BEGIN
|
||
SET @rtf = STUFF(@rtf, @Pos1, @Pos2 - @Pos1 + 1, '');
|
||
SET @Pos1 = PATINDEX('%\%[0123456789][\ ]%', @rtf);
|
||
END;
|
||
END;
|
||
|
||
IF (@REMOVE_LINE_WRAP = 1) BEGIN
|
||
SET @rtf = REPLACE(@rtf,char(10),' ');
|
||
SET @rtf = REPLACE(@rtf,char(13),' ');
|
||
END;
|
||
|
||
IF (@REMOVE_DOUBLE_BLANKS = 1) BEGIN
|
||
WHILE (@rtf like '% %') BEGIN
|
||
IF (@rtf like '% %') BEGIN
|
||
SET @rtf = REPLACE(@rtf,' ',' ');
|
||
END;
|
||
END;
|
||
END;
|
||
|
||
-- Anyway remove trailing spaces
|
||
SET @rtf = LTRIM(RTRIM(@rtf));
|
||
|
||
END;
|
||
|
||
RETURN @rtf;
|
||
|
||
END;
|
||
GO
|
||
-- [PRDD_BACKUP_DATABASES]
|
||
-- =================================================================
|
||
-- Saving database to LOCAL (!!) backup folder
|
||
-- Minimum requirement: MS SQL Server 2016
|
||
--
|
||
-- Returns: INT Value - 0 = Everything worked well
|
||
-- =================================================================
|
||
-- Copyright (c) 2024 by Digital Data GmbH
|
||
--
|
||
-- Digital Data GmbH <20> Ludwig-Rinn-Strasse 16 <20> D-35452 Heuchelheim
|
||
-- Tel.: 0641/202360 <20> E-Mail: info-flow@digitaldata.works
|
||
-- =================================================================
|
||
-- Creation Date / Author: 13.12.2024 / MK
|
||
-- Version Date / Editor: 13.12.2024 / MK
|
||
-- Version Number: 1.0.0.0
|
||
-- =================================================================
|
||
-- History:
|
||
-- 13.12.2024 / MK - First Version
|
||
|
||
CREATE OR ALTER PROCEDURE [dbo].[PRDD_BACKUP_DATABASES] (
|
||
@pCOMPRESSION BIT = 1, -- Set to 1 to compress the database backup file (This option is not available in SQL Express Versions!). Otherwise set to 0.
|
||
@pLOCALBACKUPPATH NVARCHAR(200) = 'F:\Sicherung', -- Set the LOCAL Backup path. If path doesnt exist, it will be created.
|
||
@pSUBDIRECTORY NVARCHAR(50) = 'Date_YYYYMMDD', -- Set 'Date_YYYYMMDD' (which is Failsafe) for a backup subdir like '\path\20241213'. Every other value will used a static subdirectory name for creation.
|
||
@pINCLUDEDB NVARCHAR(1000) = 'DD_ECM', -- Set a list of included databases. IF <> NULL, it will override the @pEXCLUDEDB Parameter.
|
||
@pEXCLUDEDB NVARCHAR(1000) = 'master,model,msdb,tempdb', -- Set a list of exluded databases. Default exclusen are the system databases.
|
||
@pLOGLEVEL NVARCHAR(25) = 'ERROR' -- Set to 'INFO','WARN' OR 'ERROR' (or NULL to disable), logging to table: [TBDD_BACKUP_DATABASES_LOG].
|
||
-- 'INFO' includes Infos, Warnings and Errors, 'WARN' only warnings and Errors and 'ERROR' only Errors.
|
||
)
|
||
AS
|
||
BEGIN
|
||
|
||
SET NOCOUNT ON;
|
||
|
||
-- declare new vars because of parameter sniffing
|
||
DECLARE @COMPRESSION BIT = ISNULL(@pCOMPRESSION,0),
|
||
@LOCALBACKUPPATH NVARCHAR(255) = LTRIM(RTRIM(ISNULL(@pLOCALBACKUPPATH,''))),
|
||
@SUBDIRECTORY NVARCHAR(50) = LTRIM(RTRIM(ISNULL(@pSUBDIRECTORY,'Date_YYYYMMDD'))),
|
||
@INCLUDEDB NVARCHAR(1000) = LTRIM(RTRIM(ISNULL(@pINCLUDEDB,DB_NAME()))),
|
||
@EXCLUDEDB NVARCHAR(1000) = LTRIM(RTRIM(ISNULL(@pEXCLUDEDB,'master,model,msdb,tempdb'))),
|
||
@LOGLEVEL NVARCHAR(25) = LTRIM(RTRIM(ISNULL(@pLOGLEVEL,'ERROR')));
|
||
|
||
-- declare runtime vars
|
||
DECLARE @MyProcedureName NVARCHAR(128) = OBJECT_NAME(@@PROCID);
|
||
DECLARE @DBName NVARCHAR(100),
|
||
@DBNameCount INT,
|
||
@FULLLOCALBACKUPPATH NVARCHAR(255),
|
||
@ProductVersion sql_variant,
|
||
@ProductMainVersion INT,
|
||
@ProductLevel sql_variant,
|
||
@ProductEdition sql_variant,
|
||
@ProductEditionSimpleString NVARCHAR(50),
|
||
@MySessionID NVARCHAR(50) = @@SPID,
|
||
@Date_YYYYMMDD NVARCHAR(20) = CONVERT(VARCHAR(20),GETDATE(),112),
|
||
@sysconfigurations INT = 0,
|
||
@SQLCommand NVARCHAR(1000) = NULL,
|
||
@CMDCommand NVARCHAR(1000) = NULL,
|
||
@CMDCommandResult INT = 0,
|
||
@return_status NVARCHAR(50) = 0,
|
||
@return_status_text NVARCHAR(MAX) = 'START ' + @MyProcedureName + ' @ ' + CONVERT(varchar(50),GETDATE(),120);
|
||
|
||
PRINT '==============================='
|
||
PRINT 'PROCEDURE - ' + @return_status_text;
|
||
PRINT 'PARAMETER01 - @COMPRESSION: ' + CONVERT(VARCHAR(200),@COMPRESSION);
|
||
PRINT 'PARAMETER02 - @LOCALBACKUPPATH: ' + CONVERT(VARCHAR(50),@LOCALBACKUPPATH);
|
||
PRINT 'PARAMETER03 - @SUBDIRECTORY: ' + CONVERT(VARCHAR(1),@SUBDIRECTORY);
|
||
PRINT 'PARAMETER04 - @INCLUDEDB: ' + CONVERT(VARCHAR(1000),@INCLUDEDB);
|
||
PRINT 'PARAMETER05 - @EXCLUDEDB: ' + CONVERT(VARCHAR(1000),@EXCLUDEDB);
|
||
PRINT 'PARAMETER06 - @LOGLEVEL: ' + CONVERT(VARCHAR(25),@LOGLEVEL);
|
||
|
||
--=================================================-- Get server infos --==================================================--
|
||
SELECT @ProductVersion = SERVERPROPERTY('productversion'), @ProductLevel = SERVERPROPERTY ('productlevel'), @ProductEdition = SERVERPROPERTY ('edition');
|
||
SET @ProductMainVersion = ISNULL(LEFT(convert(VARCHAR(100),@ProductVersion), CHARINDEX('.', convert(VARCHAR(100),@ProductVersion)) - 1),0);
|
||
|
||
PRINT '';
|
||
PRINT 'Informations about this Server:';
|
||
PRINT '@MySessionID: ' + CONVERT(VARCHAR(100),@MySessionID);
|
||
PRINT '@ProductVersion: ' + CONVERT(VARCHAR(100),@ProductVersion);
|
||
PRINT '@ProductMainVersion: ' + CONVERT(VARCHAR(100),@ProductMainVersion);
|
||
PRINT '@ProductLevel: ' + CONVERT(VARCHAR(100),@ProductLevel);
|
||
PRINT '@ProductEdition: ' + CONVERT(VARCHAR(100),@ProductEdition);
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--==============================================-- Prepare the log table --================================================--
|
||
IF (@LOGLEVEL is not NULL) BEGIN
|
||
PRINT '';
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
|
||
PRINT 'Log table already exists';
|
||
END; ELSE BEGIN
|
||
PRINT 'Log table does not exists, trying to create...';
|
||
|
||
CREATE TABLE [dbo].[TBDD_BACKUP_DATABASES_LOG](
|
||
[GUID] [bigint] IDENTITY(1,1) NOT NULL,
|
||
[LOG_LEVEL] [varchar](25) NOT NULL,
|
||
[MESSAGE1] [varchar](max) NOT NULL,
|
||
[MESSAGE2] [varchar](max) NULL,
|
||
[MESSAGE3] [varchar](max) NULL,
|
||
[MESSAGE4] [varchar](max) NULL,
|
||
[MESSAGE5] [varchar](max) NULL,
|
||
[COMMENT] [varchar](max) NULL,
|
||
[ADDED_WHO] [varchar](50) NOT NULL,
|
||
[ADDED_WHEN] DATETIME NOT NULL,
|
||
CONSTRAINT [PK_TBDD_BACKUP_DATABASES_LOG] PRIMARY KEY CLUSTERED
|
||
(
|
||
[GUID] ASC
|
||
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
|
||
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY];
|
||
|
||
ALTER TABLE [dbo].[TBDD_BACKUP_DATABASES_LOG] ADD CONSTRAINT [DF_TBDD_BACKUP_DATABASES_LOG_ADDED_WHO] DEFAULT ('DEFAULT') FOR [ADDED_WHO];
|
||
|
||
ALTER TABLE [dbo].[TBDD_BACKUP_DATABASES_LOG] ADD CONSTRAINT [DF_TBDD_BACKUP_DATABASES_LOG_ADDED_WHEN] DEFAULT (getdate()) FOR [ADDED_WHEN];
|
||
|
||
END;
|
||
END; ELSE BEGIN
|
||
PRINT '';
|
||
PRINT 'Skipping Logging to log table!';
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===============================================-- Log start to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL,'preparing', 'procedure', @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--================================================-- Check sql edition --=================================================--
|
||
IF (CONVERT(VARCHAR(100),@ProductEdition) like '%express%') BEGIN
|
||
SET @return_status_text = 'This is an Express Version of the SQL Server, so backup COMPRESSION is not available!';
|
||
SET @ProductEditionSimpleString = 'Express';
|
||
END; ELSE BEGIN
|
||
SET @return_status_text = 'This is not an Express Version of the SQL Server, so backup COMPRESSION is available!';
|
||
SET @ProductEditionSimpleString = 'Standard/Datacenter';
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===================================================-- Log to table --====================================================--
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL,'preparing', 'procedure', @return_status, 'Found SQL Edition: ' + @ProductEditionSimpleString, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--=============================================-- Get the dbs for the loop --==============================================--
|
||
-- Create a temporary table to hold the table names
|
||
CREATE TABLE #DBList (DBName NVARCHAR(256));
|
||
|
||
IF (@ProductMainVersion >= 13) BEGIN
|
||
|
||
IF (@INCLUDEDB is not NULL) BEGIN
|
||
INSERT INTO #DBList(DBName)
|
||
SELECT [name] as 'DBName'
|
||
FROM [master].[sys].[databases]
|
||
WHERE [name] IN (SELECT [value] FROM STRING_SPLIT(@INCLUDEDB, ',')) -- include these databases
|
||
AND [state] = 0 -- database is online
|
||
AND [is_in_standby] = 0; -- database is not read only for log shipping
|
||
END; ELSE BEGIN
|
||
INSERT INTO #DBList(DBName)
|
||
SELECT [name] as 'DBName'
|
||
FROM [master].[sys].[databases]
|
||
WHERE [name] NOT IN (SELECT [value] FROM STRING_SPLIT(@EXCLUDEDB, ',')) -- exclude these databases
|
||
AND [state] = 0 -- database is online
|
||
AND [is_in_standby] = 0; -- database is not read only for log shipping
|
||
END;
|
||
|
||
END; ELSE BEGIN
|
||
|
||
PRINT 'Because of the SQL Version only one DB can be processed!'
|
||
INSERT INTO #DBList(DBName)
|
||
SELECT [name] as 'DBName'
|
||
FROM [master].[sys].[databases]
|
||
WHERE [name] = @INCLUDEDB -- use only this database
|
||
AND [state] = 0 -- database is online
|
||
AND [is_in_standby] = 0; -- database is not read only for log shipping
|
||
|
||
END;
|
||
|
||
SELECT @DBNameCount = COUNT(*) FROM #DBList;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
SET @return_status_text = 'Found ' + convert(VARCHAR,@DBNameCount) + ' database(s) to process!';
|
||
PRINT @return_status_text;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF (@LOGLEVEL in ('INFO','WARN')) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_list', 'count', @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--==========================================-- Create the main loop (cursor) --============================================--
|
||
IF (@DBNameCount > 0) BEGIN
|
||
|
||
IF LEN(@LOCALBACKUPPATH) > 0 and (@LOCALBACKUPPATH like '%\%') BEGIN
|
||
|
||
--==========================================-- Checking system configuration --============================================--
|
||
|
||
PRINT 'Checking system configuration';
|
||
|
||
SELECT @sysconfigurations = SUM(CAST([value] AS INT))
|
||
FROM [master].[sys].[configurations]
|
||
WHERE [name] in ('show advanced options','Ole Automation Procedures','xp_cmdshell');
|
||
|
||
If (@sysconfigurations = 3) BEGIN
|
||
|
||
SET @return_status = 0;
|
||
SET @return_status_text = 'System configuration does fit! (' + CONVERT(varchar,@sysconfigurations) + ')';
|
||
PRINT @return_status_text;
|
||
|
||
END; ELSE BEGIN
|
||
|
||
PRINT 'System configuration does NOT fit! Try to reconfigure... (' + CONVERT(varchar,@sysconfigurations) + ')';
|
||
|
||
EXEC sp_configure 'show advanced options', 1;
|
||
RECONFIGURE WITH OVERRIDE;
|
||
EXEC sp_configure 'Ole Automation Procedures', 1;
|
||
RECONFIGURE WITH OVERRIDE;
|
||
EXEC sp_configure 'xp_cmdshell', 1;
|
||
RECONFIGURE WITH OVERRIDE;
|
||
|
||
-- Check again
|
||
SELECT @sysconfigurations = SUM(CAST(value AS INT))
|
||
FROM [master].[sys].[configurations]
|
||
WHERE [name] in ('show advanced options','Ole Automation Procedures','xp_cmdshell');
|
||
|
||
If (@sysconfigurations = 3) BEGIN
|
||
SET @return_status = 0;
|
||
SET @return_status_text = 'System configuration does fit, now! (' + CONVERT(varchar,@sysconfigurations) + ')';
|
||
PRINT @return_status_text;
|
||
END; ELSE BEGIN
|
||
SET @return_status = 1;
|
||
SET @return_status_text = 'System configuration does NOT fit! (' + CONVERT(varchar,@sysconfigurations) + ')';
|
||
PRINT @return_status_text;
|
||
END;
|
||
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF (@LOGLEVEL in ('INFO','WARN')) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'server_check', 'filesystem_config',@return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
If (@return_status = 0) BEGIN
|
||
|
||
DECLARE db_cursor CURSOR STATIC LOCAL FOR
|
||
SELECT [DBName] as 'DBName' FROM #DBList;
|
||
|
||
OPEN db_cursor
|
||
FETCH NEXT FROM db_cursor INTO @DBName
|
||
WHILE @@FETCH_STATUS = 0 BEGIN
|
||
BEGIN TRY
|
||
|
||
PRINT ' ';
|
||
PRINT '-------------------------------';
|
||
PRINT 'Now processing: ' + CONVERT(varchar(100),@DBName);
|
||
|
||
--==============================================-- Preparing backup path --================================================--
|
||
|
||
-- Chekc if base path exits
|
||
SET @CMDCommand = 'IF EXIST "' + @LOCALBACKUPPATH + '" (echo 1) ELSE (echo 0)';
|
||
|
||
CREATE TABLE #CMDCommandResult (Output NVARCHAR(255));
|
||
INSERT INTO #CMDCommandResult (Output)
|
||
EXEC xp_cmdshell @CMDCommand;
|
||
|
||
SELECT @CMDCommandResult = CAST(Output AS INT) FROM #CMDCommandResult WHERE Output IS NOT NULL;
|
||
DROP TABLE #CMDCommandResult;
|
||
|
||
IF (@CMDCommandResult = 1) BEGIN
|
||
|
||
SET @return_status = 0;
|
||
SET @return_status_text = 'Directory (' + @LOCALBACKUPPATH + ') does exist!';
|
||
PRINT @return_status_text;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
IF (@SUBDIRECTORY like '%Date_YYYYMMDD%') BEGIN
|
||
SELECT @FULLLOCALBACKUPPATH = @LOCALBACKUPPATH + '\' + @Date_YYYYMMDD + '\';
|
||
END; ELSE IF (LEN(@SUBDIRECTORY) >= 1) BEGIN
|
||
SELECT @FULLLOCALBACKUPPATH = @LOCALBACKUPPATH + '\' + @SUBDIRECTORY + '\';
|
||
END; ELSE BEGIN
|
||
SELECT @FULLLOCALBACKUPPATH = @LOCALBACKUPPATH + '\';
|
||
END;
|
||
|
||
SET @FULLLOCALBACKUPPATH = REPLACE(@FULLLOCALBACKUPPATH,'\\','\');
|
||
PRINT 'Final backup path set: ' + @FULLLOCALBACKUPPATH;
|
||
EXECUTE @return_status = master.dbo.xp_create_subdir @FULLLOCALBACKUPPATH;
|
||
|
||
IF (@return_status = 0) BEGIN
|
||
SET @return_status_text = 'Creating database backup path successfully completed!';
|
||
PRINT @return_status_text;
|
||
END; ELSE BEGIN
|
||
SET @return_status_text = 'Creating database backup path returns warnings or has failed, check the access rights!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
IF (@return_status = 0) BEGIN
|
||
|
||
SET @FULLLOCALBACKUPPATH += @DBName + '.BAK';
|
||
SET @return_status_text = 'Starting backup to: ' + @FULLLOCALBACKUPPATH;
|
||
PRINT @return_status_text;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
IF (@ProductEditionSimpleString = 'Express') BEGIN
|
||
SET @SQLCommand = 'BACKUP DATABASE [' + @DBName + '] TO DISK = ''' + @FULLLOCALBACKUPPATH + ''' WITH FORMAT, CHECKSUM;';
|
||
END; ELSE BEGIN
|
||
SET @SQLCommand = 'BACKUP DATABASE [' + @DBName + '] TO DISK = ''' + @FULLLOCALBACKUPPATH + ''' WITH FORMAT, COMPRESSION, CHECKSUM;';
|
||
END;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @SQLCommand, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
BEGIN TRY
|
||
EXEC sp_executesql @SQLCommand;
|
||
SET @return_status = 0;
|
||
SET @return_status_text = 'Backup successful!';
|
||
END TRY
|
||
BEGIN CATCH
|
||
|
||
-- Handle any errors that occur during the process.
|
||
SELECT ERROR_MESSAGE() AS ErrorMessage;
|
||
|
||
SET @return_status = 1;
|
||
SET @return_status_text = 'Backup failed!';
|
||
END CATCH;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END; ELSE BEGIN
|
||
|
||
SET @return_status_text = 'Cannot backup database because of the previous error!';
|
||
PRINT @return_status_text;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN','ERROR')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES ('ERROR', 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END; ELSE BEGIN
|
||
|
||
SET @return_status = 1;
|
||
SET @return_status_text = 'Directory (' + @LOCALBACKUPPATH + ') does not exist!';
|
||
PRINT @return_status_text;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN','ERROR')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES ('ERROR', 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END;
|
||
|
||
END TRY
|
||
BEGIN CATCH
|
||
|
||
-- Handle any errors that occur during the process.
|
||
SELECT ERROR_MESSAGE() AS ErrorMessage;
|
||
|
||
--================================================-- Log error to table --=================================================--
|
||
IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES ('ERROR', 'db_cursor', @DBName, ERROR_MESSAGE(),@MyProcedureName,GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
BEGIN TRY
|
||
DROP TABLE #CMDCommandResult;
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT '#CMDCommandResult Temp table is already gone...';
|
||
END CATCH;
|
||
|
||
END CATCH;
|
||
|
||
FETCH NEXT FROM db_cursor INTO @DBName;
|
||
|
||
END;
|
||
|
||
CLOSE db_cursor;
|
||
DEALLOCATE db_cursor;
|
||
|
||
END; ELSE BEGIN
|
||
|
||
SET @return_status = 1;
|
||
SET @return_status_text = 'Cannot backup database, because of system configuration!';
|
||
PRINT @return_status_text;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN','ERROR')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES ('ERROR', 'server_check', 'filesystem_config', @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END;
|
||
|
||
-- Ensure temp table is droped and cursor is closed
|
||
BEGIN TRY
|
||
DROP TABLE #DBList;
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT '#DBList Temp table is already gone...';
|
||
END CATCH;
|
||
|
||
BEGIN TRY
|
||
DROP TABLE #CMDCommandResult;
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT '#CMDCommandResult Temp table is already gone...';
|
||
END CATCH;
|
||
|
||
END; ELSE BEGIN
|
||
|
||
SET @return_status = 1;
|
||
SET @return_status_text = 'Invalid LOCALBACKUPPATH!';
|
||
PRINT @return_status_text;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN','ERROR')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES ('ERROR', 'server_check', 'filesystem_config', @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END;
|
||
|
||
END; ELSE BEGIN
|
||
|
||
SET @return_status = 0;
|
||
SET @return_status_text = 'So there is nothing to do...';
|
||
PRINT @return_status_text;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN','ERROR')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES ('WARN', 'db_list', 'count', @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
SET @return_status_text = 'END ' + @MyProcedureName + ' @ ' + CONVERT(varchar(50),GETDATE(),120);
|
||
|
||
--================================================-- Log end to table --===================================================--
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'closing', 'procedure', @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
PRINT '';
|
||
PRINT 'PROCEDURE - ' + @return_status_text;
|
||
PRINT '===============================';
|
||
|
||
Return @return_status;
|
||
|
||
END;
|
||
GO
|
||
SET ANSI_NULLS ON
|
||
GO
|
||
SET QUOTED_IDENTIFIER ON
|
||
GO
|
||
|
||
-- [PRDD_MAINTAIN_DATABASES]
|
||
-- =================================================================
|
||
-- Checks database health, shrinks all database and log files
|
||
-- and recreates indizes in a maintanance run.
|
||
-- Minimum requirement: MS SQL Server 2016
|
||
--
|
||
-- Returns: INT Value - 0 = Everything worked well
|
||
-- =================================================================
|
||
-- Copyright (c) 2024 by Digital Data GmbH
|
||
--
|
||
-- Digital Data GmbH <20> Ludwig-Rinn-Strasse 16 <20> D-35452 Heuchelheim
|
||
-- Tel.: 0641/202360 <20> E-Mail: info-flow@digitaldata.works
|
||
-- =================================================================
|
||
-- Creation Date / Author: 29.11.2024 / MK
|
||
-- Version Date / Editor: 13.12.2024 / MK
|
||
-- Version Number: 1.1.0.1
|
||
-- =================================================================
|
||
-- History:
|
||
-- 29.11.2024 / MK - First Version
|
||
-- 06.12.2024 / MK - Added "SET ONLINE" after forced SINGLE_USER Mode, Added repair parameter for DBCHECK, added @pRECOMPILEPROCEDURES, some minor error fixes
|
||
-- 13.12.2024 / MK - New way the get the procedure name, failsafe for parameters implemented
|
||
|
||
CREATE OR ALTER PROCEDURE [dbo].[PRDD_MAINTAIN_DATABASES] (
|
||
@pCHECKDB BIT = 1, -- Set to 1 to make a check of the database before shrinking incl. soft repair function. Otherwise set to 0.
|
||
@pSHRINKLOG BIT = 1, -- Set to 1 to shrink the log file. Otherwise set to 0.
|
||
@pSHRINKDB BIT = 0, -- Set to 1 to shrink the database file as well. Otherwise set to 0. (Dont use on FILESTREAM databases!)
|
||
@pREBUILDINDEX BIT = 0, -- Set to 1 to recreate all database indexes. Otherwise set to 0.
|
||
@pRECOMPILEPROCEDURES BIT = 0, -- Set to 1 to recompile all database procedures. Otherwise set to 0.
|
||
@pCLEARQUERYCACHE BIT = 0, -- Set to 1 to clear the QL query cache via DROPCLEANBUFFERS. Otherwise set to 0.
|
||
@pFORCE BIT = 0, -- Set to 1 to force the shrinking, it will cut all current sessens. In combination with @pCHECKDB it trys the soft reapair dbs. Otherwise set to 0.
|
||
@pINCLUDEDB NVARCHAR(1000) = 'DD_ECM', -- Set a list of included databases. IF <> NULL, it will override the @pEXCLUDEDB Parameter
|
||
@pEXCLUDEDB NVARCHAR(1000) = 'master,model,msdb,tempdb', -- Set a list of exluded databases. Default exclusen are the system databases.
|
||
@pLOGLEVEL NVARCHAR(25) = 'ERROR' -- Set to 'INFO','WARN' OR 'ERROR' (or NULL to disable), logging to table: [TBDD_MAINTAIN_DATABASES_LOG]
|
||
-- 'INFO' includes Infos, Warnings and Errors, 'WARN' only warnings and Errors and 'ERROR' only Errors
|
||
)
|
||
AS
|
||
BEGIN
|
||
|
||
SET NOCOUNT ON;
|
||
|
||
-- declare new vars because of parameter sniffing
|
||
DECLARE @CHECKDB BIT = ISNULL(@pCHECKDB,1),
|
||
@SHRINKLOG BIT = ISNULL(@pSHRINKLOG,1),
|
||
@SHRINKDB BIT = ISNULL(@pSHRINKDB,0),
|
||
@REBUILDINDEX BIT = ISNULL(@pREBUILDINDEX,0),
|
||
@RECOMPILEPROCEDURES BIT = ISNULL(@pRECOMPILEPROCEDURES,0),
|
||
@CLEARQUERYCACHE BIT = ISNULL(@pCLEARQUERYCACHE,0),
|
||
@FORCE BIT = ISNULL(@pFORCE,0),
|
||
@INCLUDEDB NVARCHAR(1000) = LTRIM(RTRIM(ISNULL(@pINCLUDEDB,DB_NAME()))),
|
||
@EXCLUDEDB NVARCHAR(1000) = LTRIM(RTRIM(ISNULL(@pEXCLUDEDB,'master,model,msdb,tempdb'))),
|
||
@LOGLEVEL NVARCHAR(25) = LTRIM(RTRIM(ISNULL(@pLOGLEVEL,'ERROR')));
|
||
|
||
-- declare runtime vars
|
||
DECLARE @MyProcedureName NVARCHAR(128) = OBJECT_NAME(@@PROCID);
|
||
DECLARE @ProcedureName NVARCHAR(50),
|
||
@DBName NVARCHAR(100),
|
||
@DBNameCount INT,
|
||
@LogFileName NVARCHAR(100),
|
||
@CurrentLogFileSizeMB INT,
|
||
@MinimumLogFileSizeMB INT,
|
||
@TargetLogFileSizeMB INT,
|
||
@ProductVersion sql_variant,
|
||
@ProductMainVersion INT,
|
||
@ProductLevel sql_variant,
|
||
@ProductEdition sql_variant,
|
||
@SchemaName NVARCHAR(50),
|
||
@TableName NVARCHAR(256),
|
||
@LoginName NVARCHAR(50),
|
||
@HostName NVARCHAR(50),
|
||
@SessionID NVARCHAR(50) = NULL,
|
||
@MySessionID NVARCHAR(50) = @@SPID,
|
||
@SQLCommand NVARCHAR(MAX) = NULL,
|
||
@TableListCount INT = 0,
|
||
@ProcedureListCount INT = 0,
|
||
@return_status NVARCHAR(50) = 0,
|
||
@return_status_text NVARCHAR(MAX) = 'START ' + @MyProcedureName + ' @ ' + CONVERT(varchar(50),GETDATE(),120);
|
||
|
||
PRINT '==============================='
|
||
PRINT 'PROCEDURE - ' + @return_status_text;
|
||
PRINT 'PARAMETER01 - @CHECKDB: ' + CONVERT(VARCHAR(1),@CHECKDB);
|
||
PRINT 'PARAMETER02 - @SHRINKLOG: ' + CONVERT(VARCHAR(1),@SHRINKLOG);
|
||
PRINT 'PARAMETER03 - @SHRINKDB: ' + CONVERT(VARCHAR(1),@SHRINKDB);
|
||
PRINT 'PARAMETER04 - @REBUILDINDEX: ' + CONVERT(VARCHAR(1),@REBUILDINDEX);
|
||
PRINT 'PARAMETER05 - @RECOMPILEPROCEDURES: ' + CONVERT(VARCHAR(1),@RECOMPILEPROCEDURES);
|
||
PRINT 'PARAMETER06 - @CLEARQUERYCACHE: ' + CONVERT(VARCHAR(1),@CLEARQUERYCACHE);
|
||
PRINT 'PARAMETER07 - @FORCE: ' + CONVERT(VARCHAR(1),@FORCE);
|
||
PRINT 'PARAMETER08 - @INCLUDEDB: ' + CONVERT(VARCHAR(1000),@INCLUDEDB);
|
||
PRINT 'PARAMETER09 - @EXCLUDEDB: ' + CONVERT(VARCHAR(1000),@EXCLUDEDB);
|
||
PRINT 'PARAMETER10 - @LOGLEVEL: ' + CONVERT(VARCHAR(25),@LOGLEVEL);
|
||
|
||
--=================================================-- Get server infos --==================================================--
|
||
SELECT @ProductVersion = SERVERPROPERTY('productversion'), @ProductLevel = SERVERPROPERTY ('productlevel'), @ProductEdition = SERVERPROPERTY ('edition');
|
||
SET @ProductMainVersion = ISNULL(LEFT(convert(VARCHAR(100),@ProductVersion), CHARINDEX('.', convert(VARCHAR(100),@ProductVersion)) - 1),0);
|
||
|
||
PRINT '';
|
||
PRINT 'Informations about this Server:';
|
||
PRINT '@MySessionID: ' + CONVERT(VARCHAR(100),@MySessionID);
|
||
PRINT '@ProductVersion: ' + CONVERT(VARCHAR(100),@ProductVersion);
|
||
PRINT '@ProductMainVersion: ' + CONVERT(VARCHAR(100),@ProductMainVersion);
|
||
PRINT '@ProductLevel: ' + CONVERT(VARCHAR(100),@ProductLevel);
|
||
PRINT '@ProductEdition: ' + CONVERT(VARCHAR(100),@ProductEdition);
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--==============================================-- Prepare the log table --================================================--
|
||
IF (@LOGLEVEL is not NULL) BEGIN
|
||
PRINT '';
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
PRINT 'Log table already exists';
|
||
END; ELSE BEGIN
|
||
PRINT 'Log table does not exists, trying to create...';
|
||
|
||
CREATE TABLE [dbo].[TBDD_MAINTAIN_DATABASES_LOG](
|
||
[GUID] [bigint] IDENTITY(1,1) NOT NULL,
|
||
[LOG_LEVEL] [varchar](25) NOT NULL,
|
||
[MESSAGE1] [varchar](max) NOT NULL,
|
||
[MESSAGE2] [varchar](max) NULL,
|
||
[MESSAGE3] [varchar](max) NULL,
|
||
[MESSAGE4] [varchar](max) NULL,
|
||
[MESSAGE5] [varchar](max) NULL,
|
||
[COMMENT] [varchar](max) NULL,
|
||
[ADDED_WHO] [varchar](50) NOT NULL,
|
||
[ADDED_WHEN] DATETIME NOT NULL,
|
||
CONSTRAINT [PK_TBDD_MAINTAIN_DATABASES_LOG] PRIMARY KEY CLUSTERED
|
||
(
|
||
[GUID] ASC
|
||
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
|
||
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY];
|
||
|
||
ALTER TABLE [dbo].[TBDD_MAINTAIN_DATABASES_LOG] ADD CONSTRAINT [DF_TBDD_MAINTAIN_DATABASES_LOG_ADDED_WHO] DEFAULT ('DEFAULT') FOR [ADDED_WHO];
|
||
|
||
ALTER TABLE [dbo].[TBDD_MAINTAIN_DATABASES_LOG] ADD CONSTRAINT [DF_TBDD_MAINTAIN_DATABASES_LOG_ADDED_WHEN] DEFAULT (getdate()) FOR [ADDED_WHEN];
|
||
|
||
END;
|
||
END; ELSE BEGIN
|
||
PRINT '';
|
||
PRINT 'Skipping Logging to log table!';
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===============================================-- Log start to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL,'preparing', 'procedure', @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--=============================================-- Get the dbs for the loop --==============================================--
|
||
-- Create a temporary table to hold the table names
|
||
CREATE TABLE #DBList (DBName NVARCHAR(256));
|
||
|
||
IF (@ProductMainVersion >= 13) BEGIN
|
||
|
||
IF (@INCLUDEDB is not NULL) BEGIN
|
||
INSERT INTO #DBList(DBName)
|
||
SELECT [name] as 'DBName'
|
||
FROM [master].[sys].[databases]
|
||
WHERE [name] IN (SELECT [value] FROM STRING_SPLIT(@INCLUDEDB, ',')) -- include these databases
|
||
AND [state] = 0 -- database is online
|
||
AND [is_in_standby] = 0; -- database is not read only for log shipping
|
||
END; ELSE BEGIN
|
||
INSERT INTO #DBList(DBName)
|
||
SELECT [name] as 'DBName'
|
||
FROM [master].[sys].[databases]
|
||
WHERE [name] NOT IN (SELECT [value] FROM STRING_SPLIT(@EXCLUDEDB, ',')) -- exclude these databases
|
||
AND [state] = 0 -- database is online
|
||
AND [is_in_standby] = 0; -- database is not read only for log shipping
|
||
END;
|
||
|
||
END; ELSE BEGIN
|
||
|
||
PRINT 'Because of the SQL Version only one DB can be processed!'
|
||
INSERT INTO #DBList(DBName)
|
||
SELECT [name] as 'DBName'
|
||
FROM [master].[sys].[databases]
|
||
WHERE [name] = @INCLUDEDB -- use only this database
|
||
AND [state] = 0 -- database is online
|
||
AND [is_in_standby] = 0; -- database is not read only for log shipping
|
||
|
||
END;
|
||
|
||
SELECT @DBNameCount = COUNT(*) FROM #DBList;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
SET @return_status_text = 'Found ' + convert(VARCHAR,@DBNameCount) + ' database(s) to process!';
|
||
PRINT @return_status_text;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF (@LOGLEVEL in ('INFO','WARN')) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_list', 'count', @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--==========================================-- Create the main loop (cursor) --============================================--
|
||
IF (@DBNameCount > 0) BEGIN
|
||
|
||
DECLARE db_cursor CURSOR STATIC LOCAL FOR
|
||
SELECT [DBName] as 'DBName' FROM #DBList;
|
||
|
||
OPEN db_cursor
|
||
FETCH NEXT FROM db_cursor INTO @DBName
|
||
WHILE @@FETCH_STATUS = 0 BEGIN
|
||
BEGIN TRY
|
||
|
||
PRINT ' ';
|
||
PRINT '-------------------------------';
|
||
PRINT 'Now processing: ' + CONVERT(varchar(100),@DBName);
|
||
|
||
--==============================================-- Change db working mode --===============================================--
|
||
IF (@FORCE = 1) and (@return_status = 0) BEGIN
|
||
|
||
PRINT 'Closing active database connections... first time';
|
||
DECLARE kill_cursor CURSOR STATIC LOCAL FOR
|
||
SELECT CONVERT(NVARCHAR(5), [session_id]) as 'SessionID',
|
||
CONVERT(NVARCHAR(50), [login_name]) as 'LoginName',
|
||
CONVERT(NVARCHAR(50), [host_name]) as 'HostName'
|
||
FROM [master].[sys].[dm_exec_sessions] (NOLOCK)
|
||
WHERE [is_user_process] = 1
|
||
AND [database_id] = db_id(@DBName)
|
||
AND [session_id] <> @MySessionID;
|
||
|
||
OPEN kill_cursor;
|
||
FETCH NEXT FROM kill_cursor INTO @SessionID, @LoginName, @HostName;
|
||
WHILE @@FETCH_STATUS = 0 BEGIN
|
||
|
||
BEGIN TRY
|
||
SET @SQLCommand = 'KILL ' + @SessionID + ';';
|
||
PRINT 'Killing @SessionID: ' + @SessionID + ', @LoginName: ' + @LoginName + ', @HostName: ' + @HostName;
|
||
EXEC sp_executesql @SQLCommand;
|
||
SET @SQLCommand = NULL;
|
||
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||
SET @return_status_text = 'Closing connections to database was successfully completed!';
|
||
PRINT @return_status_text;
|
||
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||
SET @return_status_text = 'Closing connections to database returns warnings or has failed, check the ID!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'kill_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END TRY
|
||
BEGIN CATCH
|
||
|
||
-- Handle any errors that occur during the process.
|
||
SELECT ERROR_MESSAGE() AS ErrorMessage;
|
||
|
||
SET @SQLCommand = NULL;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL is not null) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES ('ERROR', 'kill_cursor', @DBName, ERROR_MESSAGE(),@MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END CATCH;
|
||
|
||
FETCH NEXT FROM kill_cursor INTO @SessionID, @LoginName, @HostName;
|
||
|
||
END;
|
||
|
||
CLOSE kill_cursor;
|
||
DEALLOCATE kill_cursor;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
PRINT 'Set the database to SINGLE_USER mode to avoid multiple active sessions.';
|
||
SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET SINGLE_USER WITH ROLLBACK IMMEDIATE;';
|
||
EXEC @return_status = sp_executesql @SQLCommand;
|
||
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||
SET @return_status_text = 'Setting the database to SINGLE_USER mode was successfully completed!';
|
||
PRINT @return_status_text;
|
||
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||
SET @return_status_text = 'Setting the database to SINGLE_USER mode returns warnings or has failed, check the ID!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END; ELSE BEGIN
|
||
|
||
IF (@LOGLEVEL in ('INFO')) BEGIN
|
||
SET @return_status_text = 'Skipping to change the database mode (FORCE = OFF)!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===============================================-- Check db consistency --================================================--
|
||
IF (@CHECKDB = 1) and (@return_status = 0) BEGIN
|
||
|
||
IF (@FORCE = 1) BEGIN
|
||
PRINT 'Check the database for consistency and health and try soft repair.';
|
||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC CHECKDB ([' + @DBName + '], REPAIR_REBUILD) WITH NO_INFOMSGS, ALL_ERRORMSGS';
|
||
END; ELSE BEGIN
|
||
PRINT 'Check the database for consistency and health.';
|
||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC CHECKDB ([' + @DBName + ']) WITH NO_INFOMSGS, ALL_ERRORMSGS';
|
||
END;
|
||
|
||
EXEC @return_status = sp_executesql @SQLCommand;
|
||
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||
SET @return_status_text = 'Check the database for consistency and health was successfully completed!';
|
||
PRINT @return_status_text;
|
||
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||
SET @return_status_text = 'Check the database for consistency and health returns warnings or has failed, check the ID!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
|
||
END; ELSE BEGIN
|
||
IF (@LOGLEVEL in ('INFO')) BEGIN
|
||
SET @return_status_text = 'Skipping the database check for consistency and health!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--============================================-- Prepare shrinking the log--===============================================--
|
||
IF (@SHRINKLOG = 1) BEGIN
|
||
|
||
--===========================================-- Get infos about the log file --============================================--
|
||
PRINT 'Get the current and minimum size of the log file in MB.';
|
||
SET @SQLCommand = N'SELECT TOP 1 @LogFileName = [name], @CurrentLogFileSizeMB = ([size] / 128), @MinimumLogFileSizeMB = ([growth] * 8)
|
||
FROM [master].[sys].[master_files]
|
||
WHERE [database_id] = DB_ID(''' + @DBName + ''') AND [type_desc] = ''LOG''';
|
||
EXEC @return_status = sp_executesql @SQLCommand, N'@LogFileName VARCHAR(100) OUTPUT, @CurrentLogFileSizeMB INT OUTPUT, @MinimumLogFileSizeMB INT OUTPUT',
|
||
@LogFileName OUTPUT, @CurrentLogFileSizeMB OUTPUT, @MinimumLogFileSizeMB OUTPUT;
|
||
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||
SET @return_status_text = 'Getting log file settings was successfully completed!';
|
||
PRINT @return_status_text;
|
||
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||
SET @return_status_text = 'Getting log file settings returns warnings or has failed, check the ID!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===========================================-- Calculate target file size --==============================================--
|
||
PRINT 'The @CurrentLogFileSizeMB is: ' + CONVERT(VARCHAR(1000),@CurrentLogFileSizeMB);
|
||
SET @TargetLogFileSizeMB = CASE WHEN @CurrentLogFileSizeMB * 0.1 < @MinimumLogFileSizeMB
|
||
THEN @MinimumLogFileSizeMB
|
||
ELSE @CurrentLogFileSizeMB * 0.1
|
||
END;
|
||
|
||
PRINT 'The @TargetLogFileSizeMB is: ' + CONVERT(VARCHAR(1000),@TargetLogFileSizeMB);
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--=================================================-- Schrink db logs --===================================================--
|
||
IF (@CurrentLogFileSizeMB > @TargetLogFileSizeMB) BEGIN
|
||
|
||
--=============================================-- Change db recovery mode --===============================================--
|
||
PRINT 'Truncating the log needs to change the database recovery model to SIMPLE.';
|
||
SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET RECOVERY SIMPLE';
|
||
EXEC @return_status = sp_executesql @SQLCommand;
|
||
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||
SET @return_status_text = 'Setting database to the simple recovery model was successfully completed!';
|
||
PRINT @return_status_text;
|
||
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||
SET @return_status_text = 'Setting database to the simple recovery model returns warnings or has failed, check the ID!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===================================================-- Now, do it! --=====================================================--
|
||
IF (@return_status = 0) BEGIN
|
||
PRINT 'Shrink the truncated log file to 10% of its current size or the minimum size, whichever is larger.';
|
||
IF (@ProductMainVersion >= 16) BEGIN
|
||
IF (@FORCE = 1) BEGIN
|
||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeMB AS VARCHAR) + ') WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = BLOCKERS), NO_INFOMSGS;';
|
||
END; ELSE BEGIN
|
||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeMB AS VARCHAR) + ') WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = SELF), NO_INFOMSGS;';
|
||
END;
|
||
END; ELSE BEGIN
|
||
PRINT 'Because of the sql server version, DBCC SHRINKFILE is not applicable with the FORCE parameter!';
|
||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeMB AS VARCHAR) + ') WITH NO_INFOMSGS;';
|
||
END;
|
||
|
||
EXEC @return_status = sp_executesql @SQLCommand;
|
||
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||
SET @return_status_text = 'Shrinking the database log file was successfully completed!';
|
||
PRINT @return_status_text;
|
||
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||
SET @return_status_text = 'Shrinking the database log file returns warnings or has failed, check the ID!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
|
||
END; ELSE BEGIN
|
||
SET @return_status_text = 'Shrinking the database log was skipped because of previouse error(s)!';
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--=============================================-- Change db recovery mode --===============================================--
|
||
PRINT 'Reset the database recovery model.'
|
||
SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET RECOVERY FULL';
|
||
EXEC @return_status = sp_executesql @SQLCommand;
|
||
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||
SET @return_status_text = 'Setting database back to the full recovery model was successfully completed!';
|
||
PRINT @return_status_text;
|
||
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||
SET @return_status_text = 'Setting database back to the full recovery model returns warnings or has failed, check the ID!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END; ELSE BEGIN
|
||
PRINT 'No shrink action neccessary!';
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END; ELSE BEGIN
|
||
PRINT 'Skipping to shrink the log file!';
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--================================================-- Shrink db as well --==================================================--
|
||
IF ((@SHRINKDB = 1) and (@return_status = 0)) BEGIN
|
||
PRINT 'Shrink the database to reclaim unused space.';
|
||
IF (@ProductMainVersion >= 16) BEGIN
|
||
IF (@FORCE = 1) BEGIN
|
||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKDATABASE ([' + @DBName + ']) WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = BLOCKERS), NO_INFOMSGS;';
|
||
END; ELSE BEGIN
|
||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKDATABASE ([' + @DBName + ']) WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = SELF), NO_INFOMSGS;';
|
||
END;
|
||
END; ELSE BEGIN
|
||
PRINT 'Because of the sql server version, DBCC SHRINKDATABASE is not applicable with the FORCE parameter!';
|
||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKDATABASE ([' + @DBName + ']) WITH NO_INFOMSGS;';
|
||
END;
|
||
|
||
EXEC @return_status = sp_executesql @SQLCommand;
|
||
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||
SET @return_status_text = 'Shrinking the database was successfully completed!';
|
||
PRINT @return_status_text;
|
||
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||
SET @return_status_text = 'Shrinking the database returns warnings or has failed, check the ID!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
|
||
END; ELSE BEGIN
|
||
IF (@LOGLEVEL in ('INFO')) BEGIN
|
||
SET @return_status_text = 'Skipping shrinking the database!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--=============================================-- Rebuild database indexes --==============================================--
|
||
IF ((@REBUILDINDEX = 1) and (@return_status = 0)) BEGIN
|
||
PRINT 'Prepare to rebuild database indexes.';
|
||
|
||
BEGIN TRY
|
||
DROP TABLE #TableList;
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT '#TableList Temp table is already gone... (1)';
|
||
END CATCH;
|
||
|
||
-- Create a temporary table to hold the table names
|
||
CREATE TABLE #TableList (SchemaName NVARCHAR(50), TableName NVARCHAR(256));
|
||
|
||
-- Set the context to the specified database and fill the temporary table
|
||
SET @SQLCommand = ' INSERT INTO #TableList (SchemaName, TableName)
|
||
SELECT DISTINCT (SCHEMA_NAME([schema_id])), t.[name]
|
||
FROM [' + @DBName + '].[sys].[tables] t
|
||
INNER JOIN [' + @DBName + '].[sys].[indexes] i ON t.[object_id] = i.[object_id]
|
||
WHERE i.[type] IN (1, 2) -- Clustered and Non-Clustered indexes;';
|
||
EXEC @return_status = sp_executesql @SQLCommand;
|
||
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||
SET @return_status_text = 'Getting the tables was successfully done!';
|
||
PRINT @return_status_text;
|
||
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||
SET @return_status_text = 'Getting the tables returns warnings or has failed, check the ID!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
|
||
IF (@return_status = 0) BEGIN
|
||
SELECT @TableListCount = COUNT(*) FROM #TableList;
|
||
PRINT 'Found: ' + convert(VARCHAR,@TableListCount) + ' tables to reindex';
|
||
END; ELSE BEGIN
|
||
SET @TableListCount = 0;
|
||
PRINT 'Found: no tables to reindex';
|
||
END;
|
||
|
||
END; ELSE BEGIN
|
||
IF (@LOGLEVEL in ('INFO')) BEGIN
|
||
SET @return_status_text = 'Skipping rebuilding database indexes!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
END;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
IF ((@REBUILDINDEX = 1) and (@return_status = 0) and (@TableListCount > 0)) BEGIN
|
||
|
||
DECLARE table_cursor CURSOR STATIC LOCAL FOR
|
||
SELECT SchemaName, TableName FROM #TableList;
|
||
|
||
OPEN table_cursor;
|
||
FETCH NEXT FROM table_cursor INTO @SchemaName, @TableName;
|
||
WHILE @@FETCH_STATUS = 0 BEGIN
|
||
BEGIN TRY
|
||
|
||
PRINT 'Rebuild Index for table: ' + CONVERT(VARCHAR(1000),@TableName);
|
||
SET @SQLCommand = 'ALTER INDEX ALL ON [' + @DBName + '].[' + @SchemaName + '].[' + @TableName + '] ' +
|
||
'REBUILD WITH (FILLFACTOR = 80, SORT_IN_TEMPDB = ON, STATISTICS_NORECOMPUTE = ON)';
|
||
EXEC @return_status = sp_executesql @SQLCommand;
|
||
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||
SET @return_status_text = 'Recreation the database indexes of Table [' + @TableName + '] successfully completed!';
|
||
PRINT @return_status_text;
|
||
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||
SET @return_status_text = 'Recreation the database indexes of Table [' + @TableName + '] returns warnings or has failed, check the ID!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'table_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
-- Short break to avoid access violations
|
||
WAITFOR DELAY '00:00:03';
|
||
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
PRINT 'Closing active database connections... again';
|
||
DECLARE kill_cursor CURSOR STATIC LOCAL FOR
|
||
SELECT CONVERT(NVARCHAR(5), [session_id]) as 'SessionID',
|
||
CONVERT(NVARCHAR(50), [login_name]) as 'LoginName',
|
||
CONVERT(NVARCHAR(50), [host_name]) as 'HostName'
|
||
FROM [master].[sys].[dm_exec_sessions] (NOLOCK)
|
||
WHERE [is_user_process] = 1
|
||
AND [database_id] = db_id(@DBName)
|
||
AND [session_id] <> @MySessionID;
|
||
|
||
OPEN kill_cursor;
|
||
FETCH NEXT FROM kill_cursor INTO @SessionID, @LoginName, @HostName;
|
||
WHILE @@FETCH_STATUS = 0 BEGIN
|
||
|
||
BEGIN TRY
|
||
|
||
SET @SQLCommand = 'KILL ' + @SessionID + ';';
|
||
PRINT 'Killing @SessionID: ' + @SessionID + ', @LoginName: ' + @LoginName + ', @HostName: ' + @HostName;
|
||
EXEC sp_executesql @SQLCommand;
|
||
SET @SQLCommand = NULL;
|
||
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||
SET @return_status_text = 'Closing connections to database was successfully completed!';
|
||
PRINT @return_status_text;
|
||
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||
SET @return_status_text = 'Closing connections to database returns warnings or has failed, check the ID!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'kill_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END TRY
|
||
BEGIN CATCH
|
||
|
||
-- Handle any errors that occur during the process.
|
||
SELECT ERROR_MESSAGE() AS ErrorMessage;
|
||
|
||
SET @SQLCommand = NULL;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL is not null) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES ('ERROR', 'kill_cursor', @DBName, ERROR_MESSAGE(),@MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END CATCH;
|
||
|
||
FETCH NEXT FROM kill_cursor INTO @SessionID, @LoginName, @HostName;
|
||
|
||
END;
|
||
|
||
CLOSE kill_cursor;
|
||
DEALLOCATE kill_cursor;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
FETCH NEXT FROM table_cursor INTO @SchemaName, @TableName;
|
||
|
||
END TRY
|
||
BEGIN CATCH
|
||
|
||
-- Handle any errors that occur during the process.
|
||
SELECT ERROR_MESSAGE() AS ErrorMessage;
|
||
|
||
--================================================-- Log error to table --=================================================--
|
||
IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES ('ERROR', 'table_cursor', @DBName, ERROR_MESSAGE(),@MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
FETCH NEXT FROM table_cursor INTO @SchemaName, @TableName;
|
||
|
||
END CATCH;
|
||
|
||
END;
|
||
|
||
CLOSE table_cursor;
|
||
DEALLOCATE table_cursor;
|
||
|
||
-- Drop the temporary table
|
||
DROP TABLE #TableList;
|
||
|
||
SET @return_status_text = 'Recreation of the database indexes successfully completed!';
|
||
PRINT @return_status_text;
|
||
|
||
END; ELSE BEGIN
|
||
IF (@LOGLEVEL in ('INFO')) BEGIN
|
||
SET @return_status_text = 'Skipping the recreation of the database indexes!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--=========================================-- Prepare to recompile Procedures --===========================================--
|
||
IF ((@RECOMPILEPROCEDURES = 1) and (@return_status = 0)) BEGIN
|
||
PRINT 'Prepare to recompile database procedures.';
|
||
|
||
BEGIN TRY
|
||
DROP TABLE #ProcedureList;
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT '#ProcedureList Temp table is already gone... (1)';
|
||
END CATCH;
|
||
|
||
-- Create a temporary table to hold the procedure names
|
||
CREATE TABLE #ProcedureList (SchemaName NVARCHAR(50), ProcedureName NVARCHAR(256));
|
||
|
||
-- Set the context to the specified database and fill the temporary table
|
||
SET @SQLCommand = ' INSERT INTO #ProcedureList (SchemaName, ProcedureName)
|
||
SELECT SPECIFIC_CATALOG, SPECIFIC_NAME
|
||
FROM [' + @DBName + '].INFORMATION_SCHEMA.ROUTINES (NOLOCK)
|
||
WHERE ROUTINE_TYPE = ''PROCEDURE''
|
||
AND SPECIFIC_NAME <> ''' + @MyProcedureName + '''
|
||
ORDER BY SPECIFIC_NAME;';
|
||
EXEC @return_status = sp_executesql @SQLCommand;
|
||
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||
SET @return_status_text = 'Getting the procedures was successfully done!';
|
||
PRINT @return_status_text;
|
||
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||
SET @return_status_text = 'Getting the procedures returns warnings or has failed, check the ID!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
|
||
IF (@return_status = 0) BEGIN
|
||
SELECT @ProcedureListCount = COUNT(*) FROM #ProcedureList;
|
||
PRINT 'Found: ' + convert(VARCHAR,@ProcedureListCount) + ' procedures to recompile';
|
||
END; ELSE BEGIN
|
||
SET @ProcedureListCount = 0;
|
||
PRINT 'Found: no procedures to recompile';
|
||
END;
|
||
|
||
END; ELSE BEGIN
|
||
IF (@LOGLEVEL in ('INFO')) BEGIN
|
||
SET @return_status_text = 'Skipping recompiling procedures!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===============================================-- Recompile Procedures --================================================--
|
||
IF ((@RECOMPILEPROCEDURES = 1) and (@return_status = 0) and (@ProcedureListCount > 0)) BEGIN
|
||
|
||
PRINT 'Removing all procedure elements from the query plan cache.';
|
||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC FREEPROCCACHE;';
|
||
EXEC @return_status = sp_executesql @SQLCommand;
|
||
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||
SET @return_status_text = 'Removing all procedure elements was successfully completed!';
|
||
PRINT @return_status_text;
|
||
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||
SET @return_status_text = 'Removing all procedure elements returns warnings or has failed, check the ID!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'procedure_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
DECLARE procedure_cursor CURSOR STATIC LOCAL FOR
|
||
SELECT SchemaName, ProcedureName FROM #ProcedureList;
|
||
|
||
OPEN procedure_cursor;
|
||
FETCH NEXT FROM procedure_cursor INTO @SchemaName, @ProcedureName;
|
||
WHILE @@FETCH_STATUS = 0 BEGIN
|
||
BEGIN TRY
|
||
|
||
PRINT 'Recompile procedure: ' + CONVERT(VARCHAR(1000),@ProcedureName);
|
||
SET @SQLCommand = 'USE [' + @DBName + ']; EXEC sp_recompile ''' + @ProcedureName + '''; ';
|
||
EXEC @return_status = sp_executesql @SQLCommand;
|
||
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||
SET @return_status_text = 'Recompiling the procedure [' + @ProcedureName + '] successfully completed!';
|
||
PRINT @return_status_text;
|
||
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||
SET @return_status_text = 'Recompiling the procedure [' + @ProcedureName + '] returns warnings or has failed, check the ID!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'procedure_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
FETCH NEXT FROM procedure_cursor INTO @SchemaName, @ProcedureName;
|
||
|
||
END TRY
|
||
BEGIN CATCH
|
||
|
||
-- Handle any errors that occur during the process.
|
||
SELECT ERROR_MESSAGE() AS ErrorMessage;
|
||
|
||
--================================================-- Log error to table --=================================================--
|
||
IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES ('ERROR', 'procedure_cursor', @DBName, ERROR_MESSAGE(),@MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
FETCH NEXT FROM procedure_cursor INTO @SchemaName, @ProcedureName;
|
||
|
||
END CATCH;
|
||
|
||
END;
|
||
|
||
CLOSE procedure_cursor;
|
||
DEALLOCATE procedure_cursor;
|
||
|
||
-- Drop the temporary table
|
||
DROP TABLE #ProcedureList;
|
||
|
||
SET @return_status_text = 'Recompiling of procedures successfully completed!';
|
||
PRINT @return_status_text;
|
||
|
||
END; ELSE BEGIN
|
||
IF (@LOGLEVEL in ('INFO')) BEGIN
|
||
SET @return_status_text = 'Skipping the recompiling of the procedures!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'procedure_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--================================================-- Clear Query Cache --==================================================--
|
||
|
||
IF ((@CLEARQUERYCACHE = 1) and (@return_status = 0)) BEGIN
|
||
|
||
PRINT 'Removing the sql query cache.';
|
||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC DROPCLEANBUFFERS;';
|
||
EXEC @return_status = sp_executesql @SQLCommand;
|
||
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||
SET @return_status_text = 'Removing sql query cache was successfully completed!';
|
||
PRINT @return_status_text;
|
||
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||
SET @return_status_text = 'Removing sql query cache returns warnings or has failed, check the ID!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
|
||
END; ELSE BEGIN
|
||
IF (@LOGLEVEL in ('INFO')) BEGIN
|
||
SET @return_status_text = 'Skipping the query cache clearing!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--==============================================-- Change db working mode --===============================================--
|
||
IF (@FORCE = 1) BEGIN -- and ignore last result
|
||
PRINT 'Set the database back to MULTI_USER mode';
|
||
SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET MULTI_USER; ALTER DATABASE [' + @DBName + '] SET ONLINE;';
|
||
EXEC @return_status = sp_executesql @SQLCommand;
|
||
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||
SET @return_status_text = 'Setting the database to MULTI_USER mode was successfully completed!';
|
||
PRINT @return_status_text;
|
||
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||
SET @return_status_text = 'Setting the database to MULTI_USER mode returns warnings or has failed, check the ID!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
END; ELSE BEGIN
|
||
IF (@LOGLEVEL in ('INFO')) BEGIN
|
||
SET @return_status_text = 'Skipping to change the database mode (FORCE = OFF)!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
-- Ensure temp table is droped and cursor is closed
|
||
BEGIN TRY
|
||
DROP TABLE #DBList;
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT '#DBList Temp table are already gone...';
|
||
END CATCH;
|
||
|
||
IF (@REBUILDINDEX = 1) BEGIN
|
||
|
||
BEGIN TRY
|
||
DROP TABLE #TableList;
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT '#TableList Temp table are already gone...(1)';
|
||
END CATCH;
|
||
|
||
END;
|
||
|
||
IF (@RECOMPILEPROCEDURES = 1) BEGIN
|
||
|
||
BEGIN TRY
|
||
DROP TABLE #ProcedureList;
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT '#ProcedureList Temp table are already gone...(1)';
|
||
END CATCH;
|
||
|
||
BEGIN TRY
|
||
CLOSE procedure_cursor;
|
||
DEALLOCATE procedure_cursor;
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'Procedure cursor is already closed and deallocated...(1)';
|
||
END CATCH;
|
||
|
||
END;
|
||
|
||
PRINT '-------------------------------';
|
||
|
||
END TRY
|
||
BEGIN CATCH
|
||
-- Handle any errors that occur during the process.
|
||
SELECT ERROR_MESSAGE() AS ErrorMessage;
|
||
|
||
--================================================-- Log error to table --=================================================--
|
||
IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES ('ERROR', 'db_cursor', @DBName, ERROR_MESSAGE(),@MyProcedureName,GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--==============================================-- Change db working mode --===============================================--
|
||
-- Ensure the database is set back to MULTI_USER mode in case of errors.
|
||
--==============================================-- Change db working mode --===============================================--
|
||
IF (@FORCE = 1) BEGIN -- and ignore last result
|
||
PRINT 'Set the database back to MULTI_USER mode';
|
||
SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET MULTI_USER; ALTER DATABASE [' + @DBName + '] SET ONLINE;';
|
||
EXEC @return_status = sp_executesql @SQLCommand;
|
||
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||
SET @return_status_text = 'Setting the database to MULTI_USER mode was successfully completed!';
|
||
PRINT @return_status_text;
|
||
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||
SET @return_status_text = 'Setting the database to MULTI_USER mode returns warnings or has failed, check the ID!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
END; ELSE BEGIN
|
||
IF (@LOGLEVEL in ('INFO')) BEGIN
|
||
SET @return_status_text = 'Skipping to change the database mode (FORCE = OFF)!';
|
||
PRINT @return_status_text;
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--===============================================-- Log start to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--=====================================================-- Clean up --======================================================--
|
||
-- Ensure temp table is droped and cursor is closed
|
||
BEGIN TRY
|
||
DROP TABLE #DBList;
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT '#DBList Temp table are already gone...';
|
||
END CATCH;
|
||
|
||
IF (@REBUILDINDEX = 1) BEGIN
|
||
|
||
BEGIN TRY
|
||
DROP TABLE #TableList;
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT '#TableList Temp table are already gone...(2)';
|
||
END CATCH;
|
||
|
||
BEGIN TRY
|
||
CLOSE table_cursor;
|
||
DEALLOCATE table_cursor;
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'Table cursor is already closed and deallocated...(2)';
|
||
END CATCH;
|
||
|
||
END;
|
||
|
||
IF (@RECOMPILEPROCEDURES = 1) BEGIN
|
||
|
||
BEGIN TRY
|
||
DROP TABLE #ProcedureList;
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT '#ProcedureList Temp table are already gone...(2)';
|
||
END CATCH;
|
||
|
||
BEGIN TRY
|
||
CLOSE procedure_cursor;
|
||
DEALLOCATE procedure_cursor;
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'Procedure cursor is already closed and deallocated...(2)';
|
||
END CATCH;
|
||
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END CATCH;
|
||
|
||
FETCH NEXT FROM db_cursor INTO @DBName;
|
||
|
||
END;
|
||
|
||
CLOSE db_cursor;
|
||
DEALLOCATE db_cursor;
|
||
|
||
END; ELSE BEGIN
|
||
|
||
SET @return_status = 0;
|
||
SET @return_status_text = 'So there is nothing to do...';
|
||
PRINT @return_status_text;
|
||
|
||
--===============================================-- Log result to table --=================================================--
|
||
IF ((@LOGLEVEL in ('INFO','WARN','ERROR')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES ('WARN', 'db_list', 'count', @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
SET @return_status_text = 'END [PRDD_MAINTAIN_DATABASES] @ ' + CONVERT(varchar(50),GETDATE(),120);
|
||
|
||
--================================================-- Log end to table --===================================================--
|
||
IF ((@LOGLEVEL in ('INFO')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, 'closing', 'procedure', @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
PRINT '';
|
||
PRINT 'PROCEDURE - ' + @return_status_text;
|
||
PRINT '===============================';
|
||
|
||
Return @return_status;
|
||
|
||
END;
|
||
GO
|
||
SET ANSI_NULLS ON
|
||
GO
|
||
SET QUOTED_IDENTIFIER ON
|
||
GO
|
||
|
||
-- [PRDD_SET_STATUS_IN_THIRDPARTY_DB]
|
||
-- =================================================================
|
||
-- Set status info into a text field
|
||
--
|
||
-- Returns: 1 = SUCCESS; 0 = FAILED
|
||
-- =================================================================
|
||
-- Copyright (c) 2024 by Digital Data GmbH
|
||
--
|
||
-- Digital Data GmbH <20> Ludwig-Rinn-Strasse 16 <20> D-35452 Heuchelheim
|
||
-- Tel.: 0641/202360 <20> E-Mail: info-flow@digitaldata.works
|
||
-- =================================================================
|
||
-- Creation Date / Author: 25.11.2024 / HE,MK
|
||
-- Version Date / Editor: 14.12.2024 / HE,MK
|
||
-- Version Number: 1.1.0.0
|
||
-- =================================================================
|
||
-- History:
|
||
-- 25.11.2024 / HE,MK - First Version
|
||
-- 14.12.2024 / MK - @MyProcedureName variable implemented, Failsafe for parameters implemented
|
||
|
||
CREATE OR ALTER PROCEDURE [PRDD_SET_STATUS_IN_THIRDPARTY_DB](
|
||
@pTARGET_DB NVARCHAR(256) = '[DD_CWLDATEN_DDVP]', -- Give target DB name (without schema!)
|
||
@pTARGET_SCHEMA NVARCHAR(256) = '[dbo]', -- Give target DB schema
|
||
@pTARGET_TABLE NVARCHAR(256) = '[t025]', -- Give target DB table
|
||
@pTARGET_COLUMN NVARCHAR(256) = '[c069]', -- Give target DB column
|
||
@pTARGET_COLUMN_TYPE NVARCHAR(256) = 'NVARCHAR', -- Give target DB column type eg. INT or NVARCHAR
|
||
@pREF_DOC_TYPE NVARCHAR(256) = 'Ausgangsrechnung', -- Give REF_DOC_TYPE, eg.: Ausgangsangebot, Ausgangsauftrag, Ausgangslieferschein, Ausgangsrechnung (ONLY FOR LOGGING PURPOSE!)
|
||
@pREF_DOC_NR_COLUMN NVARCHAR(256) = '[c055]', -- Give the column where the REF_DOC_NR is stored (eg. WINLINE: Ausgangsangebot=[c043], Ausgangsauftrag=[c044], Ausgangslieferschein=[c045], Ausgangsrechnung=[c055])
|
||
@pREF_DOC_NR NVARCHAR(256), -- Give REF_DOC_NR, like 'ARE-20234187' or 'AANG-20241060'
|
||
@pADDITIONAL_WHERE NVARCHAR(256) = '', -- Give an additional WHERE clause like ' AND [COLUMN] IS NOT NULL'
|
||
@pSTATUS_VALUE NVARCHAR(256), -- Give text to write in @pTARGET_COLUMN
|
||
@pSTATUS_VALUE_MAX_LEN INT = 60, -- Give the max lenght of the target field for the status text
|
||
@pSTATUS_VALUE_DELIMITER NVARCHAR(3) = '; ', -- Give the separator to concat multiple status values, like "Text1; Text2; ..."
|
||
@pUSERNAME NVARCHAR(50), -- Give the user of the Frontend call, for the logging
|
||
@pOVERWRITE BIT = 0, -- Set overwrite for @pTARGET_COLUMN: 0 = concat; 1 = overwrite
|
||
@pLOGLEVEL NVARCHAR(25) = 'ERROR' -- Set Loglevel (ERROR or INFO) to be written to table [TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG]
|
||
)
|
||
AS
|
||
BEGIN TRY
|
||
|
||
SET NOCOUNT ON;
|
||
|
||
-- decalare new vars because of parameter sniffing
|
||
DECLARE @TARGET_DB NVARCHAR(256) = ISNULL(@pTARGET_DB,''),
|
||
@TARGET_SCHEMA NVARCHAR(256) = ISNULL(@pTARGET_SCHEMA,''),
|
||
@TARGET_TABLE NVARCHAR(256) = ISNULL(@pTARGET_TABLE,''),
|
||
@TARGET_COLUMN NVARCHAR(256) = ISNULL(@pTARGET_COLUMN,''),
|
||
@TARGET_COLUMN_TYPE NVARCHAR(256) = ISNULL(@pTARGET_COLUMN_TYPE,'NVARCHAR'),
|
||
@REF_DOC_TYPE NVARCHAR(256) = ISNULL(@pREF_DOC_TYPE,''),
|
||
@REF_DOC_NR_COLUMN NVARCHAR(256) = ISNULL(@pREF_DOC_NR_COLUMN,''),
|
||
@REF_DOC_NR NVARCHAR(256) = ISNULL(@pREF_DOC_NR,''),
|
||
@ADDITIONAL_WHERE NVARCHAR(256) = ISNULL(@pADDITIONAL_WHERE,''),
|
||
@STATUS_VALUE NVARCHAR(256) = ISNULL(@pSTATUS_VALUE,''),
|
||
@STATUS_VALUE_MAX_LEN INT = ISNULL(@pSTATUS_VALUE_MAX_LEN,60),
|
||
@STATUS_VALUE_DELIMITER NVARCHAR(3) = ISNULL(@pSTATUS_VALUE_DELIMITER,'; '),
|
||
@USERNAME NVARCHAR(50) = ISNULL(@pUSERNAME,LEFT(OBJECT_NAME(@@PROCID),50)),
|
||
@OVERWRITE BIT = ISNULL(@pOVERWRITE,0),
|
||
@LOGLEVEL NVARCHAR(25) = ISNULL(@pLOGLEVEL,'ERROR');
|
||
|
||
-- decalare runtime vars
|
||
DECLARE @MyProcedureName NVARCHAR(128) = OBJECT_NAME(@@PROCID);
|
||
DECLARE @LINE_COUNT_1 INT = 0,
|
||
@LINE_COUNT_2 INT = 0,
|
||
@SQL_COMMAND NVARCHAR(2000) = NULL,
|
||
@STATUS_VALUE_OLD NVARCHAR(256) = NULL,
|
||
@RETURN_STATUS NVARCHAR(256) = NULL,
|
||
@RETURN_STATUS_VALUE NVARCHAR(256) = 'START ' + @MyProcedureName + ' @ ' + CONVERT(varchar(50),GETDATE(),120);
|
||
|
||
PRINT '==============================='
|
||
PRINT 'PROCEDURE - ' + @RETURN_STATUS_VALUE;
|
||
PRINT 'PARAMETER01 - @TARGET_DB: ' + CONVERT(NVARCHAR(256),@TARGET_DB);
|
||
PRINT 'PARAMETER02 - @TARGET_SCHEMA: ' + CONVERT(NVARCHAR(256),@TARGET_SCHEMA);
|
||
PRINT 'PARAMETER03 - @TARGET_TABLE: ' + CONVERT(NVARCHAR(256),@TARGET_TABLE);
|
||
PRINT 'PARAMETER04 - @TARGET_COLUMN: ' + CONVERT(NVARCHAR(256),@TARGET_COLUMN);
|
||
PRINT 'PARAMETER05 - @TARGET_COLUMN_TYPE: ' + CONVERT(NVARCHAR(256),@TARGET_COLUMN_TYPE);
|
||
PRINT 'PARAMETER06 - @REF_DOC_TYPE: ' + CONVERT(NVARCHAR(256),@REF_DOC_TYPE);
|
||
PRINT 'PARAMETER07 - @REF_DOC_NR_COLUMN ' + CONVERT(NVARCHAR(256),@REF_DOC_NR_COLUMN);
|
||
PRINT 'PARAMETER08 - @REF_DOC_NR: ' + CONVERT(NVARCHAR(256),@REF_DOC_NR);
|
||
PRINT 'PARAMETER09 - @ADDITIONAL_WHERE ' + CONVERT(NVARCHAR(256),@ADDITIONAL_WHERE);
|
||
PRINT 'PARAMETER10 - @STATUS_VALUE: ' + CONVERT(NVARCHAR(256),@STATUS_VALUE);
|
||
PRINT 'PARAMETER11 - @STATUS_VALUE_MAX_LEN ' + CONVERT(NVARCHAR(256),@STATUS_VALUE_MAX_LEN);
|
||
PRINT 'PARAMETER12 - @STATUS_VALUE_DELIMITER ' + CONVERT(NVARCHAR(3),@STATUS_VALUE_DELIMITER);
|
||
PRINT 'PARAMETER13 - @USERNAME: ' + CONVERT(NVARCHAR(50),@USERNAME);
|
||
PRINT 'PARAMETER14 - @OVERWRITE: ' + CONVERT(NVARCHAR(1),@OVERWRITE);
|
||
PRINT 'PARAMETER15 - @LOGLEVEL: ' + CONVERT(NVARCHAR(25),@LOGLEVEL);
|
||
|
||
--==============================================-- Prepare the log table --================================================--
|
||
IF (@LOGLEVEL is not NULL) BEGIN
|
||
PRINT '';
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG') BEGIN
|
||
PRINT 'Log table already exists';
|
||
|
||
END; ELSE BEGIN
|
||
PRINT 'Log table does not exists, trying to create...';
|
||
|
||
CREATE TABLE [dbo].[TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG](
|
||
[GUID] [bigint] IDENTITY(1,1) NOT NULL,
|
||
[LOG_LEVEL] NVARCHAR(25) NOT NULL,
|
||
[MESSAGE1] NVARCHAR(max) NOT NULL,
|
||
[MESSAGE2] NVARCHAR(max) NULL,
|
||
[MESSAGE3] NVARCHAR(max) NULL,
|
||
[MESSAGE4] NVARCHAR(max) NULL,
|
||
[MESSAGE5] NVARCHAR(max) NULL,
|
||
[COMMENT] NVARCHAR(max) NULL,
|
||
[ADDED_WHO] NVARCHAR(50) NOT NULL,
|
||
[ADDED_WHEN] DATETIME NOT NULL,
|
||
CONSTRAINT [PK_TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG] PRIMARY KEY CLUSTERED
|
||
(
|
||
[GUID] ASC
|
||
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
|
||
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY];
|
||
|
||
ALTER TABLE [dbo].[TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG] ADD CONSTRAINT [DF_TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG_ADDED_WHO] DEFAULT ('DEFAULT') FOR [ADDED_WHO];
|
||
|
||
ALTER TABLE [dbo].[TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG] ADD CONSTRAINT [DF_TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG_ADDED_WHEN] DEFAULT (getdate()) FOR [ADDED_WHEN];
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
--=====================================================-- main part --=====================================================--
|
||
PRINT 'Check if there is a valid target...'
|
||
SET @SQL_COMMAND = N'SELECT @LINE_COUNT_1 = count(*)
|
||
FROM ' + @TARGET_DB + '.' + @TARGET_SCHEMA + '.' + @TARGET_TABLE + '
|
||
WHERE ' + @REF_DOC_NR_COLUMN + ' = ''' + @REF_DOC_NR + ''' ' + @ADDITIONAL_WHERE;
|
||
PRINT 'Build Query @SQL_COMMAND: ' + @SQL_COMMAND;
|
||
EXEC @RETURN_STATUS = sp_executesql @SQL_COMMAND,N'@LINE_COUNT_1 INT OUTPUT', @LINE_COUNT_1 OUTPUT;
|
||
|
||
IF (@RETURN_STATUS = 0) BEGIN
|
||
IF (@LINE_COUNT_1 > 0) BEGIN
|
||
PRINT 'Found: ' + CONVERT(NVARCHAR(25),@LINE_COUNT_1) + ' docs to update!';
|
||
PRINT 'Checking if docs have a existing "status text"';
|
||
SET @SQL_COMMAND = N'SELECT @LINE_COUNT_2 = count(*)
|
||
FROM ' + @TARGET_DB + '.' + @TARGET_SCHEMA + '.' + @TARGET_TABLE + '
|
||
WHERE ' + @REF_DOC_NR_COLUMN + ' = ''' + @REF_DOC_NR + '''
|
||
AND (' + @TARGET_COLUMN + ' = ''' + @STATUS_VALUE + '''
|
||
OR ' + @TARGET_COLUMN + ' LIKE ''%' + @STATUS_VALUE + '''
|
||
OR ' + @TARGET_COLUMN + ' LIKE ''' + @STATUS_VALUE + '%''
|
||
OR ' + @TARGET_COLUMN + ' LIKE ''%' + @STATUS_VALUE + '%'') '
|
||
+ @ADDITIONAL_WHERE;
|
||
PRINT 'Build "status text" Query @SQL_COMMAND: ' + @SQL_COMMAND;
|
||
EXEC @RETURN_STATUS = sp_executesql @SQL_COMMAND,N'@LINE_COUNT_2 INT OUTPUT', @LINE_COUNT_2 OUTPUT;
|
||
|
||
IF (@RETURN_STATUS = 0) BEGIN
|
||
PRINT 'Query was successful!';
|
||
PRINT 'Found: ' + CONVERT(NVARCHAR(25),@LINE_COUNT_2) + ' docs with the status text duplicate!';
|
||
|
||
IF (@LINE_COUNT_2 > 0) BEGIN
|
||
PRINT 'Given status text is already there, no update needed!';
|
||
SET @RETURN_STATUS = 1;
|
||
|
||
END; ELSE BEGIN
|
||
PRINT 'Given status text is not there, update needed!';
|
||
|
||
IF ((@OVERWRITE = 0) and (@LINE_COUNT_1 > 0)) BEGIN
|
||
SET @SQL_COMMAND = N'SELECT TOP 1 @STATUS_VALUE_OLD = ' + @TARGET_COLUMN + '
|
||
FROM ' + @TARGET_DB + '.' + @TARGET_SCHEMA + '.' + @TARGET_TABLE + '
|
||
WHERE ' + @REF_DOC_NR_COLUMN + ' = ''' + @REF_DOC_NR + '''
|
||
AND ' + @TARGET_COLUMN + ' IS NOT NULL
|
||
AND ' + @TARGET_COLUMN + ' <> '''' '
|
||
+ @ADDITIONAL_WHERE;
|
||
PRINT 'Build "status text" Query for existing values @SQL_COMMAND: ' + @SQL_COMMAND;
|
||
PRINT 'Found: ' + CONVERT(NVARCHAR(25),@LINE_COUNT_1) + ' docs with a existing status text!';
|
||
EXEC @RETURN_STATUS = sp_executesql @SQL_COMMAND,N'@STATUS_VALUE_OLD NVARCHAR(256) OUTPUT', @STATUS_VALUE_OLD OUTPUT;
|
||
|
||
IF ((@RETURN_STATUS = 0)) BEGIN
|
||
PRINT 'Query was successful!';
|
||
|
||
IF (@STATUS_VALUE_OLD <> @STATUS_VALUE) BEGIN
|
||
PRINT 'Extending status text';
|
||
SET @STATUS_VALUE = concat(@STATUS_VALUE_OLD,@STATUS_VALUE_DELIMITER,@STATUS_VALUE);
|
||
END;
|
||
|
||
SET @STATUS_VALUE = CASE WHEN LEFT(@STATUS_VALUE,2) = @STATUS_VALUE_DELIMITER
|
||
THEN SUBSTRING(@STATUS_VALUE, 2, LEN(@STATUS_VALUE)-2)
|
||
ELSE @STATUS_VALUE
|
||
END;
|
||
END; ELSE BEGIN
|
||
PRINT 'Query has failed!';
|
||
PRINT '@STATUS_VALUE keeps untouched!';
|
||
END;
|
||
|
||
END; ELSE IF ((@OVERWRITE = 1) or (@LINE_COUNT_1 = 0)) BEGIN
|
||
PRINT 'Overwrite is enabled and or no doc with existing status text found!';
|
||
END;
|
||
|
||
--===========================================-- data collected updating row --=============================================--
|
||
|
||
-- Check STATUS TEXT for its lenght
|
||
SET @STATUS_VALUE = LTRIM(RTRIM(convert(NVARCHAR(MAX),@STATUS_VALUE)))
|
||
IF (LEN(@STATUS_VALUE) > @STATUS_VALUE_MAX_LEN) BEGIN
|
||
SET @STATUS_VALUE = LEFT(@STATUS_VALUE,@STATUS_VALUE_MAX_LEN);
|
||
END;
|
||
|
||
SET @SQL_COMMAND = N'SET NOCOUNT ON; UPDATE ' + @TARGET_DB + '.' + @TARGET_SCHEMA + '.' + @TARGET_TABLE + ' ';
|
||
|
||
IF (@TARGET_COLUMN_TYPE LIKE '%INT%') BEGIN
|
||
SET @STATUS_VALUE = convert(INT,@STATUS_VALUE);
|
||
SET @SQL_COMMAND += ' SET ' + @TARGET_COLUMN + ' = ' + @STATUS_VALUE;
|
||
END; ELSE BEGIN
|
||
-- NVARCHAR is always the failsafe
|
||
SET @SQL_COMMAND += ' SET ' + @TARGET_COLUMN + ' = ''' + @STATUS_VALUE + '''';
|
||
END;
|
||
|
||
SET @SQL_COMMAND += ' WHERE ' + @REF_DOC_NR_COLUMN + ' = ''' + @REF_DOC_NR + ''' ' + @ADDITIONAL_WHERE;
|
||
PRINT 'Build Update @SQL_COMMAND: ' + @SQL_COMMAND;
|
||
EXEC @RETURN_STATUS = sp_executesql @SQL_COMMAND;
|
||
|
||
IF (@RETURN_STATUS = 0) BEGIN
|
||
PRINT 'Update was successful!';
|
||
SET @RETURN_STATUS = 1;
|
||
END; ELSE BEGIN
|
||
PRINT 'Update has failed!';
|
||
PRINT '@RETURN_STATUS: ' + CONVERT(NVARCHAR(50),@RETURN_STATUS);
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
END;
|
||
|
||
END; ELSE BEGIN
|
||
PRINT 'Query has failed!';
|
||
SET @RETURN_STATUS = 0;
|
||
END;
|
||
|
||
END; ELSE BEGIN
|
||
PRINT 'No doc were found!';
|
||
SET @RETURN_STATUS = 0;
|
||
END;
|
||
|
||
END; ELSE BEGIN
|
||
PRINT 'Error at dynamic SQL!';
|
||
SET @RETURN_STATUS = 0;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
IF (@RETURN_STATUS = 1) BEGIN
|
||
SET @RETURN_STATUS_VALUE = 'SUCCESS';
|
||
END; ELSE BEGIN
|
||
SET @RETURN_STATUS_VALUE = 'FAILED';
|
||
END;
|
||
|
||
PRINT '';
|
||
PRINT 'PROCEDURE Result: ' + @RETURN_STATUS_VALUE;
|
||
PRINT 'PROCEDURE - END ' + @MyProcedureName + ' @ ' + CONVERT(NVARCHAR(50),GETDATE(),120);
|
||
PRINT '===============================';
|
||
|
||
--==============================================-- Log result to table --===============================================--
|
||
|
||
IF (@LOGLEVEL in ('INFO','WARN')) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG') BEGIN
|
||
INSERT INTO [TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [MESSAGE5], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES (@LOGLEVEL, concat(@TARGET_DB,'.',@TARGET_SCHEMA,'.',@TARGET_TABLE,'.',@TARGET_COLUMN), concat(@REF_DOC_TYPE,' - Nr: ',@REF_DOC_NR), @STATUS_VALUE, 'OVERWRITE = ' + convert(varchar,@OVERWRITE), @RETURN_STATUS_VALUE, @USERNAME ,GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
RETURN @RETURN_STATUS; -- Because of the target index in windream!
|
||
|
||
END TRY
|
||
BEGIN CATCH
|
||
|
||
-- Handle any errors that occur during the process.
|
||
SELECT ERROR_MESSAGE() AS ErrorMessage;
|
||
|
||
--================================================-- Log error to table --=================================================--
|
||
IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN
|
||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG') BEGIN
|
||
INSERT INTO [TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [MESSAGE5], [ADDED_WHO], [ADDED_WHEN])
|
||
VALUES ('ERROR', concat(@TARGET_DB,'.',@TARGET_SCHEMA,'.',@TARGET_TABLE,'.',@TARGET_COLUMN), concat(@REF_DOC_TYPE,' - Nr: ',@REF_DOC_NR), @STATUS_VALUE, 'OVERWRITE = ' + convert(NVARCHAR,@OVERWRITE), ERROR_MESSAGE(), @USERNAME, GetDate());
|
||
END;
|
||
END;
|
||
-----------------------------------------------------------------------------------------------------------------------------
|
||
|
||
PRINT '';
|
||
PRINT 'PROCEDURE Result: ERROR! ' + ERROR_MESSAGE();
|
||
PRINT 'PROCEDURE - END ' + @MyProcedureName + ' @ ' + CONVERT(varchar(50),GETDATE(),120);
|
||
PRINT '===============================';
|
||
|
||
RETURN 0; -- Because of the target index in windream!
|
||
|
||
END CATCH;
|
||
GO
|
||
|
||
CREATE OR ALTER FUNCTION [dbo].[FNDD_LOGIN_USER_MODULE] (@pUSERNAME VARCHAR(100), @pMODULE_SHORT_NAME VARCHAR(10),@pCLIENTID INTEGER)
|
||
RETURNS @Table TABLE
|
||
(SequentialOrder INT IDENTITY(1, 1),
|
||
USER_ID INTEGER,
|
||
USER_PRENAME VARCHAR(50),
|
||
USER_SURNAME VARCHAR(50),
|
||
USER_SHORTNAME VARCHAR(50),
|
||
USER_EMAIL VARCHAR(100),
|
||
USER_LANGUAGE VARCHAR(10),
|
||
USER_LANGUAGE_ID TINYINT NOT NULL DEFAULT 1,
|
||
USER_DATE_FORMAT VARCHAR(10),
|
||
USER_RIGHT_FILE_DEL BIT,
|
||
MODULE_ACCESS BIT,
|
||
IS_ADMIN BIT,
|
||
USERCOUNT_LOGGED_IN INTEGER,
|
||
COMMENT VARCHAR(500),
|
||
USER_RIGHT2 BIT NOT NULL DEFAULT 1,
|
||
USER_RIGHT3 BIT NOT NULL DEFAULT 0,
|
||
USER_RIGHT4 BIT NOT NULL DEFAULT 0,
|
||
USER_RIGHT5 BIT NOT NULL DEFAULT 0,
|
||
WORKING_MODE VARCHAR(5000) NOT NULL DEFAULT ''
|
||
,ADDITIONAL_TITLE VARCHAR(200))
|
||
AS
|
||
BEGIN
|
||
/*
|
||
This function checks all user-relevant relations an
|
||
*/
|
||
DECLARE
|
||
@RESULT VARCHAR(500),
|
||
@USER_ID INTEGER,
|
||
@USER_PRENAME VARCHAR(50),
|
||
@USER_SURNAME VARCHAR(50),
|
||
@USER_SHORTNAME VARCHAR(50),
|
||
@USER_EMAIL VARCHAR(50),
|
||
@USER_LANGUAGE VARCHAR(10),
|
||
@USER_LANGUAGE_ID TINYINT,
|
||
@USER_DATE_FORMAT VARCHAR(10),
|
||
@IS_IN_MODULE BIT,
|
||
@IS_ADMIN BIT,
|
||
@USER_RIGHT_FILE_DEL BIT,
|
||
@USER_RIGHT2 BIT,
|
||
@USER_RIGHT3 BIT,
|
||
@USER_RIGHT4 BIT,
|
||
@USER_RIGHT5 BIT,
|
||
@USERCOUNT_LOGGED_IN INTEGER,
|
||
@MODULE_NAME VARCHAR(100),
|
||
@MODULE_GUID INTEGER,
|
||
@USER_GROUPNAME VARCHAR(100),
|
||
@ADMIN_GROUPNAME VARCHAR(100),
|
||
@WORKING_MODE VARCHAR(1000),
|
||
@ADDITIONAL_TITLE VARCHAR(500)
|
||
--'PM#NO_MASS_VALIDATOR;PM#FORCE_LAYOUT_OVERVIEW;PM#NO_CHARTS;PM#DEBUG_LOG'
|
||
SET @ADDITIONAL_TITLE = ''
|
||
SET @USER_RIGHT2 = 1 --= DocumentPropertyView only View
|
||
SET @USER_RIGHT3 = 0
|
||
SET @USER_RIGHT4 = 0
|
||
SET @USER_RIGHT5 = 0
|
||
DECLARE @CONN_ID_IDB INTEGER
|
||
SELECT @CONN_ID_IDB = GUID FROM TBDD_CONNECTION WHERE BEZEICHNUNG = 'IDB'
|
||
|
||
|
||
SET @WORKING_MODE = ''
|
||
IF @pMODULE_SHORT_NAME = 'PM'
|
||
BEGIN
|
||
SET @WORKING_MODE = 'OPERATION_MODE_FS=IDB_WM#PM.IDBWITHWMFS#PM.IDB_CONID!' + CONVERT(VARCHAR(2),@CONN_ID_IDB) +
|
||
'#PM.NO_MASS_VALIDATOR' --#PM.NO_CHARTS#PM.DEBUG_LOG#PM.FORCE_LAYOUT_OVERVIEW#PM.IDBWITHWMFS
|
||
+'#PM.MONITORING#PM.COLORSCHEME=Purple#PM.CONV_IDENTIFICATION=Email#PM.INACTIVITY_DURATION=9#PM.COL_LAST_EDITED=[Zuletzt bearbeitet]#PM.COL_LAST_ADDED=[Addedwhen]' --#PM.NO_BASICCONF#PM.NO_DETAIL_PROFILES --PM.SYS_LOCKED_MAINTENANCE#
|
||
+'#PM.SEARCH1=Starte Suche 1~MyExePath\Folder\myexe.exe%--start-search=id|7~doctype|ARE#PM.GHOSTMODE' --#PM.DEBUG_LOG
|
||
+ '#PM.TRAFFICLIGHT_ICON=False#PM.START_CW=Start Globale Suche~-1#PM.RibbonPageCustTitle=WISAG#PM.RibbonPageCustItm1=Anh<6E>nge#PM.ButtonExport2FolderCaption=Export Y:#PM.ButtonExport2Folder_RootFolder=S#PM.ButtonExport2Folder_Mode=Convert to PDF'
|
||
SET @ADDITIONAL_TITLE = 'Mein Workflow zur Demo'
|
||
END
|
||
ELSE IF @pMODULE_SHORT_NAME = 'CW'
|
||
SET @WORKING_MODE = 'NOMATCH_INFO=False#HotkeySearchKey=d#NotifyMode=Msgbox'--#NotifyMode=NotifyIcon'
|
||
ELSE IF @pMODULE_SHORT_NAME = 'ZF'
|
||
SET @WORKING_MODE = 'NO_BASICCONF#NOMATCH_INFO=False#SEARCH_STRING_ATTRID=1,2#SEARCH_INT_ATTRID=5'
|
||
SET @USER_ID = 0
|
||
SET @IS_ADMIN = 0
|
||
SET @IS_IN_MODULE = 0
|
||
SET @USERCOUNT_LOGGED_IN = 0
|
||
SET @RESULT = ''
|
||
IF @pMODULE_SHORT_NAME = 'PM'
|
||
BEGIN
|
||
SET @USER_GROUPNAME = 'PM_USER'
|
||
SET @ADMIN_GROUPNAME = 'PM_ADMINS'
|
||
END
|
||
ELSE IF @pMODULE_SHORT_NAME = 'CW'
|
||
BEGIN
|
||
SET @USER_GROUPNAME = 'CW_USER'
|
||
SET @ADMIN_GROUPNAME = 'CW_ADMINS'
|
||
END
|
||
ELSE IF @pMODULE_SHORT_NAME = 'ADDI'
|
||
BEGIN
|
||
SET @USER_GROUPNAME = 'ADDI_USER'
|
||
SET @ADMIN_GROUPNAME = 'ADDI_ADMINS'
|
||
END
|
||
ELSE IF @pMODULE_SHORT_NAME = 'fileFLOW'
|
||
BEGIN
|
||
SET @USER_GROUPNAME = 'fileFLOW_USER'
|
||
SET @ADMIN_GROUPNAME = 'fileFLOW_ADMINS'
|
||
END
|
||
ELSE IF @pMODULE_SHORT_NAME = 'UM'
|
||
BEGIN
|
||
SET @USER_GROUPNAME = 'XXXX'
|
||
SET @ADMIN_GROUPNAME = 'UM_ADMINS'
|
||
END
|
||
ELSE IF @pMODULE_SHORT_NAME = 'SIG_ENV_CR'
|
||
BEGIN
|
||
SET @USER_GROUPNAME = 'ENVELOPE-CREATOR'
|
||
SET @ADMIN_GROUPNAME = 'XXXX'
|
||
END
|
||
|
||
|
||
SELECT @MODULE_GUID = GUID, @MODULE_NAME = NAME FROM TBDD_MODULES WHERE SHORT_NAME = @pMODULE_SHORT_NAME
|
||
|
||
IF NOT EXISTS(SELECT GUID FROM TBDD_USER WHERE UPPER(USERNAME) = UPPER(@pUSERNAME))
|
||
BEGIN
|
||
SET @RESULT = 'USER NOT CONFIGURED OR LISTED'
|
||
END
|
||
ELSE
|
||
BEGIN
|
||
SELECT @USER_ID = T.GUID,@USER_PRENAME = T.PRENAME,
|
||
@USER_SURNAME = T.NAME
|
||
,@USER_SHORTNAME = T.SHORTNAME
|
||
,@USER_EMAIL = T.EMAIL
|
||
,@USER_LANGUAGE = T.LANGUAGE
|
||
,@USER_DATE_FORMAT = T.DATE_FORMAT
|
||
FROM TBDD_USER T WHERE UPPER(USERNAME) = UPPER(@pUSERNAME)
|
||
|
||
IF @USER_LANGUAGE = 'de-DE'
|
||
SET @USER_LANGUAGE_ID = 1
|
||
ELSE IF @USER_LANGUAGE = 'en-US'
|
||
SET @USER_LANGUAGE_ID = 2
|
||
ELSE IF @USER_LANGUAGE = 'fr-FR'
|
||
SET @USER_LANGUAGE_ID = 3
|
||
--IF @USER_ID = 1
|
||
-- SET @USER_LANGUAGE = 'en-US'
|
||
--##### LICENSE COUNT
|
||
SELECT @USERCOUNT_LOGGED_IN = COUNT(*) FROM TBDD_USER_MODULE_LOG_IN WHERE UPPER(MODULE) = UPPER(@MODULE_NAME) AND CLIENT_ID = @pCLIENTID
|
||
--CHECK USER <20>S IN MODULE_USER_GROUP
|
||
IF EXISTS(select T1.* from TBDD_GROUPS T, TBDD_GROUPS_USER T1 WHERE T.GUID = T1.GROUP_ID AND T1.USER_ID = @USER_ID AND UPPER(T.NAME) = @USER_GROUPNAME)
|
||
BEGIN
|
||
SET @IS_IN_MODULE = 1
|
||
SET @RESULT = 'User is part of Group (' + @USER_GROUPNAME + ')'
|
||
IF EXISTS(select T.* from TBDD_USER_MODULES T WHERE T.USER_ID = @USER_ID AND T.MODULE_ID = @MODULE_GUID)
|
||
BEGIN
|
||
SET @RESULT = @RESULT + '| User is also configured in User-Modules'
|
||
select @IS_ADMIN = T.IS_ADMIN,@USER_RIGHT_FILE_DEL = T.RIGHT1 from TBDD_USER_MODULES T WHERE T.USER_ID = @USER_ID AND T.MODULE_ID = @MODULE_GUID
|
||
END
|
||
END
|
||
ELSE
|
||
BEGIN
|
||
SET @RESULT = 'User not part of group (' + @USER_GROUPNAME + ')'
|
||
IF EXISTS(select T.* from TBDD_USER_MODULES T WHERE T.USER_ID = @USER_ID AND T.MODULE_ID = @MODULE_GUID)
|
||
BEGIN
|
||
SET @RESULT = @RESULT + '| BUT User configured in User-Modules'
|
||
select @IS_ADMIN = T.IS_ADMIN,@USER_RIGHT_FILE_DEL = T.RIGHT1
|
||
--,@USER_RIGHT2 = T.RIGHT2
|
||
from TBDD_USER_MODULES T WHERE T.USER_ID = @USER_ID AND T.MODULE_ID = @MODULE_GUID
|
||
END
|
||
END
|
||
|
||
IF EXISTS(select T1.* from TBDD_GROUPS T, TBDD_GROUPS_USER T1 WHERE T.GUID = T1.GROUP_ID AND T1.USER_ID = @USER_ID AND UPPER(T.NAME) = @ADMIN_GROUPNAME)
|
||
BEGIN
|
||
SET @RESULT = @RESULT + '| User is part of group (' + @ADMIN_GROUPNAME + ')'
|
||
SET @IS_ADMIN = 1
|
||
SET @IS_IN_MODULE = 1
|
||
END
|
||
|
||
END
|
||
|
||
INSERT INTO @Table (USER_ID,USER_PRENAME, USER_SURNAME,USER_SHORTNAME,USER_EMAIL,USER_LANGUAGE,USER_LANGUAGE_ID, USER_DATE_FORMAT, USER_RIGHT_FILE_DEL,
|
||
MODULE_ACCESS,IS_ADMIN,USERCOUNT_LOGGED_IN, COMMENT,WORKING_MODE,USER_RIGHT2,USER_RIGHT3,USER_RIGHT4,USER_RIGHT5
|
||
,ADDITIONAL_TITLE)
|
||
VALUES (@USER_ID,@USER_PRENAME,@USER_SURNAME,@USER_SHORTNAME,@USER_EMAIL,@USER_LANGUAGE,@USER_LANGUAGE_ID,@USER_DATE_FORMAT,@USER_RIGHT_FILE_DEL,
|
||
@IS_IN_MODULE,@IS_ADMIN,@USERCOUNT_LOGGED_IN,@RESULT,@WORKING_MODE,@USER_RIGHT2,@USER_RIGHT3,@USER_RIGHT4,@USER_RIGHT5
|
||
,@ADDITIONAL_TITLE)
|
||
|
||
RETURN
|
||
END
|
||
GO
|
||
|
||
CREATE VIEW VWDD_USER_GROUP_MODULE
|
||
AS
|
||
select
|
||
T1.NAME AS GROUP_NAME,
|
||
TU.*
|
||
FROM
|
||
TBDD_GROUPS_USER T,
|
||
TBDD_GROUPS T1,
|
||
TBDD_USER TU
|
||
WHERE
|
||
TU.NAME IS NOT NULL
|
||
AND TU.PRENAME IS NOT NULL
|
||
AND T1.INTERNAL = 1
|
||
AND T.GROUP_ID = T1.GUID
|
||
AND T.USER_ID = TU.GUID
|
||
--AND T1.NAME IN ('CW_USER','CW_ADMINS')
|
||
|
||
UNION
|
||
|
||
SELECT
|
||
T2.NAME AS GROUP_MODULE,
|
||
TU.*
|
||
|
||
FROM
|
||
TBDD_USER TU,
|
||
TBDD_USER_MODULES T1,
|
||
TBDD_MODULES T2
|
||
WHERE
|
||
TU.NAME IS NOT NULL
|
||
AND TU.PRENAME IS NOT NULL
|
||
AND TU.GUID = T1.USER_ID
|
||
AND T1.MODULE_ID = T2.GUID
|
||
GO
|
||
CREATE VIEW VWDD_USER_MODULE_CW
|
||
AS
|
||
SELECT
|
||
DISTINCT GUID ,
|
||
USERNAME,
|
||
NAME,
|
||
PRENAME,
|
||
EMAIL
|
||
FROM
|
||
VWDD_USER_GROUP_MODULE
|
||
WHERE
|
||
GROUP_NAME IN ('Clipboard-Watcher','CW_USER','CW_ADMINS')
|
||
GO
|
||
CREATE FUNCTION [dbo].[FNDD_GET_USER_FOR_GROUP] (@pGROUP_ID INTEGER,@pONLY_FREE BIT)
|
||
RETURNS @Table TABLE
|
||
(USER_ID INTEGER,
|
||
USER_PRENAME VARCHAR(50),
|
||
USER_SURNAME VARCHAR(50),
|
||
USER_SHORTNAME VARCHAR(50),
|
||
USER_EMAIL VARCHAR(100),
|
||
USER_LANGUAGE VARCHAR(10),
|
||
COMMENT VARCHAR(500))
|
||
AS
|
||
BEGIN
|
||
IF @pONLY_FREE = 1
|
||
INSERT INTO @Table (USER_ID,USER_PRENAME,USER_SURNAME,USER_SHORTNAME,USER_EMAIL,USER_LANGUAGE,COMMENT)
|
||
select T.GUID, T.PRENAME, T.NAME, T.SHORTNAME, T.EMAIL,T.LANGUAGE, T.COMMENT FROM TBDD_USER T, TBDD_GROUPS_USER T1 WHERE T1.USER_ID = T.GUID AND
|
||
T.GUID NOT IN (SELECT USER_ID FROM TBDD_GROUPS_USER WHERE GROUP_ID = @pGROUP_ID)
|
||
ELSE
|
||
INSERT INTO @Table (USER_ID,USER_PRENAME,USER_SURNAME,USER_SHORTNAME,USER_EMAIL,USER_LANGUAGE,COMMENT)
|
||
select T.GUID, T.PRENAME, T.NAME, T.SHORTNAME, T.EMAIL,T.LANGUAGE, T.COMMENT FROM TBDD_USER T, TBDD_GROUPS_USER T1 WHERE T1.USER_ID = T.GUID AND T1.GROUP_ID = @pGROUP_ID
|
||
|
||
RETURN
|
||
END
|
||
GO
|
||
|
||
-- 20.09.2024 MS fileFLOW as Module
|
||
CREATE FUNCTION [dbo].[FNDD_GET_USER_FOR_MODULE] (@pMODULE_SHORT_NAME VARCHAR(10),@pCLIENTID INTEGER)
|
||
RETURNS
|
||
@Table TABLE
|
||
(SequentialOrder INT IDENTITY(1, 1),
|
||
USER_ID INTEGER,
|
||
USER_NAME VARCHAR(50),
|
||
USER_PRENAME VARCHAR(50),
|
||
USER_SURNAME VARCHAR(50),
|
||
USER_SHORTNAME VARCHAR(50),
|
||
USER_EMAIL VARCHAR(100),
|
||
USER_LANGUAGE VARCHAR(10),
|
||
USER_RIGHT_FILE_DEL BIT,
|
||
MODULE_ACCESS BIT,
|
||
IS_ADMIN BIT,
|
||
USER_COMMENT VARCHAR(500),
|
||
COMMENT VARCHAR(500))
|
||
AS
|
||
BEGIN
|
||
/*
|
||
This function checks all user-relevant relations an
|
||
*/
|
||
DECLARE
|
||
@RESULT VARCHAR(500),
|
||
@USER_ID INTEGER,
|
||
@USER_NAME VARCHAR(50),
|
||
@USER_PRENAME VARCHAR(50),
|
||
@USER_SURNAME VARCHAR(50),
|
||
@USER_SHORTNAME VARCHAR(50),
|
||
@USER_EMAIL VARCHAR(50),
|
||
@USER_LANGUAGE VARCHAR(10),
|
||
@IS_IN_MODULE BIT,
|
||
@IS_ADMIN BIT,
|
||
@USER_RIGHT_FILE_DEL BIT,
|
||
@MODULE_NAME VARCHAR(100),
|
||
@MODULE_GUID INTEGER,
|
||
@USER_GROUPNAME VARCHAR(100),
|
||
@ADMIN_GROUPNAME VARCHAR(100),
|
||
@USER_COMMENT VARCHAR(500)
|
||
|
||
IF @pMODULE_SHORT_NAME = 'PM'
|
||
BEGIN
|
||
SET @USER_GROUPNAME = 'PM_USER'
|
||
SET @ADMIN_GROUPNAME = 'PM_ADMINS'
|
||
END
|
||
ELSE IF @pMODULE_SHORT_NAME = 'CW'
|
||
BEGIN
|
||
SET @USER_GROUPNAME = 'CW_USER'
|
||
SET @ADMIN_GROUPNAME = 'CW_ADMINS'
|
||
END
|
||
ELSE IF @pMODULE_SHORT_NAME = 'ADDI'
|
||
BEGIN
|
||
SET @USER_GROUPNAME = 'ADDI_USER'
|
||
SET @ADMIN_GROUPNAME = 'ADDI_ADMINS'
|
||
END
|
||
ELSE IF @pMODULE_SHORT_NAME = 'fileFLOW'
|
||
BEGIN
|
||
SET @USER_GROUPNAME = 'fileFLOW_USER'
|
||
SET @ADMIN_GROUPNAME = 'fileFLOW_ADMINS'
|
||
END
|
||
ELSE IF @pMODULE_SHORT_NAME = 'UM'
|
||
BEGIN
|
||
SET @USER_GROUPNAME = 'XXXX'
|
||
SET @ADMIN_GROUPNAME = 'UM_ADMINS'
|
||
END
|
||
SELECT @MODULE_GUID = GUID, @MODULE_NAME = NAME FROM TBDD_MODULES WHERE SHORT_NAME = @pMODULE_SHORT_NAME
|
||
|
||
DECLARE cursor_user CURSOR FOR
|
||
select GUID, ISNULL(PRENAME,'no prename'), ISNULL(NAME,'no name'), ISNULL(SHORTNAME,'no shortname'), ISNULL(EMAIL,'no email'), LANGUAGE,USERNAME,COMMENT from TBDD_USER
|
||
OPEN cursor_user
|
||
FETCH NEXT FROM cursor_user INTO @USER_ID,@USER_PRENAME,@USER_SURNAME,@USER_SHORTNAME,@USER_EMAIL,@USER_LANGUAGE,@USER_NAME,@USER_COMMENT
|
||
WHILE @@FETCH_STATUS = 0
|
||
BEGIN
|
||
SET @IS_ADMIN = 0
|
||
SET @IS_IN_MODULE = 0
|
||
SET @RESULT = ''
|
||
--CHECK USER IS IN MODULE_USER_GROUP
|
||
IF EXISTS(select T1.* from TBDD_GROUPS T, TBDD_GROUPS_USER T1 WHERE T.GUID = T1.GROUP_ID AND T1.USER_ID = @USER_ID AND UPPER(T.NAME) = @USER_GROUPNAME)
|
||
BEGIN
|
||
SET @IS_IN_MODULE = 1
|
||
SET @RESULT = 'User is part of Group (' + @USER_GROUPNAME + ')'
|
||
IF EXISTS(select T.* from TBDD_USER_MODULES T WHERE T.USER_ID = @USER_ID AND T.MODULE_ID = @MODULE_GUID)
|
||
BEGIN
|
||
SET @RESULT = @RESULT + '| User is also configured in User-Modules (Unnecessary)'
|
||
select @IS_ADMIN = T.IS_ADMIN,@USER_RIGHT_FILE_DEL = T.RIGHT1 from TBDD_USER_MODULES T WHERE T.USER_ID = @USER_ID AND T.MODULE_ID = @MODULE_GUID
|
||
|
||
END
|
||
END
|
||
ELSE
|
||
BEGIN
|
||
SET @RESULT = 'User <' + CONVERT(VARCHAR(10),@USER_ID) + ' - ' + @USER_NAME + '> not part of group (' + @USER_GROUPNAME + ')'
|
||
IF EXISTS(select T.* from TBDD_USER_MODULES T WHERE T.USER_ID = @USER_ID AND T.MODULE_ID = @MODULE_GUID)
|
||
BEGIN
|
||
SET @RESULT = @RESULT + '| BUT User configured in User-Modules'
|
||
select @IS_ADMIN = T.IS_ADMIN,@USER_RIGHT_FILE_DEL = T.RIGHT1 from TBDD_USER_MODULES T WHERE T.USER_ID = @USER_ID AND T.MODULE_ID = @MODULE_GUID
|
||
SET @IS_IN_MODULE = 1
|
||
END
|
||
END
|
||
|
||
IF EXISTS(select T1.* from TBDD_GROUPS T, TBDD_GROUPS_USER T1 WHERE T.GUID = T1.GROUP_ID AND T1.USER_ID = @USER_ID AND UPPER(T.NAME) = @ADMIN_GROUPNAME)
|
||
BEGIN
|
||
SET @RESULT = @RESULT + '| User is part of group (' + @ADMIN_GROUPNAME + ')'
|
||
SET @IS_ADMIN = 1
|
||
SET @IS_IN_MODULE = 1
|
||
END
|
||
--PRINT @RESULT
|
||
IF @IS_IN_MODULE = 1
|
||
INSERT INTO @Table (USER_ID,USER_NAME, USER_PRENAME, USER_SURNAME,USER_SHORTNAME,USER_EMAIL,USER_LANGUAGE, USER_RIGHT_FILE_DEL, MODULE_ACCESS,IS_ADMIN,USER_COMMENT,COMMENT)
|
||
VALUES (@USER_ID,@USER_NAME,@USER_PRENAME,@USER_SURNAME,@USER_SHORTNAME,@USER_EMAIL,@USER_LANGUAGE,@USER_RIGHT_FILE_DEL,@IS_IN_MODULE,@IS_ADMIN,@USER_COMMENT,@RESULT)
|
||
FETCH NEXT FROM cursor_user INTO @USER_ID,@USER_PRENAME,@USER_SURNAME,@USER_SHORTNAME,@USER_EMAIL,@USER_LANGUAGE,@USER_NAME,@USER_COMMENT
|
||
END
|
||
CLOSE cursor_user
|
||
DEALLOCATE cursor_user
|
||
RETURN
|
||
END
|
||
GO
|
||
|
||
CREATE FUNCTION [dbo].[FNDD_LANGUAGE_PHRASE](@pTITLE VARCHAR(100),@pLANG_CODE VARCHAR(5), @pMODULE VARCHAR(10))
|
||
RETURNS VARCHAR(500)
|
||
AS
|
||
BEGIN
|
||
DECLARE @RESULT VARCHAR(250), @CTRL_CONFIG_TITLE VARCHAR(100)
|
||
|
||
SELECT @RESULT = STRING1 FROM TBDD_GUI_LANGUAGE_PHRASE
|
||
WHERE MODULE = @pMODULE AND TITLE = @pTITLE
|
||
AND [LANGUAGE] = @pLANG_CODE
|
||
IF LEN(@RESULT) > 0
|
||
SET @RESULT = @RESULT
|
||
ELSE
|
||
BEGIN
|
||
SELECT @RESULT = STRING1 FROM TBDD_GUI_LANGUAGE_PHRASE
|
||
WHERE MODULE = @pMODULE AND TITLE = @pTITLE
|
||
AND [LANGUAGE] = 'de-DE'
|
||
SET @RESULT = @RESULT + ' (NoLangConf)'
|
||
END
|
||
|
||
RETURN @RESULT
|
||
END
|
||
GO
|
||
|
||
CREATE PROCEDURE [dbo].[PRDD_GUI_LANGUAGE_PHRASE] (@pMODULE VARCHAR(10),@pTITLE VARCHAR(100),@pLANG_CODE VARCHAR(5),@pCAPTION_TYPE VARCHAR(50),@pSTRING1 VARCHAR(900),@pSTRING2 VARCHAR(900),@pWHO VARCHAR(100)
|
||
,@pOBJ_NAME VARCHAR(100),@pINTERNAL BIT)
|
||
AS
|
||
If NOT EXISTS(SELECT GUID FROm TBDD_GUI_LANGUAGE_PHRASE WHERE [MODULE] = @pMODULE AND TITLE = @pTITLE AND [LANGUAGE] = @pLANG_CODE)
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE]
|
||
,[TITLE]
|
||
,[LANGUAGE]
|
||
,[CAPT_TYPE]
|
||
,[STRING1]
|
||
,STRING2
|
||
,[ADDED_WHO]
|
||
,[OBJ_NAME],INTERNAL) VALUES
|
||
(@pMODULE,@pTITLE,@pLANG_CODE,@pCAPTION_TYPE,@pSTRING1,@pSTRING2,@pWHO,@pOBJ_NAME,@pINTERNAL)
|
||
ELSE
|
||
UPDATE [dbo].[TBDD_GUI_LANGUAGE_PHRASE] SET [CAPT_TYPE] = @pCAPTION_TYPE
|
||
,[STRING1] = @pSTRING1
|
||
,STRING2 = @pSTRING2
|
||
,CHANGED_WHO = @pWHO
|
||
,[OBJ_NAME] = @pOBJ_NAME,INTERNAL = @pINTERNAL WHERE
|
||
[MODULE] = @pMODULE AND TITLE = @pTITLE AND [LANGUAGE] = @pLANG_CODE
|
||
GO
|
||
IF NOT EXISTS(SELECT 1 FROM sys.columns
|
||
WHERE Name = N'ARCHIVE_FOLDER'
|
||
AND Object_ID = Object_ID(N'dbo.TBDD_EMAIL_ACCOUNT'))
|
||
BEGIN
|
||
-- Column Exists
|
||
ALTER TABLE TBDD_EMAIL_ACCOUNT ADD ARCHIVE_FOLDER VARCHAR(100) NOT NULL DEFAULT ''
|
||
END
|
||
GO
|
||
CREATE TABLE TBDD_LANGUAGE
|
||
(
|
||
GUID TINYINT NOT NULL IDENTITY (1, 1),
|
||
LANG_CODE VARCHAR(10) NOT NULL,
|
||
CREATE_DEFAULT_ENTRY BIT NOT NULL DEFAULT 0,
|
||
COMMENT VARCHAR(1000),
|
||
ADDED_WHO VARCHAR(30) NOT NULL DEFAULT 'SYSTEM',
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT (GETDATE()),
|
||
CHANGED_WHO VARCHAR(30),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBDD_LANGUAGE PRIMARY KEY (GUID),
|
||
CONSTRAINT UQ_TBDD_LANGUAGE UNIQUE (LANG_CODE)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBDD_LANGUAGE_AFT_UPD ON TBDD_LANGUAGE
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBDD_LANGUAGE SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBDD_LANGUAGE.GUID = INSERTED.GUID
|
||
GO
|
||
INSERT INTO TBDD_LANGUAGE (LANG_CODE,CREATE_DEFAULT_ENTRY) VALUES ('de-DE',1);
|
||
INSERT INTO TBDD_LANGUAGE (LANG_CODE,CREATE_DEFAULT_ENTRY) VALUES ('en-EN',1);
|
||
INSERT INTO TBDD_LANGUAGE (LANG_CODE,CREATE_DEFAULT_ENTRY) VALUES ('fr-FR',1);
|
||
GO
|
||
IF NOT EXISTS(SELECT 1 FROM sys.columns
|
||
WHERE Name = N'LANGUAGE_OVERRIDE'
|
||
AND Object_ID = Object_ID(N'dbo.TBDD_USER_MODULE_LOG_IN'))
|
||
BEGIN
|
||
-- Column Exists
|
||
ALTER TABLE TBDD_USER_MODULE_LOG_IN ADD LANGUAGE_OVERRIDE VARCHAR(5) NOT NULL DEFAULT ''
|
||
END
|
||
ELSE
|
||
PRINT 'COLUMN LANGUAGE_OVERRIDE EXISTS'
|
||
GO
|
||
IF NOT EXISTS(SELECT 1 FROM sys.columns
|
||
WHERE Name = N'LANGUAGE_OVERRIDE'
|
||
AND Object_ID = Object_ID(N'dbo.TBDD_USER_LOGIN_OUT'))
|
||
BEGIN
|
||
-- Column Exists
|
||
ALTER TABLE TBDD_USER_LOGIN_OUT ADD LANGUAGE_OVERRIDE VARCHAR(5) NOT NULL DEFAULT ''
|
||
END
|
||
ELSE
|
||
PRINT 'COLUMN LANGUAGE_OVERRIDE EXISTS'
|
||
GO
|
||
|
||
CREATE TABLE TBDD_USER_LOG_IN_ATTEMPT(
|
||
GUID BIGINT IDENTITY(1,1) NOT NULL,
|
||
USERNAME VARCHAR(100),
|
||
MODULE VARCHAR(30),
|
||
APP_STARTUP_PATH VARCHAR(1000),
|
||
VERSION_CLIENT VARCHAR(30),
|
||
MACHINE_NAME VARCHAR(250),
|
||
OVERRIDE_LANGUAGE VARCHAR(5),
|
||
[LOGIN] DATETIME DEFAULT (GETDATE()),
|
||
CONSTRAINT [PK_TBDD_USER_LOG_IN_ATTEMPT] PRIMARY KEY(GUID))
|
||
GO
|
||
CREATE TABLE TBDD_USER_CHANGE_LOG(
|
||
GUID BIGINT IDENTITY(1,1) NOT NULL,
|
||
USR_ID INTEGER NOT NULL,
|
||
COMMENT VARCHAR(3000),
|
||
CONSTRAINT [PK_TBDD_USER_CHANGE_LOG] PRIMARY KEY(GUID))
|
||
GO
|
||
|
||
CREATE TRIGGER [dbo].[TBDD_USER_AFT_UPD_LOG] ON [dbo].[TBDD_USER]
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
DECLARE @USRNAME VARCHAR(50),@LANGUAGE VARCHAR(5),@CHANGED_WHO VARCHAR(100),@USR_ID INTEGER, @COMMENT VARCHAR(1000)
|
||
SELECT @USRNAME = USERNAME,@LANGUAGE = LANGUAGE,@CHANGED_WHO = CHANGED_WHO,@USR_ID = GUID FROM inserted
|
||
|
||
IF UPDATE (LANGUAGE) AND @CHANGED_WHO LIKE 'LANG_CHANGE_GUI%'
|
||
BEGIN
|
||
SET @COMMENT = 'USER CHANGED LANGUAGE TO [' + @LANGUAGE + ']'
|
||
INSERT INTO [dbo].[TBDD_USER_CHANGE_LOG]
|
||
([USR_ID],[COMMENT])
|
||
VALUES
|
||
(@USR_ID,@COMMENT)
|
||
END
|
||
END
|
||
GO
|
||
|
||
CREATE OR ALTER VIEW [dbo].[VWDD_GROUPS_USER] AS
|
||
select
|
||
USR.GUID AS USR_ID
|
||
,USR.USERNAME,
|
||
GRP.GUID AS GRP_ID
|
||
,GRP.NAME AS GRP_NAME
|
||
,GU.ADDED_WHEN
|
||
,GU.ADDED_WHO
|
||
from
|
||
TBDD_GROUPS GRP INNER JOIN TBDD_GROUPS_USER GU ON GRP.GUID = GU.GROUP_ID
|
||
INNER JOIN TBDD_USER USR ON GU.USER_ID = USR.GUID;
|
||
GO
|
||
Insert INTO TBDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE
|
||
(SPECNAME, Row_Caption, Area, xPosition, SequenceItem, Y_eq_lastrow, Display) values
|
||
('INVOICE_TYPE', '', 'TYPE', 10, 1, 0, 0),
|
||
('INVOICE_CURRENCY', '', 'TYPE', 10, 2, 0, 0),
|
||
('INVOICE_NUMBER', 'Rechnungsnummer/Invoice-No:', 'HEAD', 10, 3, 0, 1),
|
||
('INVOICE_DATE', 'Datum/Date:', 'HEAD', 10, 4, 0, 1),
|
||
('INVOICE_SERVICE_DATE','Leistungsdatum/Service date:', 'HEAD', 10, 5, 0, 1),
|
||
('INVOICE_SELLER_NAME', '', 'SELLER', 10, 6, 0, 1),
|
||
('INVOICE_SELLER_ADDRESS', '', 'SELLER', 10, 7, 0, 1),
|
||
('INVOICE_SELLER_POSTALCODE', '', 'SELLER', 10, 8, 0, 1),
|
||
('INVOICE_SELLER_CITY', '', 'SELLER', 35, 9, 1, 1),
|
||
('INVOICE_SELLER_TAX_ID', 'USt-ID/Seller tax ID:', 'SELLER', 10, 10, 0, 1),
|
||
('INVOICE_SELLER_ID', 'Lieferant-Nr/Seller ID:', 'SELLER', 10, 10, 0, 1),
|
||
('INVOICE_BUYER_NAME', '', 'BUYER', 10, 11, 0, 1),
|
||
('INVOICE_BUYER_ADRESS', '', 'BUYER', 10, 12, 0, 1),
|
||
('INVOICE_BUYER_POSTALCODE', '', 'BUYER', 10, 13, 0, 1),
|
||
('INVOICE_BUYER_CITY', '', 'BUYER', 35, 14, 1, 1),
|
||
--('STATIC_Y_SWITCH', '271', 'INTERNAL', 35, 15, 0, 0),
|
||
('INVOICE_POSITION_AMOUNT', '', 'POSITION', 10, 16, 0, 0),
|
||
('INVOICE_POSITION_ARTICLE', '', 'POSITION', 10, 17, 0, 0),
|
||
('INVOICE_TAXPOS_TAX_RATE', '', 'POSITION', 10, 18, 0, 0),
|
||
('INVOICE_POSITION_TAX_AMOUNT', '', 'POSITION', 10, 19, 0, 1),
|
||
('INVOICE_TOTAL_NET', 'Nettobetrag/Net amount:', 'AMOUNT', 10, 400, 0, 1),
|
||
('INVOICE_TOTAL_TAX', 'Steuerbetrag/Tax amount:', 'AMOUNT', 10, 401, 0, 1),
|
||
('INVOICE_TOTAL_GROSS', 'Bruttobetrag/Gross amount:', 'AMOUNT', 10, 402, 0, 1),
|
||
('INVOICE_TAXPOS_RATE', '', 'TAXPOS', 10, 403, 1, 0),
|
||
('INVOICE_TAXPOS_AMOUNT', '', 'TAXPOS', 10, 404, 0, 0),
|
||
('INVOICE_TAXPOS_TYPE', '', 'TAXPOS', 10, 405, 1, 1),
|
||
('INVOICE_PAYMENT_TERMS','', 'PAYMENT', 10, 500, 0, 1),
|
||
('INVOICE_PAYMENT_IBAN','IBAN:', 'PAYMENT', 10, 501, 0, 1),
|
||
('INVOICE_PAYMENT_BIC','BIC:', 'PAYMENT', 10, 502, 0, 1);
|
||
GO
|
||
CREATE PROCEDURE [dbo].[PRDD_DELETE_GROUP](@pGROUP_ID INT)
|
||
AS
|
||
BEGIN TRY
|
||
-- COMMON
|
||
IF OBJECT_ID(N'dbo.TBDD_GROUPS_USER', N'U') IS NOT NULL
|
||
DELETE FROM TBDD_GROUPS_USER WHERE GROUP_ID = @pGROUP_ID
|
||
IF OBJECT_ID(N'dbo.TBDD_GROUPS_CLIENT', N'U') IS NOT NULL
|
||
DELETE FROM TBDD_GROUPS_CLIENT WHERE GROUP_ID = @pGROUP_ID
|
||
IF OBJECT_ID(N'dbo.TBDD_GROUPS_MODULES', N'U') IS NOT NULL
|
||
DELETE FROM TBDD_GROUPS_MODULES WHERE GROUP_ID = @pGROUP_ID
|
||
|
||
-- FINALLY
|
||
DELETE FROM TBDD_GROUPS WHERE GUID = @pGROUP_ID
|
||
|
||
RETURN 0
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'FEHLER IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE()) + ' - ZEILE: ' + CONVERT(VARCHAR(10),ERROR_LINE())
|
||
+ ' - FEHLER-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
RETURN -1
|
||
END CATCH
|
||
--USER MANAGER
|
||
UPDATE TBDD_MODULES SET PRODUCT_VERSION = '1.0.0.1' where SHORT_NAME = 'UM'
|
||
GO
|
||
|
||
DECLARE @UM_GROUP_ID INT
|
||
SELECT @UM_GROUP_ID = GUID FROM TBDD_GROUPS WHERE NAME = 'UM_ADMINS'
|
||
INSERT INTO TBDD_GROUPS_USER (GROUP_ID,USER_ID)
|
||
SELECT @UM_GROUP_ID,B.GUID FROM TBDD_USER
|
||
GO
|
||
CREATE TABLE TBUM_AD_COMMAND
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
AD_CMD_NAME VARCHAR(250),
|
||
COMMAND_STRING VARCHAR(MAX),
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DEFAULT' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBUM_AD_COMMAND PRIMARY KEY (GUID),
|
||
CONSTRAINT UC_TBUM_AD_COMMAND UNIQUE (AD_CMD_NAME),
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBUM_AD_COMMAND_AFT_UPD ON TBUM_AD_COMMAND
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBUM_AD_COMMAND SET CHANGED_WHEN = GETDATE() FROM INSERTED
|
||
WHERE TBUM_AD_COMMAND.GUID = INSERTED.GUID
|
||
GO
|
||
|
||
|
||
GO
|
||
|
||
/*######################################################
|
||
--ToolCollection
|
||
########################################################*/
|
||
-- Replace @WINDREAM_DB in code with name of WM-Database
|
||
IF not EXISTS(SELECT GUID FROM TBDD_MODULES WHERE NAME = 'ToolCollection' )
|
||
INSERT INTO TBDD_MODULES (NAME, SHORT_NAME, LICENSE,ACTIVE) VALUES ('ToolCollection','TC','kc6j9HSv/UJVAzFjMZv2A3wHZFy+2nNLKP9Qs8g9EVY=',1)
|
||
UPDATE TBDD_MODULES SET DB_VERSION = '1.1.0.0' where UPPER(NAME) = UPPER('ToolCollection')
|
||
GO
|
||
CREATE TABLE TBTC_MOVE_RENAME
|
||
(
|
||
GUID INT IDENTITY(1,1),
|
||
PROFILE_NAME VARCHAR(100) NOT NULL,
|
||
FOLDER_FOR_INDEX VARCHAR(500) DEFAULT '' NOT NULL,
|
||
NAMECONVENTION VARCHAR(500) NOT NULL DEFAULT '',
|
||
VERSION_OFF BIT DEFAULT 0 NOT NULL,
|
||
ACTIVE BIT DEFAULT 1 NOT NULL,
|
||
CREATED_WHO VARCHAR(50) DEFAULT 'DEFAULT' NOT NULL,
|
||
CREATED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBTC_MOVE_RENAME PRIMARY KEY(GUID),
|
||
CONSTRAINT UNIQUE_TBTC_MOVE_RENAME UNIQUE(PROFILE_NAME)
|
||
)
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
|
||
CREATE TRIGGER TBTC_MOVE_RENAME_AFT_UPD ON TBTC_MOVE_RENAME
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN TRY
|
||
UPDATE TBTC_MOVE_RENAME SET CHANGED_WHEN = GETDATE() FROM INSERTED
|
||
WHERE TBTC_MOVE_RENAME.GUID = INSERTED.GUID
|
||
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'ERROR IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE())
|
||
+ ' - ERROR-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
END CATCH
|
||
GO
|
||
|
||
CREATE TABLE TBTC_DI_REGEX_MATCH
|
||
(
|
||
GUID INT IDENTITY(1,1),
|
||
PROFIL_NAME VARCHAR(250) NOT NULL,
|
||
REGEX VARCHAR(1000) NOT NULL,
|
||
CREATED_WHO VARCHAR(50) DEFAULT 'DEFAULT' NOT NULL,
|
||
CREATED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBTC_DI_REGEX_MATCH PRIMARY KEY(GUID),
|
||
CONSTRAINT UNIQUE_TBTC_DI_REGEX_MATCH UNIQUE(PROFIL_NAME)
|
||
)
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
|
||
CREATE TRIGGER TBTC_DI_REGEX_MATCH_AFT_UPD ON TBTC_DI_REGEX_MATCH
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN TRY
|
||
UPDATE TBTC_DI_REGEX_MATCH SET CHANGED_WHEN = GETDATE() FROM INSERTED
|
||
WHERE TBTC_DI_REGEX_MATCH.GUID = INSERTED.GUID
|
||
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'ERROR IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE())
|
||
+ ' - ERROR-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
END CATCH
|
||
GO
|
||
--###################################################################################################
|
||
--######################## EMAIL-PROFILER ###########################################################
|
||
--###################################################################################################
|
||
IF NOT EXISTS(SELECT GUID FROM TBDD_MODULES WHERE SHORT_NAME = 'EMLP')
|
||
INSERT INTO TBDD_MODULES(GUID,NAME,SHORT_NAME,LICENSE,STRING1,DB_VERSION) VALUES
|
||
(6,'Email-Profiler','EMLP','kc6j9HSv/UJVAzFjMZv2A3wHZFy+2nNLKP9Qs8g9EVY=','W','1.3.5.0')
|
||
GO
|
||
CREATE TABLE TBEMLP_CONFIG
|
||
(
|
||
GUID TINYINT,
|
||
FONT_BODY VARCHAR(50) NOT NULL DEFAULT 'Calibri',
|
||
LOG_ERRORS_ONLY BIT NOT NULL DEFAULT 1,
|
||
CHECK_INTERVALL_MINUTES INTEGER NOT NULL DEFAULT 5,
|
||
LAST_TICK DATETIME,
|
||
PATH_EMAIL_TEMP VARCHAR(1000) NOT NULL,
|
||
PATH_EMAIL_ERRORS VARCHAR(1000) NOT NULL,
|
||
WM_CON_STRING VARCHAR(1000) NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBEMLP_CONFIG_GUID PRIMARY KEY(GUID),
|
||
CONSTRAINT CH_TBEMLP_CONFIG_GUID CHECK(GUID = 1)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBEMLP_CONFIG_AFT_UPD ON TBEMLP_CONFIG
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBEMLP_CONFIG SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBEMLP_CONFIG.GUID = INSERTED.GUID
|
||
GO
|
||
INSERT INTO TBEMLP_CONFIG (GUID, PATH_EMAIL_TEMP,PATH_EMAIL_ERRORS,WM_CON_STRING) VALUES (1,'E:\TEMP\EMAIL_PROFILER\TEMP','E:\TEMP\EMAIL_PROFILER\ERROR','Data Source=172.24.12.41\tests;Initial Catalog=DD_ECM;Persist Security Info=True;User ID=sa;Password=dd')
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
|
||
CREATE TABLE TBEMLP_POLL_PROFILES
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
PROFILE_NAME VARCHAR(100) NOT NULL,
|
||
POLL_TYPE VARCHAR(100) NOT NULL, --IMAP OR POP
|
||
EMAIL_CONF_ID INTEGER NOT NULL,
|
||
COMMENT VARCHAR(500),
|
||
LAST_TICK DATETIME,
|
||
ACTIVE BIT DEFAULT 0 NOT NULL,
|
||
VALIDATION_SQL NVARCHAR(MAX) NOT NULL DEFAULT '',
|
||
SEQUENCE INT DEFAULT 1,
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'Default',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBEMLP_POLL_PROFILES PRIMARY KEY (GUID)
|
||
)
|
||
GO
|
||
INSERT INTO TBEMLP_POLL_PROFILES (PROFILE_NAME,POLL_TYPE,EMAIL_CONF_ID) VALUES ('TEST1','POP',1)
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
CREATE TRIGGER TBEMLP_POLL_PROFILES_AFT_UPD ON TBEMLP_POLL_PROFILES
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBEMLP_POLL_PROFILES SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBEMLP_POLL_PROFILES.GUID = INSERTED.GUID
|
||
GO
|
||
CREATE TABLE TBEMLP_POLL_PROCESS
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
PROCESS_NAME VARCHAR(100) NOT NULL,
|
||
STEP_NAME VARCHAR(50) NOT NULL, --'Easy Approval' bei ProcessManager,
|
||
PROFILE_ID INTEGER NOT NULL,
|
||
COPY_2_HDD BIT NOT NULL DEFAULT 0,
|
||
ALLOW_XML_RECEIPTS BIT NOT NULL DEFAULT 0,
|
||
WM_IDX_BODY_TEXT VARCHAR(50) NOT NULL DEFAULT '',
|
||
WM_IDX_BODY_SUBSTR_LENGTH INTEGER NOT NULL DEFAULT 0,
|
||
WM_IMPORT BIT NOT NULL DEFAULT 0,
|
||
WM_OBJEKTTYPE VARCHAR(100),
|
||
WM_VECTOR_LOG VARCHAR(100),
|
||
WM_PATH VARCHAR(1000),
|
||
WM_FILE_NAME VARCHAR(100),
|
||
WM_REFERENCE_INDEX VARCHAR(100),
|
||
PATH_EMAIL_TEMP VARCHAR(1000) NOT NULL DEFAULT '',
|
||
PATH_EMAIL_ERRORS VARCHAR(1000) NOT NULL DEFAULT '',
|
||
PATH_ORIGINAL VARCHAR(1000),
|
||
DELETE_MAIL BIT NOT NULL DEFAULT 0,
|
||
USE_FOR_DIRECT_ANSWER BIT NOT NULL DEFAULT 0,
|
||
COMMENT VARCHAR(500),
|
||
ACTIVE BIT DEFAULT 1 NOT NULL, --
|
||
SEQUENCE INT DEFAULT 1,
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'Default',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBEMLP_POLL_PROCESS PRIMARY KEY (GUID),
|
||
CONSTRAINT FK_TBEMLP_POLL_PROCESS_PROFILE_ID FOREIGN KEY (PROFILE_ID) REFERENCES TBEMLP_POLL_PROFILES (GUID)
|
||
)
|
||
GO
|
||
INSERT INTO TBEMLP_POLL_PROCESS (PROCESS_NAME,STEP_NAME,PROFILE_ID,PATH_EMAIL_TEMP,PATH_EMAIL_ERRORS,COPY_2_HDD,
|
||
WM_IMPORT,
|
||
WM_OBJEKTTYPE,
|
||
WM_VECTOR_LOG,
|
||
WM_PATH,
|
||
WM_FILE_NAME,
|
||
WM_REFERENCE_INDEX,
|
||
SEQUENCE,DELETE_MAIL) VALUES ('ProcessManager','Easy Approval',1,'E:\TEMP\EMAIL_PROFILER\TEMP','E:\TEMP\EMAIL_PROFILER\ERROR',1,
|
||
0,
|
||
'DIGITAL DATA - Entwicklung',
|
||
'Vektor_Text1',
|
||
'W:\Import_Temp',
|
||
'EA_[%DATE]_',
|
||
'Dokument-ID',
|
||
1,1)
|
||
GO
|
||
CREATE TRIGGER TBEMLP_POLL_PROCESS_AFT_UPD ON TBEMLP_POLL_PROCESS
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBEMLP_POLL_PROCESS SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBEMLP_POLL_PROCESS.GUID = INSERTED.GUID
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
--select * from TBEMLP_POLL_STEPS
|
||
--GO
|
||
CREATE TABLE TBEMLP_POLL_STEPS
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
PROCESS_ID INTEGER NOT NULL,
|
||
STEP_NAME VARCHAR(50) NOT NULL, --'z.B. Invoice Approved or Invoice Disapproved' bei ProcessManager,
|
||
KEYWORDS_BODY VARCHAR(1000),
|
||
COMMENT VARCHAR(500),
|
||
ACTIVE BIT DEFAULT 1 NOT NULL, --
|
||
SEQUENCE INT DEFAULT 1,
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'Default',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBEMLP_POLL_STEPS PRIMARY KEY (GUID),
|
||
CONSTRAINT FK_TBEMLP_POLL_STEPS_PROCESS_ID FOREIGN KEY (PROCESS_ID) REFERENCES TBEMLP_POLL_PROCESS (GUID)
|
||
)
|
||
GO
|
||
INSERT INTO TBEMLP_POLL_STEPS (PROCESS_ID,STEP_NAME,KEYWORDS_BODY,ACTIVE) VALUES (1,'Invoice Disapproved','Disapproved;Abgelehnt',1)
|
||
GO
|
||
INSERT INTO TBEMLP_POLL_STEPS (PROCESS_ID,STEP_NAME,KEYWORDS_BODY,ACTIVE) VALUES (1,'Invoice Approved','OK;Approved;OK',1)
|
||
GO
|
||
CREATE TRIGGER TBEMLP_POLL_STEPS_AFT_UPD ON TBEMLP_POLL_STEPS
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBEMLP_POLL_STEPS SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBEMLP_POLL_STEPS.GUID = INSERTED.GUID
|
||
GO
|
||
CREATE TABLE TBEMLP_POLL_INDEXING_STEPS
|
||
(
|
||
GUID SMALLINT IDENTITY(1,1),
|
||
STEP_ID INTEGER NOT NULL,
|
||
INDEXNAME VARCHAR(100) NOT NULL, --'Easy Approval' bei ProcessManager,
|
||
INDEXVALUE VARCHAR(100) NOT NULL,
|
||
USE_FOR_DIRECT_ANSWER BIT NOT NULL DEFAULT 0,
|
||
ACTIVE BIT DEFAULT 1 NOT NULL, --
|
||
SEQUENCE INT DEFAULT 1,
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'Default',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBEMLP_POLL_INDEXING_STEPS PRIMARY KEY (GUID),
|
||
CONSTRAINT FK_TBEMLP_POLL_INDEXING_STEPS_STEP_ID FOREIGN KEY (STEP_ID) REFERENCES TBEMLP_POLL_STEPS (GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBEMLP_POLL_INDEXING_STEPS_AFT_UPD ON TBEMLP_POLL_INDEXING_STEPS
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBEMLP_POLL_INDEXING_STEPS SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBEMLP_POLL_INDEXING_STEPS.GUID = INSERTED.GUID
|
||
GO
|
||
INSERT INTO TBEMLP_POLL_INDEXING_STEPS (STEP_ID,INDEXNAME,INDEXVALUE) VALUES (1,'Dokumentart','Email-Approved')
|
||
GO
|
||
INSERT INTO TBEMLP_POLL_INDEXING_STEPS (STEP_ID,INDEXNAME,INDEXVALUE) VALUES (2,'Dokumentart','Email-Disapproved')
|
||
GO
|
||
--select * from TBEMLP_POLL_INDEXING_STEPS
|
||
--GO
|
||
CREATE TABLE TBEMLP_EMAIL_OUT
|
||
(
|
||
GUID INTEGER NOT NULL IDENTITY(1,1),
|
||
REMINDER_TYPE_ID INTEGER NOT NULL DEFAULT '1',
|
||
SENDING_PROFILE INTEGER NOT NULL,
|
||
REFERENCE_ID INTEGER NOT NULL,
|
||
REFERENCE_STRING VARCHAR(200),
|
||
ENTITY_ID INTEGER,
|
||
WF_ID INTEGER NOT NULL,
|
||
WF_REFERENCE VARCHAR(200),
|
||
EMAIL_ADRESS VARCHAR(1000) NOT NULL,
|
||
EMAIL_SUBJ VARCHAR(500) NOT NULL,
|
||
EMAIL_BODY VARCHAR(500) NOT NULL,
|
||
EMAIL_ATTMT1 VARCHAR(512),
|
||
ATT1_RELATED_ID BIGINT,
|
||
ATT1_REL_TYPE VARCHAR(20),
|
||
EMAIL_SENT DATETIME,
|
||
COMMENT VARCHAR(500),
|
||
ADDED_WHO VARCHAR(50) NOT NULL DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
ERROR_TIMESTAMP DATETIME,
|
||
ERROR_MSG VARCHAR(900),
|
||
CONSTRAINT PK_TBEMLP_EMAIL_OUT PRIMARY KEY (GUID),
|
||
CONSTRAINT FK_TBEMLP_EMAIL_OUT_SENDING_PROFILE FOREIGN KEY (SENDING_PROFILE) REFERENCES TBDD_EMAIL_ACCOUNT (GUID)
|
||
)
|
||
GO
|
||
CREATE TABLE TBEMLP_HISTORY
|
||
(
|
||
GUID BIGINT IDENTITY(1,1),
|
||
WORK_PROCESS VARCHAR(100),
|
||
EMAIL_MSGID VARCHAR(500) NOT NULL,
|
||
EMAIL_FROM VARCHAR(500) NOT NULL DEFAULT 'NONE',
|
||
EMAIL_SUBJECT VARCHAR(MAX),
|
||
EMAIL_DATE DATETIME,
|
||
EMAIL_BODY VARCHAR(MAX),
|
||
EMAIL_SUBSTRING1 VARCHAR(2000),
|
||
EMAIL_SUBSTRING2 VARCHAR(2000),
|
||
DATE_DELETED_INBOX DATETIME,
|
||
COMMENT VARCHAR(500),
|
||
[STATUS] VARCHAR(900),
|
||
[PROFILE_ID] INTEGER,
|
||
MD5HASH VARCHAR(500) NOT NULL DEFAULT(''),
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBEMLP_HISTORY PRIMARY KEY (GUID)
|
||
)
|
||
GO
|
||
CREATE TABLE TBEMLP_HISTORY_STATE
|
||
(
|
||
GUID INTEGER NOT NULL IDENTITY (1, 1),
|
||
MESSAGE_ID VARCHAR(900) NOT NULL,
|
||
STATE_TITLE VARCHAR(900) NOT NULL,
|
||
STATE_TITLE1 VARCHAR(900) ,
|
||
COMMENT VARCHAR(3000),
|
||
ADDED_WHO VARCHAR(30) DEFAULT 'Digital Data',
|
||
ADDED_WHEN DATETIME DEFAULT (GETDATE()),
|
||
CHANGED_WHO VARCHAR(30),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBEMLP_HISTORY_STATE PRIMARY KEY (GUID)
|
||
)
|
||
GO
|
||
CREATE PROCEDURE PRCUST_ADD_HISTORY_STATE @MessageID VARCHAR(250), @TITLE1 VARCHAR(250), @TITLE2 VARCHAR(250), @COMMENT VARCHAR(3000) = 0
|
||
AS
|
||
BEGIN
|
||
INSERT INTO TBEMLP_HISTORY_STATE
|
||
(MESSAGE_ID,STATE_TITLE,STATE_TITLE1,COMMENT) VALUES (@MessageID,@TITLE1,@TITLE2,@COMMENT)
|
||
END
|
||
GO
|
||
CREATE TABLE [dbo].[TBEMLP_HISTORY_ATTACHMENT](
|
||
[GUID] [int] IDENTITY(1,1) NOT NULL,
|
||
[WORK_PROCESS] VARCHAR(50),
|
||
[EMAIL_MSGID] VARCHAR(500) NOT NULL,
|
||
[EMAIL_FROM] VARCHAR(100) NOT NULL,
|
||
[EMAIL_SUBJECT] VARCHAR(500),
|
||
[EMAIL_DATETIME] VARCHAR(50),
|
||
[EMAIL_BODY] VARCHAR(5000) NOT NULL,
|
||
[EMAIL_ATTMT] VARCHAR(500) NOT NULL,
|
||
[COMMENT] VARCHAR(500),
|
||
EMAIL_ATTMT_INDEX NVARCHAR(MAX) NOT NULL DEFAULT '',
|
||
[CREATEDWHEN] DATETIME,
|
||
[CREATEDWHO] VARCHAR(50),
|
||
CONSTRAINT [PK_TBEDM_EMAIL_PROFILER_HISTORY] PRIMARY KEY CLUSTERED
|
||
(
|
||
[GUID] 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
|
||
ALTER TABLE [dbo].[TBEMLP_HISTORY_ATTACHMENT] ADD DEFAULT (getdate()) FOR [CREATEDWHEN]
|
||
GO
|
||
ALTER TABLE [dbo].[TBEMLP_HISTORY_ATTACHMENT] ADD DEFAULT ('EDMI-Admin') FOR [CREATEDWHO]
|
||
GO
|
||
-- =============================================
|
||
-- Author: DD MS
|
||
-- Creation date: 07.05.2020
|
||
-- =============================================
|
||
CREATE PROCEDURE PREMAIL_NEW_EMAIL @SENDING_PROFILE TINYINT, @EMAIL_TO VARCHAR(100),@SUBJECT VARCHAR(200),@BODY VARCHAR(MAX),@REF_STRING As VARCHAR(900),@REF_ID BIGINT,@WF_ID INT,@WHO VARCHAR(100) AS
|
||
BEGIN
|
||
INSERT INTO [dbo].[TBEMLP_EMAIL_OUT]
|
||
([SENDING_PROFILE]
|
||
,[WF_ID]
|
||
,[EMAIL_ADRESS]
|
||
,[EMAIL_SUBJ]
|
||
,[EMAIL_BODY]
|
||
,REFERENCE_STRING
|
||
,REFERENCE_ID
|
||
,[ADDED_WHO])
|
||
VALUES (@SENDING_PROFILE,
|
||
@WF_ID,
|
||
@EMAIL_TO,
|
||
@SUBJECT,
|
||
@BODY,
|
||
@REF_STRING,
|
||
@REF_ID,
|
||
@WHO)
|
||
END
|
||
GO
|
||
-- =============================================
|
||
-- Author: DD
|
||
-- =============================================
|
||
CREATE PROCEDURE [dbo].[PREML_CREATE_EMAIL]
|
||
-- Add the parameters for the stored procedure here
|
||
@SENDING_PROFILE INTEGER,
|
||
@RECEIPIANT VARCHAR(1000),
|
||
@REFERENCE_ID INTEGER,
|
||
@WF_ID INTEGER,
|
||
@EMAIL_SUBJ VARCHAR(500),
|
||
@EMAIL_BODY VARCHAR(500),
|
||
@ADDED_WHO VARCHAR(100)
|
||
|
||
|
||
AS
|
||
BEGIN
|
||
INSERT INTO [dbo].[TBEMLP_EMAIL_OUT]
|
||
([SENDING_PROFILE]
|
||
,[REFERENCE_ID]
|
||
,[WF_ID]
|
||
,[EMAIL_ADRESS]
|
||
,[EMAIL_SUBJ]
|
||
,[EMAIL_BODY]
|
||
,[COMMENT]
|
||
,[ADDED_WHO])
|
||
VALUES (@SENDING_PROFILE,
|
||
@REFERENCE_ID,
|
||
@WF_ID,
|
||
@RECEIPIANT,
|
||
@EMAIL_SUBJ,
|
||
@EMAIL_BODY,
|
||
'',
|
||
@ADDED_WHO
|
||
)
|
||
|
||
|
||
END
|
||
GO
|
||
--################################ ENDE EMAIL-PROFILER ############################################
|
||
|
||
--################################# ZUGFERD #######################################################
|
||
CREATE TABLE [dbo].[TBDD_ZUGFERD_XML_ITEMS](
|
||
[GUID] [int] IDENTITY(1,1) NOT NULL,
|
||
[SPECIFICATION] NVARCHAR(50) NOT NULL,
|
||
ITEM_TYPE int NOT NULL,
|
||
[XML_PATH] NVARCHAR(500) NOT NULL,
|
||
[DESCRIPTION] NVARCHAR(500) NOT NULL,
|
||
[TABLE_NAME] NVARCHAR(100) NOT NULL,
|
||
[TABLE_COLUMN] NVARCHAR(100) NOT NULL,
|
||
[COMMENT] NVARCHAR(500),
|
||
[ACTIVE] BIT,
|
||
[IS_REQUIRED] BIT NOT NULL DEFAULT 0,
|
||
[IS_GROUPED] BIT NOT NULL DEFAULT 0,
|
||
[GROUP_SCOPE] NVARCHAR(50) NULL,
|
||
[ADDED_WHEN] DATETIME NOT NULL,
|
||
[ADDED_WHO] NVARCHAR(50),
|
||
[CHANGED_WHEN] DATETIME,
|
||
[CHANGED_WHO] NVARCHAR(50),
|
||
CONSTRAINT [PK_TBDD_ZUGFERD_XML_ITEMS] PRIMARY KEY CLUSTERED
|
||
(
|
||
[GUID] 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
|
||
|
||
ALTER TABLE [dbo].[TBDD_ZUGFERD_XML_ITEMS] ADD CONSTRAINT [DF_TBDD_ZUGFERD_XML_ITEMS_SPECIFICATION] DEFAULT (N'DEFAULT') FOR [SPECIFICATION]
|
||
GO
|
||
ALTER TABLE [dbo].[TBDD_ZUGFERD_XML_ITEMS] ADD CONSTRAINT [DF_TBDD_ZUGFERD_XML_ITEMS_ACTIVE] DEFAULT ((1)) FOR [ACTIVE]
|
||
GO
|
||
ALTER TABLE [dbo].[TBDD_ZUGFERD_XML_ITEMS] ADD CONSTRAINT [DF_TBDD_ZUGFERD_XML_ITEMS_GROUP_SCOPE] DEFAULT (N'DEFAULT') FOR [GROUP_SCOPE]
|
||
GO
|
||
ALTER TABLE [dbo].[TBDD_ZUGFERD_XML_ITEMS] ADD CONSTRAINT [DF_TBDD_ZUGFERD_XML_ITEMS_ADDED_WHEN] DEFAULT (getdate()) FOR [ADDED_WHEN]
|
||
GO
|
||
ALTER TABLE [dbo].[TBDD_ZUGFERD_XML_ITEMS] ADD CONSTRAINT [DF_TBDD_ZUGFERD_XML_ITEMS_ADDED_WHO] DEFAULT (N'EDM-Admin') FOR [ADDED_WHO]
|
||
GO
|
||
ALTER TABLE [dbo].[TBDD_ZUGFERD_XML_ITEMS] ADD CONSTRAINT DF_TBDD_ZUGFERD_XML_ITEMS_ITEM_TYP DEFAULT 0 FOR ITEM_TYPE
|
||
GO
|
||
--################################# fileFLOW #######################################################
|
||
UPDATE TBDD_MODULES SET DB_VERSION = '2.5.4.3' where NAME = 'fileFLOW'
|
||
GO
|
||
UPDATE TBDD_MODULES SET STRING1 = '\\windream\objects' WHERE SHORT_NAME = 'GLOBIX' AND STRING1 = 'W';
|
||
CREATE TABLE TBGI_CONFIGURATION
|
||
(
|
||
GUID TINYINT,
|
||
WD_UNICODE BIT NOT NULL DEFAULT 0,
|
||
LICENSEKEY VARCHAR(1000) NOT NULL DEFAULT '',
|
||
IDX_EMAIL_ID VARCHAR(50) NOT NULL DEFAULT '',
|
||
IDX_EMAIL_FROM VARCHAR(50) NOT NULL DEFAULT '',
|
||
IDX_EMAIL_TO VARCHAR(50) NOT NULL DEFAULT '',
|
||
IDX_EMAIL_SUBJECT VARCHAR(50) NOT NULL DEFAULT '',
|
||
IDX_EMAIL_DATE_IN VARCHAR(50) NOT NULL DEFAULT '',
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBGI_CONFIGURATION_GUID PRIMARY KEY(GUID),
|
||
CONSTRAINT CH_TBGI_CONFIGURATION_GUID CHECK(GUID = 1)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBGI_CONFIGURATION_AFT_UPD ON TBGI_CONFIGURATION
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBGI_CONFIGURATION SET CHANGED_WHEN = GETDATE() FROM INSERTED
|
||
WHERE TBGI_CONFIGURATION.GUID = INSERTED.GUID
|
||
GO
|
||
|
||
INSERT INTO TBGI_CONFIGURATION(GUID,IDX_EMAIL_ID,LICENSEKEY)
|
||
VALUES
|
||
(1,'','lsHEktEpn3R1UiIxAnvtY7aM5dBRxgb7aYTlEzH52V0=')
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
CREATE TABLE TBGI_FILES_USER
|
||
(
|
||
GUID BIGINT IDENTITY(1,1),
|
||
DocID BIGINT NOT NULL DEFAULT 0,
|
||
FILENAME2WORK VARCHAR(500) NOT NULL,
|
||
FILENAME_ONLY VARCHAR(250) NOT NULL DEFAULT '',
|
||
FILE_HASH VARCHAR(200),
|
||
USER@WORK VARCHAR(50) NOT NULL,
|
||
WORKED BIT NOT NULL DEFAULT 0,
|
||
HANDLE_TYPE VARCHAR(50) NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE() NOT NULL,
|
||
CONSTRAINT PK_TBGI_FILES_USER PRIMARY KEY(GUID)
|
||
)
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
CREATE TABLE TBGI_FOLDERWATCH_USER
|
||
(
|
||
GUID INTEGER IDENTITY(0,1),
|
||
[USER_ID] INT NOT NULL,
|
||
FOLDER_PATH VARCHAR(800) NOT NULL,
|
||
FOLDER_TYPE VARCHAR(20) DEFAULT 'DEFAULT' NOT NULL,
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DEFAULT' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBGI_FOLDERWATCH_USER PRIMARY KEY (GUID),
|
||
CONSTRAINT UQ_USER_FOLDERWATCHPATH UNIQUE([USER_ID],FOLDER_PATH),
|
||
CONSTRAINT FK_TBGI_FOLDERWATCH_USER_USER_ID FOREIGN KEY([USER_ID]) REFERENCES TBDD_USER(GUID),
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBGI_FOLDERWATCH_USER_AFT_UPD ON TBGI_FOLDERWATCH_USER
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBGI_FOLDERWATCH_USER SET CHANGED_WHEN = GETDATE() FROM INSERTED
|
||
WHERE TBGI_FOLDERWATCH_USER.GUID = INSERTED.GUID
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
CREATE TABLE TBGI_FUNCTION_REGEX
|
||
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
FUNCTION_NAME VARCHAR(100) NOT NULL,
|
||
REGEX VARCHAR(2000) NOT NULL,
|
||
STRING1 VARCHAR(100),
|
||
STRING2 VARCHAR(100),
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'Digital Data',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBGI_FUNCTION_REGEX PRIMARY KEY (GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBGI_FUNCTION_REGEX_AFT_UPD ON TBGI_FUNCTION_REGEX
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBGI_FUNCTION_REGEX SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBGI_FUNCTION_REGEX.GUID = INSERTED.GUID
|
||
GO
|
||
|
||
|
||
INSERT INTO TBGI_FUNCTION_REGEX(FUNCTION_NAME,REGEX) VALUES
|
||
('FROM_EMAIL_HEADER','From:(?:\s*[\w\s\d.@&,|+%\)\(\-]*<|\s*=\?[\w\s\d.@&,|+%?=\)\(\-]+\?=\s*<|\s*""[\w\s\d.@&,|+%\)\(\-]+""\s*<|\s*)([A-Z0-9._%+-]+@[A-Z0-9.-]+\.[A-Z]{2,})>?')
|
||
GO
|
||
INSERT INTO TBGI_FUNCTION_REGEX(FUNCTION_NAME,REGEX) VALUES
|
||
('TO_EMAIL_HEADER','To:(?:\s*[\w\s\d.@&,|+%\)\(\-]+<|\s*=\?[\w\s\d.@&,|+%?=\)\(\-]+\?=\s*<|\s*""[\w\s\d.@&,|+%\)\(\-]+""\s*<|\s*)([A-Z0-9._%+-]+@[A-Z0-9.-]+\.[A-Z]{2,})>?')
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
CREATE TABLE TBGI_HISTORY
|
||
(
|
||
GUID INT IDENTITY(1,1),
|
||
FILENAME_ORIGINAL VARCHAR(512),
|
||
FILENAME_NEW VARCHAR(512),
|
||
INDEX1 VARCHAR(250),
|
||
INDEX2 VARCHAR(250),
|
||
INDEX3 VARCHAR(250),
|
||
INDEX4 VARCHAR(250),
|
||
INDEX5 VARCHAR(250),
|
||
INDEX6 VARCHAR(250),
|
||
INDEX7 VARCHAR(250),
|
||
INDEX8 VARCHAR(250),
|
||
INDEX9 VARCHAR(250),
|
||
INDEX10 VARCHAR(250),
|
||
MSG_ID VARCHAR(250),
|
||
ATTACHMENT BIT NOT NULL DEFAULT 0,
|
||
FILE_HASH VARCHAR(100),
|
||
ADDED_WHO VARCHAR(50),
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
ADDED_WHERE VARCHAR(100),
|
||
CONSTRAINT PK_TBGI_HISTORY PRIMARY KEY(GUID)
|
||
)
|
||
GO
|
||
|
||
------------------------------------------------------------------------------
|
||
CREATE TABLE TBGI_OBJECTTYPE_EMAIL_INDEX
|
||
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
OBJECTTYPE VARCHAR(100) NOT NULL,
|
||
IDX_EMAIL_ID VARCHAR(50) NOT NULL DEFAULT '',
|
||
IDX_EMAIL_FROM VARCHAR(50) NOT NULL DEFAULT '',
|
||
IDX_EMAIL_TO VARCHAR(50) NOT NULL DEFAULT '',
|
||
IDX_EMAIL_SUBJECT VARCHAR(50) NOT NULL DEFAULT '',
|
||
IDX_EMAIL_DATE_IN VARCHAR(50) NOT NULL DEFAULT '',
|
||
IDX_CHECK_ATTACHMENT VARCHAR(50) NOT NULL DEFAULT '',
|
||
ADDED_WHO VARCHAR(50) NOT NULL DEFAULT 'Digital Data',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBGI_OBJECTTYPE_EMAIL_INDEX PRIMARY KEY (GUID)
|
||
)
|
||
GO
|
||
|
||
CREATE TRIGGER TBGI_OBJECTTYPE_EMAIL_INDEX_AFT_UPD ON TBGI_OBJECTTYPE_EMAIL_INDEX
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBGI_OBJECTTYPE_EMAIL_INDEX SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBGI_OBJECTTYPE_EMAIL_INDEX.GUID = INSERTED.GUID
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
CREATE TABLE TBHOTKEY_PROFILE
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
NAME VARCHAR(50) NOT NULL,
|
||
OBJECTTYPE VARCHAR(100) NOT NULL,
|
||
WD_SEARCH VARCHAR(250) NOT NULL,
|
||
HOTKEY1 VARCHAR(10) NOT NULL,
|
||
HOTKEY2 VARCHAR(5) NOT NULL,
|
||
WINDOW_NAME VARCHAR(100) NOT NULL,
|
||
ADDED_WHO VARCHAR(50) NOT NULL DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBHOTKEY_PROFILE PRIMARY KEY (GUID)
|
||
)
|
||
GO
|
||
|
||
CREATE TRIGGER TBHOTKEY_PROFILE_UPD ON TBHOTKEY_PROFILE
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBHOTKEY_PROFILE SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBHOTKEY_PROFILE.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
|
||
CREATE TABLE TBHOTKEY_PATTERNS
|
||
(
|
||
GUID INT IDENTITY(1,1),
|
||
HKPROFILE_ID INT NOT NULL,
|
||
PATTERN_WDSEARCH VARCHAR(50) NOT NULL,
|
||
WINDOW_CONTROL VARCHAR(100) NOT NULL,
|
||
SEQUENCE_NUMBER INTEGER NOT NULL,
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DEFAULT' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PKTBHOTKEY_PATTERNS PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBHOTKEY_PATTERNS_PROFILE_ID FOREIGN KEY(HKPROFILE_ID) REFERENCES TBHOTKEY_PROFILE(GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBHOTKEY_PATTERNS_AFT_UPD ON TBHOTKEY_PATTERNS
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBHOTKEY_PATTERNS SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBHOTKEY_PATTERNS.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
CREATE TABLE TBHOTKEY_WINDOW_HOOK
|
||
(
|
||
GUID INT IDENTITY(1,1),
|
||
HKPROFILE_ID INT NOT NULL,
|
||
SEQUENCE_NUMBER INTEGER NOT NULL,
|
||
CONTROL_VALUE VARCHAR(100) NOT NULL,
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DEFAULT' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PKTBHOTKEY_WINDOW_HOOK PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBHOTKEY_WINDOW_HOOK_PROFILE_ID FOREIGN KEY(HKPROFILE_ID) REFERENCES TBHOTKEY_PROFILE(GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBHOTKEY_WINDOW_HOOK_AFT_UPD ON TBHOTKEY_WINDOW_HOOK
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBHOTKEY_WINDOW_HOOK SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBHOTKEY_WINDOW_HOOK.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
CREATE TABLE TBHOTKEY_PATTERNS_REWORK
|
||
(
|
||
GUID INT IDENTITY(1,1),
|
||
HKPATTERN_ID INT NOT NULL,
|
||
TYPE VARCHAR(30) NOT NULL,
|
||
FUNCTION1 VARCHAR(250) DEFAULT '',
|
||
FUNCTION2 VARCHAR(250) DEFAULT '',
|
||
TEXT1 VARCHAR(100) DEFAULT '',
|
||
TEXT2 VARCHAR(100) DEFAULT '',
|
||
SEQUENCE INTEGER NOT NULL DEFAULT 1,
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'DEFAULT' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBHOTKEY_PATTERNS_REWORK PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBHOTKEY_PATTERNS_REWORK_HKPATTERN_ID FOREIGN KEY(HKPATTERN_ID) REFERENCES TBHOTKEY_PATTERNS(GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TTBHOTKEY_PATTERNS_REWORK_AFT_UPD ON TBHOTKEY_PATTERNS_REWORK
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBHOTKEY_PATTERNS_REWORK SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBHOTKEY_PATTERNS_REWORK.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
CREATE TABLE TBHOTKEY_USER_PROFILE
|
||
(
|
||
GUID INT IDENTITY(1,1),
|
||
HKPROFILE_ID INT NOT NULL,
|
||
[USER_ID] INT NOT NULL,
|
||
WD_SEARCH VARCHAR(250) NOT NULL DEFAULT '',
|
||
HOTKEY1 VARCHAR(10) NOT NULL DEFAULT '',
|
||
HOTKEY2 VARCHAR(5) NOT NULL DEFAULT '',
|
||
ADDED_WHO VARCHAR(50) NOT NULL DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBHOTKEY_USER_PROFILE PRIMARY KEY (GUID),
|
||
CONSTRAINT UQ_TBHOTKEY_USER_PROFILE UNIQUE (HKPROFILE_ID,[USER_ID]),
|
||
CONSTRAINT FK_TBHOTKEY_USER_PROFILE_PROFILE_ID FOREIGN KEY(HKPROFILE_ID) REFERENCES TBHOTKEY_PROFILE(GUID),
|
||
CONSTRAINT FK_TBHOTKEY_USER_PROFILE_USER_ID FOREIGN KEY([USER_ID]) REFERENCES TBDD_USER(GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBHOTKEY_USER_PROFILE_AFT_UPD ON TBHOTKEY_USER_PROFILE
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBHOTKEY_USER_PROFILE SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBHOTKEY_USER_PROFILE.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
CREATE TABLE TBHOTKEYTEMP_USER_HOTKEYS
|
||
(
|
||
HOTKEY_ID INTEGER NOT NULL,
|
||
HOTKEY1 VARCHAR(10) NOT NULL,
|
||
HOTKEY2 VARCHAR(5) NOT NULL,
|
||
[USER_ID] INTEGER NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CONSTRAINT PK_TBHOTKEYTEMP_USER_HOTKEYS PRIMARY KEY (HOTKEY1,HOTKEY2,[USER_ID])
|
||
)
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
--############# VIEWS #################
|
||
------------------------------------------------------------------------------
|
||
------------------------------------------------------------------------------
|
||
|
||
CREATE VIEW [dbo].[VWGI_DOCTYPE] AS
|
||
SELECT DISTINCT
|
||
T.GUID AS [USER_ID],
|
||
T.USERNAME,
|
||
--T2.NAME AS GROUP_NAME,
|
||
T3.DOCTYPE_ID,
|
||
T4.BEZEICHNUNG AS DOCTYPE,
|
||
T4.BEZEICHNUNG AS DOCTYPE_ONLY,
|
||
T4.KURZNAME,
|
||
T4.ZIEL_PFAD,
|
||
T4.AKTIV,
|
||
T4.NAMENKONVENTION,
|
||
T4.OBJEKTTYP,
|
||
0 IDB_FILESTORE_ID, --T4.IDB_FILESTORE_ID,
|
||
T4.SEQUENCE
|
||
FROM
|
||
TBDD_USER T,
|
||
TBDD_GROUPS_USER T1,
|
||
TBDD_GROUPS T2,
|
||
TBDD_USRGRP_DOKTYPE T3,
|
||
TBDD_DOKUMENTART T4
|
||
WHERE
|
||
T4.AKTIV = 1 AND
|
||
T.GUID = T1.[USER_ID] AND
|
||
T1.GROUP_ID = T2.GUID AND
|
||
T2.GUID = T3.GROUP_ID AND
|
||
T3.DOCTYPE_ID = T4.GUID AND
|
||
T4.GUID in (SELECT DOKART_ID FROM TBDD_DOKUMENTART_MODULE WHERE MODULE_ID = (SELECT GUID FROM TBDD_MODULES WHERE UPPER(SHORT_NAME) = ('GLOBIX')))
|
||
UNION
|
||
SELECT DISTINCT
|
||
T.GUID AS [USER_ID],
|
||
T.USERNAME,
|
||
--'' AS GROUP_NAME,
|
||
T4.GUID as DOCTYPE_ID,
|
||
T4.BEZEICHNUNG AS DOCTYPE,
|
||
T4.BEZEICHNUNG AS DOCTYPE_ONLY,
|
||
T4.KURZNAME,
|
||
T4.ZIEL_PFAD,
|
||
T4.AKTIV,
|
||
T4.NAMENKONVENTION,
|
||
T4.OBJEKTTYP,
|
||
0 IDB_FILESTORE_ID, --T4.IDB_FILESTORE_ID,
|
||
T4.SEQUENCE
|
||
FROM
|
||
TBDD_USER T,
|
||
TBDD_USER_DOKTYPE T3,
|
||
TBDD_DOKUMENTART T4
|
||
WHERE
|
||
T4.AKTIV = 1 AND
|
||
T.GUID = T3.[USER_ID] AND
|
||
T3.DOCTYPE_ID = T4.GUID AND
|
||
T4.GUID in (SELECT DOKART_ID FROM TBDD_DOKUMENTART_MODULE WHERE MODULE_ID = (SELECT GUID FROM TBDD_MODULES WHERE UPPER(SHORT_NAME) = ('GLOBIX')))
|
||
GO
|
||
|
||
DECLARE @SQL nvarchar(max);
|
||
IF EXISTS (SELECT * FROM [TBDD_CATALOG] WHERE CAT_TITLE = 'USE_IDB_AS_METADATA' AND CAT_STRING = '1')
|
||
BEGIN
|
||
SET @SQL = N'--26.09 MS Shortname angepasst
|
||
CREATE OR ALTER VIEW [dbo].[VWGI_DOCTYPE_IDB] AS
|
||
SELECT
|
||
T4.GUID as DOCTYPE_ID,
|
||
T4.BEZEICHNUNG AS DOCTYPE,
|
||
T4.BEZEICHNUNG AS DOCTYPE_ONLY,
|
||
T4.KURZNAME,
|
||
T4.FOLDER_FOR_INDEX DYNAMIC_FOLDER,
|
||
T4.AKTIV,
|
||
T4.NAMENKONVENTION,
|
||
T4.OBJEKTTYP,
|
||
T6.OBJECT_TITLE AS OBJECT_STORE,
|
||
T4.IDB_OBJECT_STORE_ID OBJECT_ST_ID,
|
||
T7.CAT_TITLE AS OBJECT_ST_PATH,
|
||
T4.ERSTELLTWANN,
|
||
T4.GEAENDERTWANN,
|
||
T4.SEQUENCE,
|
||
T4.IDB_DOCTYPE_ID
|
||
FROM
|
||
DD_ECM.dbo.TBDD_DOKUMENTART T4 LEFT JOIN IDB.dbo.TBIDB_OBJECT_STORE T6 ON T4.IDB_OBJECT_STORE_ID = T6.GUID
|
||
LEFT JOIN IDB.dbo.TBIDB_CATALOG T7 On T6.CAT_ID = T7.GUID
|
||
WHERE
|
||
T4.GUID in (SELECT DOKART_ID FROM DD_ECM.dbo.TBDD_DOKUMENTART_MODULE WHERE MODULE_ID = (SELECT GUID FROM DD_ECM.dbo.TBDD_MODULES WHERE SHORT_NAME = ''fileFLOW''));';
|
||
EXEC (@SQL);
|
||
END;
|
||
GO
|
||
|
||
DECLARE @SQL nvarchar(max);
|
||
IF EXISTS (SELECT * FROM [TBDD_CATALOG] WHERE CAT_TITLE = 'USE_IDB_AS_METADATA' AND CAT_STRING = '1')
|
||
BEGIN
|
||
SET @SQL = N'
|
||
--26.09 MS Shortname angepasst
|
||
ALTER VIEW [dbo].[VWGI_DOCTYPE_USER] AS
|
||
SELECT DISTINCT
|
||
T.GUID AS [USER_ID],
|
||
T.USERNAME,
|
||
--T2.NAME AS GROUP_NAME,
|
||
T3.DOCTYPE_ID,
|
||
T4.BEZEICHNUNG AS DOCTYPE,
|
||
T4.BEZEICHNUNG AS DOCTYPE_ONLY,
|
||
T4.KURZNAME,
|
||
T4.ZIEL_PFAD,
|
||
T4.AKTIV,
|
||
T4.NAMENKONVENTION,
|
||
T4.OBJEKTTYP,
|
||
T4.IDB_OBJECT_STORE_ID OBJECT_ST_ID,
|
||
T5.OBJECT_TITLE as OBJECT_ST_NAME,
|
||
T4.SEQUENCE
|
||
FROM
|
||
DD_ECM.dbo.TBDD_USER T,
|
||
DD_ECM.dbo.TBDD_GROUPS_USER T1,
|
||
DD_ECM.dbo.TBDD_GROUPS T2,
|
||
DD_ECM.dbo.TBDD_USRGRP_DOKTYPE T3,
|
||
DD_ECM.dbo.TBDD_DOKUMENTART T4,
|
||
IDB.dbo.TBIDB_OBJECT_STORE T5
|
||
WHERE
|
||
T4.AKTIV = 1 AND
|
||
T.GUID = T1.[USER_ID] AND
|
||
T1.GROUP_ID = T2.GUID AND
|
||
T2.GUID = T3.GROUP_ID AND
|
||
T3.DOCTYPE_ID = T4.GUID AND
|
||
T4.IDB_OBJECT_STORE_ID = T5.GUID AND
|
||
|
||
T4.GUID in (SELECT DOKART_ID FROM DD_ECM.dbo.TBDD_DOKUMENTART_MODULE WHERE MODULE_ID = (SELECT GUID FROM DD_ECM.dbo.TBDD_MODULES WHERE SHORT_NAME = ''fileFLOW''))
|
||
UNION
|
||
SELECT DISTINCT
|
||
T.GUID AS [USER_ID],
|
||
T.USERNAME,
|
||
--'' AS GROUP_NAME,
|
||
T4.GUID as DOCTYPE_ID,
|
||
T4.BEZEICHNUNG AS DOCTYPE,
|
||
T4.BEZEICHNUNG AS DOCTYPE_ONLY,
|
||
T4.KURZNAME,
|
||
T4.ZIEL_PFAD,
|
||
T4.AKTIV,
|
||
T4.NAMENKONVENTION,
|
||
T4.OBJEKTTYP,
|
||
T4.IDB_OBJECT_STORE_ID OBJECT_ST_ID,
|
||
T5.OBJECT_TITLE as OBJECT_ST_NAME,
|
||
T4.SEQUENCE
|
||
FROM
|
||
DD_ECM.dbo.TBDD_USER T,
|
||
DD_ECM.dbo.TBDD_USER_DOKTYPE T3,
|
||
DD_ECM.dbo.TBDD_DOKUMENTART T4,
|
||
IDB.dbo.TBIDB_OBJECT_STORE T5
|
||
WHERE
|
||
T4.AKTIV = 1 AND
|
||
T.GUID = T3.[USER_ID] AND
|
||
T3.DOCTYPE_ID = T4.GUID AND
|
||
T4.IDB_OBJECT_STORE_ID = T5.GUID AND
|
||
T4.GUID in (SELECT DOKART_ID FROM DD_ECM.dbo.TBDD_DOKUMENTART_MODULE WHERE MODULE_ID = (SELECT GUID FROM DD_ECM.dbo.TBDD_MODULES WHERE SHORT_NAME = ''fileFLOW''))'
|
||
PRINT @SQL
|
||
END
|
||
ELSE
|
||
SET @SQL = N'
|
||
--26.09 MS Shortname angepasst
|
||
ALTER VIEW [dbo].[VWGI_DOCTYPE_USER] AS
|
||
SELECT DISTINCT
|
||
T.GUID AS [USER_ID],
|
||
T.USERNAME,
|
||
--T2.NAME AS GROUP_NAME,
|
||
T3.DOCTYPE_ID,
|
||
T4.BEZEICHNUNG AS DOCTYPE,
|
||
T4.BEZEICHNUNG AS DOCTYPE_ONLY,
|
||
T4.KURZNAME,
|
||
T4.ZIEL_PFAD,
|
||
T4.AKTIV,
|
||
T4.NAMENKONVENTION,
|
||
T4.OBJEKTTYP,
|
||
0 OBJECT_ST_ID,
|
||
T5.OBJECT_TITLE as OBJECT_ST_NAME,
|
||
T4.SEQUENCE
|
||
FROM
|
||
DD_ECM.dbo.TBDD_USER T,
|
||
DD_ECM.dbo.TBDD_GROUPS_USER T1,
|
||
DD_ECM.dbo.TBDD_GROUPS T2,
|
||
DD_ECM.dbo.TBDD_USRGRP_DOKTYPE T3,
|
||
DD_ECM.dbo.TBDD_DOKUMENTART T4
|
||
WHERE
|
||
T4.AKTIV = 1 AND
|
||
T.GUID = T1.[USER_ID] AND
|
||
T1.GROUP_ID = T2.GUID AND
|
||
T2.GUID = T3.GROUP_ID AND
|
||
T3.DOCTYPE_ID = T4.GUID AND
|
||
T4.GUID in (SELECT DOKART_ID FROM DD_ECM.dbo.TBDD_DOKUMENTART_MODULE WHERE MODULE_ID = (SELECT GUID FROM DD_ECM.dbo.TBDD_MODULES WHERE SHORT_NAME = ''fileFLOW''))
|
||
UNION
|
||
SELECT DISTINCT
|
||
T.GUID AS [USER_ID],
|
||
T.USERNAME,
|
||
--'' AS GROUP_NAME,
|
||
T4.GUID as DOCTYPE_ID,
|
||
T4.BEZEICHNUNG AS DOCTYPE,
|
||
T4.BEZEICHNUNG AS DOCTYPE_ONLY,
|
||
T4.KURZNAME,
|
||
T4.ZIEL_PFAD,
|
||
T4.AKTIV,
|
||
T4.NAMENKONVENTION,
|
||
T4.OBJEKTTYP,
|
||
0 OBJECT_ST_ID,
|
||
T5.OBJECT_TITLE as OBJECT_ST_NAME,
|
||
T4.SEQUENCE
|
||
FROM
|
||
DD_ECM.dbo.TBDD_USER T,
|
||
DD_ECM.dbo.TBDD_USER_DOKTYPE T3,
|
||
DD_ECM.dbo.TBDD_DOKUMENTART T4
|
||
WHERE
|
||
T4.AKTIV = 1 AND
|
||
T.GUID = T3.[USER_ID] AND
|
||
T3.DOCTYPE_ID = T4.GUID AND
|
||
T4.GUID in (SELECT DOKART_ID FROM DD_ECM.dbo.TBDD_DOKUMENTART_MODULE WHERE MODULE_ID = (SELECT GUID FROM DD_ECM.dbo.TBDD_MODULES WHERE SHORT_NAME = ''fileFLOW''))'
|
||
EXEC (@SQL);
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
|
||
CREATE VIEW [dbo].[VWGI_USER_GROUPS_RELATION] AS
|
||
SELECT DISTINCT
|
||
T.GUID AS [USER_ID],
|
||
T.USERNAME,
|
||
--T2.NAME AS GROUP_NAME,
|
||
T3.DOCTYPE_ID,
|
||
T4.BEZEICHNUNG AS DOCTYPE,
|
||
T4.BEZEICHNUNG AS DOCTYPE_ONLY,
|
||
T4.KURZNAME,
|
||
T4.ZIEL_PFAD,
|
||
T4.AKTIV,
|
||
T4.NAMENKONVENTION,
|
||
T4.OBJEKTTYP,
|
||
T4.IDB_OBJECT_STORE_ID OBJECT_ST_ID,
|
||
T4.SEQUENCE
|
||
FROM
|
||
DD_ECM.dbo.TBDD_USER T,
|
||
DD_ECM.dbo.TBDD_GROUPS_USER T1,
|
||
DD_ECM.dbo.TBDD_GROUPS T2,
|
||
DD_ECM.dbo.TBDD_USRGRP_DOKTYPE T3,
|
||
DD_ECM.dbo.TBDD_DOKUMENTART T4
|
||
WHERE
|
||
T4.AKTIV = 1 AND
|
||
T.GUID = T1.[USER_ID] AND
|
||
T1.GROUP_ID = T2.GUID AND
|
||
T2.GUID = T3.GROUP_ID AND
|
||
T3.DOCTYPE_ID = T4.GUID AND
|
||
|
||
T4.GUID in (SELECT DOKART_ID FROM DD_ECM.dbo.TBDD_DOKUMENTART_MODULE WHERE MODULE_ID = (SELECT GUID FROM DD_ECM.dbo.TBDD_MODULES WHERE UPPER(SHORT_NAME) = ('GLOBIX')))
|
||
UNION
|
||
SELECT DISTINCT
|
||
T.GUID AS [USER_ID],
|
||
T.USERNAME,
|
||
--'' AS GROUP_NAME,
|
||
T4.GUID as DOCTYPE_ID,
|
||
T4.BEZEICHNUNG AS DOCTYPE,
|
||
T4.BEZEICHNUNG AS DOCTYPE_ONLY,
|
||
T4.KURZNAME,
|
||
T4.ZIEL_PFAD,
|
||
T4.AKTIV,
|
||
T4.NAMENKONVENTION,
|
||
T4.OBJEKTTYP,
|
||
T4.IDB_OBJECT_STORE_ID OBJECT_ST_ID,
|
||
T4.SEQUENCE
|
||
FROM
|
||
DD_ECM.dbo.TBDD_USER T,
|
||
DD_ECM.dbo.TBDD_USER_DOKTYPE T3,
|
||
DD_ECM.dbo.TBDD_DOKUMENTART T4
|
||
WHERE
|
||
T4.AKTIV = 1 AND
|
||
T.GUID = T3.[USER_ID] AND
|
||
T3.DOCTYPE_ID = T4.GUID AND
|
||
T4.GUID in (SELECT DOKART_ID FROM DD_ECM.dbo.TBDD_DOKUMENTART_MODULE WHERE MODULE_ID = (SELECT GUID FROM DD_ECM.dbo.TBDD_MODULES WHERE UPPER(SHORT_NAME) = ('GLOBIX')))
|
||
GO
|
||
|
||
------------------------------------------------------------------------------
|
||
--############# PROCEDURES #################
|
||
------------------------------------------------------------------------------
|
||
CREATE PROCEDURE [dbo].[PRDD_GLOBIX_DELETE_DOCTYPE](@pDOCID INT)
|
||
AS
|
||
BEGIN TRY
|
||
IF OBJECT_ID(N'dbo.TBPMO_CLIENT_DOCTYPE', N'U') IS NOT NULL
|
||
DELETE FROM TBPMO_CLIENT_DOCTYPE WHERE DOCTYPE_ID = @pDOCID
|
||
IF OBJECT_ID(N'dbo.TBPMO_TEMPLATE', N'U') IS NOT NULL
|
||
DELETE FROM TBPMO_TEMPLATE WHERE DOCTYPE_ID = @pDOCID
|
||
IF OBJECT_ID(N'dbo.TBPMO_WD_FORMVIEW_DOKTYPES', N'U') IS NOT NULL
|
||
DELETE FROM TBPMO_WD_FORMVIEW_DOKTYPES WHERE DOCTYPE_ID = @pDOCID
|
||
|
||
DELETE FROM TBDD_INDEX_MAN_POSTPROCESSING WHERE IDXMAN_ID IN (SELECT GUID FROM TBDD_INDEX_MAN WHERE DOK_ID = @pDOCID)
|
||
DELETE FROM TBDD_INDEX_MAN WHERE DOK_ID = @pDOCID
|
||
DELETE FROM TBDD_INDEX_AUTOM WHERE DOCTYPE_ID = @pDOCID
|
||
DELETE FROM TBDD_USRGRP_DOKTYPE WHERE DOCTYPE_ID = @pDOCID
|
||
DELETE FROM TBGI_REGEX_DOCTYPE WHERE DOCTYPE_ID = @pDOCID
|
||
DELETE FROM TBDD_DOKUMENTART_MODULE WHERE DOKART_ID = @pDOCID
|
||
DELETE FROM TBDD_DOKUMENTART WHERE GUID = @pDOCID
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'FEHLER IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE()) + ' - ZEILE: ' + CONVERT(VARCHAR(10),ERROR_LINE())
|
||
+ ' - FEHLER-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
END CATCH
|
||
GO
|
||
--CHANGED 24.09.2024 SEQ in autom. Index
|
||
CREATE OR ALTER PROCEDURE [dbo].[PRDD_COPY_DOKPROFILE](@pDOCTYPE_ID INT,@pMODULE_ID INT)
|
||
AS
|
||
DECLARE @NEWDOCTYPE_ID INT
|
||
|
||
BEGIN
|
||
INSERT INTO TBDD_DOKUMENTART (
|
||
BEZEICHNUNG,EINGANGSART_ID,WINDREAM_DIRECT,KURZNAME,ZIEL_PFAD,BESCHREIBUNG,AKTIV,NAMENKONVENTION,OBJEKTTYP,FOLDER_FOR_INDEX,ERSTELLTWER,DUPLICATE_HANDLING
|
||
)
|
||
SELECT
|
||
'COPY_' + BEZEICHNUNG ,EINGANGSART_ID,WINDREAM_DIRECT,KURZNAME,ZIEL_PFAD,BESCHREIBUNG,0,NAMENKONVENTION,OBJEKTTYP,FOLDER_FOR_INDEX,'COPY-PROCEDURE',DUPLICATE_HANDLING FROM TBDD_DOKUMENTART WHERE GUID = @pDOCTYPE_ID
|
||
|
||
SELECT @NEWDOCTYPE_ID = MAX(GUID) FROM TBDD_DOKUMENTART
|
||
INSERT INTO TBDD_DOKUMENTART_MODULE (DOKART_ID,MODULE_ID,ADDED_WHO) VALUES (@NEWDOCTYPE_ID,@pMODULE_ID,'COPY-PROCEDURE')
|
||
|
||
INSERT INTO TBDD_INDEX_AUTOM (
|
||
DOCTYPE_ID,INDEXNAME,VALUE,SEQUENCE, SQL_ACTIVE,CONNECTION_ID,SQL_RESULT,COMMENT,ACTIVE,ADDED_WHO)
|
||
SELECT @NEWDOCTYPE_ID,INDEXNAME,VALUE, [SEQUENCE], SQL_ACTIVE,CONNECTION_ID,SQL_RESULT,COMMENT,ACTIVE,'COPY-PROCEDURE' FROM TBDD_INDEX_AUTOM WHERE DOCTYPE_ID = @pDOCTYPE_ID
|
||
|
||
DECLARE
|
||
@MANINDEX_ID INTEGER,
|
||
@NEW_ID INTEGER
|
||
DECLARE c_INDEX CURSOR FOR
|
||
SELECT GUID FROM TBDD_INDEX_MAN WHERE DOK_ID = @pDOCTYPE_ID ORDER BY SEQUENCE
|
||
OPEN c_INDEX
|
||
FETCH NEXT FROM c_INDEX INTO @MANINDEX_ID
|
||
WHILE @@FETCH_STATUS = 0
|
||
BEGIN
|
||
INSERT INTO TBDD_INDEX_MAN (
|
||
DOK_ID, NAME, WD_INDEX, COMMENT, DATATYPE, SUGGESTION, DEFAULT_VALUE, CONNECTION_ID, SEQUENCE, ACTIVE , ADDED_WHO ,SQL_RESULT, SQL_CHECK, OPTIONAL, MULTISELECT, VKT_ADD_ITEM, VKT_PREVENT_MULTIPLE_VALUES)
|
||
SELECT @NEWDOCTYPE_ID, NAME, WD_INDEX, COMMENT, DATATYPE, SUGGESTION, DEFAULT_VALUE, CONNECTION_ID, [SEQUENCE], ACTIVE ,'COPY-PROCEDURE',SQL_RESULT, SQL_CHECK, OPTIONAL, MULTISELECT, VKT_ADD_ITEM, VKT_PREVENT_MULTIPLE_VALUES FROM TBDD_INDEX_MAN WHERE GUID = @MANINDEX_ID
|
||
|
||
SELECT @NEW_ID = MAX(GUID) FROM TBDD_INDEX_MAN WHERE DOK_ID = @NEWDOCTYPE_ID
|
||
|
||
--Nachbearbeitungsfunktionen hinzuf<75>gen
|
||
IF EXISTS(SELECT * FROM TBDD_INDEX_MAN_POSTPROCESSING WHERE IDXMAN_ID = @MANINDEX_ID)
|
||
BEGIN
|
||
DECLARE
|
||
@NB_ID INTEGER
|
||
DECLARE c_NBFUNCTION CURSOR FOR
|
||
SELECT GUID FROM TBDD_INDEX_MAN_POSTPROCESSING WHERE IDXMAN_ID = @MANINDEX_ID ORDER BY SEQUENCE ASC
|
||
OPEN c_NBFUNCTION
|
||
FETCH NEXT FROM c_NBFUNCTION INTO @NB_ID
|
||
WHILE @@FETCH_STATUS = 0
|
||
BEGIN
|
||
PRINT '@NB_ID: ' + CONVERT(VARCHAR(5),@NB_ID)
|
||
INSERT INTO TBDD_INDEX_MAN_POSTPROCESSING (
|
||
IDXMAN_ID, TYPE, FUNCTION1, FUNCTION2, TEXT1, TEXT2, TEXT3, SEQUENCE, ADDED_WHO, VARIANT)
|
||
SELECT @NEW_ID, TYPE, FUNCTION1, FUNCTION2, TEXT1, TEXT2, TEXT3, [SEQUENCE], 'COPY-ROUTINE',VARIANT
|
||
FROM TBDD_INDEX_MAN_POSTPROCESSING WHERE GUID = @NB_ID
|
||
FETCH NEXT FROM c_NBFUNCTION INTO @NB_ID
|
||
END
|
||
CLOSE c_NBFUNCTION
|
||
DEALLOCATE c_NBFUNCTION
|
||
END
|
||
|
||
FETCH NEXT FROM c_INDEX INTO @MANINDEX_ID
|
||
END
|
||
CLOSE c_INDEX
|
||
DEALLOCATE c_INDEX
|
||
END
|
||
GO
|
||
|
||
-- 20.09.2024 MS ModuleName ge<67>ndert
|
||
CREATE OR ALTER VIEW [dbo].[VWGI_DOCTYPE] AS
|
||
SELECT DISTINCT
|
||
T.GUID AS [USER_ID],
|
||
T.USERNAME,
|
||
--T2.NAME AS GROUP_NAME,
|
||
T3.DOCTYPE_ID,
|
||
T4.BEZEICHNUNG AS DOCTYPE,
|
||
T4.BEZEICHNUNG AS DOCTYPE_ONLY,
|
||
T4.KURZNAME,
|
||
T4.ZIEL_PFAD,
|
||
T4.AKTIV,
|
||
T4.NAMENKONVENTION,
|
||
T4.OBJEKTTYP,
|
||
--T4.IDB_FILESTORE_ID,
|
||
T4.SEQUENCE
|
||
FROM
|
||
TBDD_USER T,
|
||
TBDD_GROUPS_USER T1,
|
||
TBDD_GROUPS T2,
|
||
TBDD_USRGRP_DOKTYPE T3,
|
||
TBDD_DOKUMENTART T4
|
||
WHERE
|
||
T4.AKTIV = 1 AND
|
||
T.GUID = T1.[USER_ID] AND
|
||
T1.GROUP_ID = T2.GUID AND
|
||
T2.GUID = T3.GROUP_ID AND
|
||
T3.DOCTYPE_ID = T4.GUID AND
|
||
T4.GUID in (SELECT DOKART_ID FROM TBDD_DOKUMENTART_MODULE WHERE MODULE_ID = (SELECT GUID FROM TBDD_MODULES WHERE SHORT_NAME = 'fileFLOW'))
|
||
UNION
|
||
SELECT DISTINCT
|
||
T.GUID AS [USER_ID],
|
||
T.USERNAME,
|
||
--'' AS GROUP_NAME,
|
||
T4.GUID as DOCTYPE_ID,
|
||
T4.BEZEICHNUNG AS DOCTYPE,
|
||
T4.BEZEICHNUNG AS DOCTYPE_ONLY,
|
||
T4.KURZNAME,
|
||
T4.ZIEL_PFAD,
|
||
T4.AKTIV,
|
||
T4.NAMENKONVENTION,
|
||
T4.OBJEKTTYP,
|
||
--T4.IDB_FILESTORE_ID,
|
||
T4.SEQUENCE
|
||
FROM
|
||
TBDD_USER T,
|
||
TBDD_USER_DOKTYPE T3,
|
||
TBDD_DOKUMENTART T4
|
||
WHERE
|
||
T4.AKTIV = 1 AND
|
||
T.GUID = T3.[USER_ID] AND
|
||
T3.DOCTYPE_ID = T4.GUID AND
|
||
T4.GUID in (SELECT DOKART_ID FROM TBDD_DOKUMENTART_MODULE WHERE MODULE_ID = (SELECT GUID FROM TBDD_MODULES WHERE SHORT_NAME = 'fileFLOW'))
|
||
GO
|
||
|
||
CREATE VIEW [dbo].[VWGI_DOCTYPE] AS
|
||
SELECT DISTINCT
|
||
T.GUID AS [USER_ID],
|
||
T.USERNAME,
|
||
--T2.NAME AS GROUP_NAME,
|
||
T3.DOCTYPE_ID,
|
||
T4.BEZEICHNUNG AS DOCTYPE,
|
||
T4.BEZEICHNUNG AS DOCTYPE_ONLY,
|
||
T4.KURZNAME,
|
||
T4.ZIEL_PFAD,
|
||
T4.AKTIV,
|
||
T4.NAMENKONVENTION,
|
||
T4.OBJEKTTYP,
|
||
0 IDB_FILESTORE_ID--T4.IDB_FILESTORE_ID,
|
||
T4.SEQUENCE
|
||
FROM
|
||
TBDD_USER T,
|
||
TBDD_GROUPS_USER T1,
|
||
TBDD_GROUPS T2,
|
||
TBDD_USRGRP_DOKTYPE T3,
|
||
TBDD_DOKUMENTART T4
|
||
WHERE
|
||
T4.AKTIV = 1 AND
|
||
T.GUID = T1.[USER_ID] AND
|
||
T1.GROUP_ID = T2.GUID AND
|
||
T2.GUID = T3.GROUP_ID AND
|
||
T3.DOCTYPE_ID = T4.GUID AND
|
||
T4.GUID in (SELECT DOKART_ID FROM TBDD_DOKUMENTART_MODULE WHERE MODULE_ID = (SELECT GUID FROM TBDD_MODULES WHERE UPPER(SHORT_NAME) = ('GLOBIX')))
|
||
UNION
|
||
SELECT DISTINCT
|
||
T.GUID AS [USER_ID],
|
||
T.USERNAME,
|
||
--'' AS GROUP_NAME,
|
||
T4.GUID as DOCTYPE_ID,
|
||
T4.BEZEICHNUNG AS DOCTYPE,
|
||
T4.BEZEICHNUNG AS DOCTYPE_ONLY,
|
||
T4.KURZNAME,
|
||
T4.ZIEL_PFAD,
|
||
T4.AKTIV,
|
||
T4.NAMENKONVENTION,
|
||
T4.OBJEKTTYP,
|
||
0 IDB_FILESTORE_ID,--T4.IDB_FILESTORE_ID,
|
||
T4.SEQUENCE
|
||
FROM
|
||
TBDD_USER T,
|
||
TBDD_USER_DOKTYPE T3,
|
||
TBDD_DOKUMENTART T4
|
||
WHERE
|
||
T4.AKTIV = 1 AND
|
||
T.GUID = T3.[USER_ID] AND
|
||
T3.DOCTYPE_ID = T4.GUID AND
|
||
T4.GUID in (SELECT DOKART_ID FROM TBDD_DOKUMENTART_MODULE WHERE MODULE_ID = (SELECT GUID FROM TBDD_MODULES WHERE UPPER(SHORT_NAME) = ('GLOBIX')))
|
||
GO
|
||
|
||
|
||
CREATE TABLE TBGI_REGEX_DOCTYPE(
|
||
GUID INTEGER NOT NULL IDENTITY(1,1),
|
||
REGEX VARCHAR(500) NOT NULL,
|
||
DOCTYPE_ID INTEGER,
|
||
ADDED_WHO VARCHAR(50) NOT NULL DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBGI_REGEX_DOCTYPE PRIMARY KEY (GUID),
|
||
CONSTRAINT FK_TBGI_REGEX_DOCTYPE_DTID FOREIGN KEY (DOCTYPE_ID) REFERENCES TBDD_DOKUMENTART (GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBGI_REGEX_DOCTYPE_AFT_UPD ON TBGI_REGEX_DOCTYPE
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBGI_REGEX_DOCTYPE SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBGI_REGEX_DOCTYPE.GUID = INSERTED.GUID
|
||
GO
|
||
IF EXISTS (SELECT name from sys.indexes
|
||
WHERE name = N'UQ_TBGI_REGEX_DOCTYPE_DOCTYPE_ID')
|
||
DROP INDEX UQ_TBGI_REGEX_DOCTYPE_DOCTYPE_ID ON TBGI_REGEX_DOCTYPE;
|
||
GO
|
||
CREATE UNIQUE INDEX UQ_TBGI_REGEX_DOCTYPE_DOCTYPE_ID
|
||
ON TBGI_REGEX_DOCTYPE (DOCTYPE_ID);
|
||
GO
|
||
IF NOT EXISTS(SELECT GUID FROM TBDD_3RD_PARTY_MODULES WHERE NAME = 'GDPICTURE_FILEFLOW')
|
||
|
||
BEGIN
|
||
INSERT INTO TBDD_3RD_PARTY_MODULES (ACTIVE,NAME,LICENSE) VALUES (
|
||
1,
|
||
'GDPICTURE_FILEFLOW',
|
||
'kG1Qf9PwmqgR8aDmIW2zI_ebj48RzqAJegRxcystEmkbTGQqfkNBdFOXIb6C_A00Ra8zZkrHdfjqzOPXK7kgkF2YDhvrqKfqh4WDug2vOt0qO31IommzkANSuLjZ4zmraoubyEVd25rE3veQ2h_j7tGIoH_LyIHmy24GaXsxdG0yCzIBMdiLbMMMDwcPY-809KeZ83Grv76OVhFvcbBWyYc251vou1N-kGg5_ZlHDgfWoY85gTLRxafjD3KS_i9ARW4BMiy36y8n7UP2jN8kGRnW_04ubpFtfjJqvtsrP_J9D0x7bqV8xtVtT5JI6dpKsVTiMgDCrIcoFSo5gCC1fw9oUopX4TDCkBQttO4-WHBlOeq9dG5Yb0otonVmJKaQA2tP6sMR-lZDs3ql_WI9t91yPWgpssrJUxSHDd27_LMTH_owJIqkF3NOJd9mYQuAv22oNKFYbH8e41pVKb8cT33Y9CgcQ_sy6YDA5PTuIRi67mjKge_nD9rd0IN213Ir9M_EFWqg9e4haWzIdHXQUo0md70kVhPX4UIH_BKJnxEEnFfoFRNMh77bB0N4jkcBEHPl-ghOERv8dOztf4vCnNpzzWvcLD2cqWIm6THy8XGGq9h4hp8aEreRleSMwv9QQAC7mjLwhQ1rBYkpUHlpTjhTLnMwHknl6HH0Z6zzmsgkRKVyfquv94Pd7QbQfZrRka0ss_48pf9p8hAywEn81Q=='
|
||
)
|
||
END
|
||
GO
|
||
--#################################### EASYFLOW ############################################################################################
|
||
IF not EXISTS(SELECT GUID FROM TBDD_MODULES WHERE NAME = 'Clipboard-Watcher' )
|
||
INSERT INTO TBDD_MODULES (NAME, SHORT_NAME, LICENSE,ACTIVE) VALUES ('Clipboard-Watcher','CW','kc6j9HSv/UJVAzFjMZv2A3wHZFy+2nNLKP9Qs8g9EVY=',1)
|
||
GO
|
||
UPDATE TBDD_MODULES SET DB_VERSION = '2.3.0.0' where UPPER(NAME) = UPPER('Clipboard-Watcher')
|
||
GO
|
||
--ADDs THE USER WITH ADMIN-RIGHTS TO USER-MODULE RELATION
|
||
INSERT INTO TBDD_USER_MODULES(USER_ID,MODULE_ID)
|
||
SELECT DISTINCT USER_ID,(SELECT GUID FROM TBDD_MODULES WHERE SHORT_NAME = 'CW')
|
||
FROM TBDD_USER_MODULES where IS_ADMIN = 1
|
||
GO
|
||
INSERT INTO TBDD_CLIENT_USER (USER_ID,CLIENT_ID) SELECT GUID,1 FROM TBDD_USER WHERE GUID NOT IN (SELECT USER_ID FROM TBDD_CLIENT_USER WHERE CLIENT_ID = 1)
|
||
GO
|
||
CREATE TABLE TBCW_CONFIGURATION
|
||
(
|
||
GUID TINYINT,
|
||
WD_UNICODE BIT NOT NULL DEFAULT 1,
|
||
GDPICTURE_LICENSE VARCHAR(500) NOT NULL DEFAULT '',
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBCW_CONFIGURATION_GUID PRIMARY KEY(GUID),
|
||
CONSTRAINT CH_TBCW_CONFIGURATION_GUID CHECK(GUID = 1)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBCW_CONFIGURATION_AFT_UPD ON TBCW_CONFIGURATION
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBCW_CONFIGURATION SET CHANGED_WHEN = GETDATE() FROM INSERTED
|
||
WHERE TBCW_CONFIGURATION.GUID = INSERTED.GUID
|
||
GO
|
||
INSERT INTO TBCW_CONFIGURATION (GUID) VALUES (1)
|
||
GO
|
||
--ALTER TABLE TBDD_CLIENT
|
||
--ADD LICENSE_DDCBSEARCHER VARCHAR(5000) NOT NULL DEFAULT ''
|
||
--GO
|
||
CREATE TABLE TBCW_PROFILES
|
||
(
|
||
GUID INTEGER NOT NULL IDENTITY(1,1),
|
||
NAME VARCHAR(100) NOT NULL,
|
||
PROFILE_TYPE SMALLINT NOT NULL DEFAULT 1,
|
||
REGEX_EXPRESSION VARCHAR(100) NOT NULL,
|
||
ACTIVE BIT NOT NULL DEFAULT 0,
|
||
COMMENT VARCHAR(500),
|
||
ADDED_WHO VARCHAR(50) NOT NULL DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBCW_PROFILES PRIMARY KEY (GUID),
|
||
CONSTRAINT UQ_TBCW_PROFILES_NAME UNIQUE(NAME)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBCW_PROFILES_AFT_UPD ON TBCW_PROFILES
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBCW_PROFILES SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBCW_PROFILES.GUID = INSERTED.GUID
|
||
GO
|
||
CREATE TABLE TBCW_USER_PROFILE
|
||
(
|
||
GUID INT IDENTITY(1,1),
|
||
PROFILE_ID INT NOT NULL,
|
||
[USER_ID] INT NOT NULL,
|
||
ADDED_WHO VARCHAR(50) NOT NULL DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CONSTRAINT PK_TBCW_USER_PROFILE PRIMARY KEY (GUID),
|
||
CONSTRAINT UQ_TBCW_USER_PROFILE_PID_UID UNIQUE (PROFILE_ID,[USER_ID])
|
||
)
|
||
GO
|
||
CREATE TABLE TBCW_PROFILE_PROCESS
|
||
(
|
||
GUID INT IDENTITY(1,1),
|
||
PROFILE_ID INT NOT NULL,
|
||
PROC_NAME VARCHAR(100) NOT NULL,
|
||
ADDED_WHO VARCHAR(50) NOT NULL DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CONSTRAINT PK_TBCW_PROFILE_PROCESS PRIMARY KEY (GUID),
|
||
CONSTRAINT UQ_TBCW_PROFILE_PROCESS UNIQUE (PROFILE_ID,PROC_NAME)
|
||
)
|
||
GO
|
||
CREATE TABLE TBCW_PROF_DOC_SEARCH(
|
||
GUID INTEGER NOT NULL IDENTITY(1,1),
|
||
PROFILE_ID INTEGER NOT NULL,
|
||
CONN_ID TinyINT NOT NULL DEFAULT 0,
|
||
SQL_COMMAND VARCHAR(MAX) NOT NULL,
|
||
COUNT_COMMAND VARCHAR(MAX) NOT NULL,
|
||
TAB_INDEX TINYINT NOT NULL DEFAULT 0,
|
||
ACTIVE BIT NOT NULL DEFAULT 0,
|
||
TAB_TITLE VARCHAR(100) NOT NULL DEFAULT 'NOT DEFINED',
|
||
ADDED_WHO VARCHAR(50) NOT NULL DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBCW_PROF_DOC_SEARCH PRIMARY KEY (GUID),
|
||
CONSTRAINT FK_TBCW_PROF_DOC_SEARCH_PROF_IF FOREIGN KEY (PROFILE_ID) REFERENCES TBCW_PROFILES (GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBCW_PROF_DOC_SEARCH_AFT_UPD ON TBCW_PROF_DOC_SEARCH
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBCW_PROF_DOC_SEARCH SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBCW_PROF_DOC_SEARCH.GUID = INSERTED.GUID
|
||
GO
|
||
CREATE TRIGGER [dbo].[TBCW_PROF_DOC_SEARCH_AFT_INS] ON [dbo].[TBCW_PROF_DOC_SEARCH]
|
||
WITH EXECUTE AS CALLER
|
||
FOR INSERT
|
||
AS
|
||
BEGIN TRY
|
||
DECLARE @TABINDEX TINYINT
|
||
,@MAX_INDEX TINYINT
|
||
,@PROFILE_ID INT
|
||
,@GUID INTEGER
|
||
SELECT @TABINDEX = TAB_INDEX
|
||
,@PROFILE_ID = PROFILE_ID
|
||
,@GUID = GUID FROM inserted
|
||
|
||
SELECT @MAX_INDEX = ISNULL(MAX(TAB_INDEX),0) FROM TBCW_PROF_DOC_SEARCH WHERE PROFILE_ID = @PROFILE_ID AND GUID <> @GUID
|
||
UPDATE TBCW_PROF_DOC_SEARCH SET TAB_INDEX = @MAX_INDEX
|
||
FROM INSERTED
|
||
WHERE TBCW_PROF_DOC_SEARCH.GUID = INSERTED.GUID
|
||
|
||
UPDATE TBCW_PROF_DOC_SEARCH SET ADDED_WHEN = GETDATE() FROM INSERTED WHERE TBCW_PROF_DOC_SEARCH.GUID = INSERTED.GUID
|
||
|
||
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'ERROR IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE())
|
||
+ ' - ERROR-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
END CATCH
|
||
GO
|
||
--DROP TABLE TBCW_PROF_DATA_SEARCH
|
||
--GO
|
||
CREATE TABLE TBCW_PROF_DATA_SEARCH(
|
||
GUID INTEGER NOT NULL IDENTITY(1,1),
|
||
PROFILE_ID INTEGER NOT NULL,
|
||
CONN_ID TinyINT NOT NULL DEFAULT 0,
|
||
SQL_COMMAND VARCHAR(MAX) NOT NULL,
|
||
COUNT_COMMAND VARCHAR(MAX) NOT NULL,
|
||
TAB_INDEX TINYINT NOT NULL DEFAULT 0,
|
||
ACTIVE BIT NOT NULL DEFAULT 0,
|
||
TAB_TITLE VARCHAR(100) NOT NULL DEFAULT 'NOT DEFINED',
|
||
ADDED_WHO VARCHAR(50) NOT NULL DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBCW_PROF_DATA_SEARCH PRIMARY KEY (GUID),
|
||
CONSTRAINT FK_TBCW_PROF_DATA_SEARCH_PROF_IF FOREIGN KEY (PROFILE_ID) REFERENCES TBCW_PROFILES (GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBCW_PROF_DATA_SEARCH_AFT_UPD ON TBCW_PROF_DATA_SEARCH
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBCW_PROF_DATA_SEARCH SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBCW_PROF_DATA_SEARCH.GUID = INSERTED.GUID
|
||
GO
|
||
CREATE TRIGGER [dbo].[TBCW_PROF_DATA_SEARCH_AFT_INS] ON [dbo].[TBCW_PROF_DATA_SEARCH]
|
||
WITH EXECUTE AS CALLER
|
||
FOR INSERT
|
||
AS
|
||
BEGIN TRY
|
||
DECLARE @TABINDEX TINYINT
|
||
,@MAX_INDEX TINYINT
|
||
,@PROFILE_ID INT
|
||
,@GUID INTEGER
|
||
SELECT @TABINDEX = TAB_INDEX
|
||
,@PROFILE_ID = PROFILE_ID
|
||
,@GUID = GUID FROM inserted
|
||
|
||
SELECT @MAX_INDEX = ISNULL(MAX(TAB_INDEX),0) FROM TBCW_PROF_DATA_SEARCH WHERE PROFILE_ID = @PROFILE_ID AND GUID <> @GUID
|
||
UPDATE TBCW_PROF_DATA_SEARCH SET TAB_INDEX = @MAX_INDEX
|
||
FROM INSERTED
|
||
WHERE TBCW_PROF_DATA_SEARCH.GUID = INSERTED.GUID
|
||
UPDATE TBCW_PROF_DATA_SEARCH SET ADDED_WHEN = GETDATE() FROM INSERTED WHERE TBCW_PROF_DATA_SEARCH.GUID = INSERTED.GUID
|
||
|
||
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'ERROR IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE())
|
||
+ ' - ERROR-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
END CATCH
|
||
GO
|
||
|
||
CREATE TABLE [dbo].[TBCW_GROUP_PROFILE](
|
||
GUID INTEGER IDENTITY(1,1) NOT NULL,
|
||
PROFILE_ID INTEGER NOT NULL,
|
||
GROUP_ID INTEGER NOT NULL,
|
||
ADDED_WHO VARCHAR(50) NOT NULL DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME NULL DEFAULT GETDATE(),
|
||
CONSTRAINT PK_TBCW_GROUP_PROFILE PRIMARY KEY (GUID),
|
||
CONSTRAINT UQ_TBCW_GROUP_PROFILE_PID_UID UNIQUE (PROFILE_ID,GROUP_ID)
|
||
)
|
||
|
||
GO
|
||
|
||
CREATE TABLE TBCW_PROF_REL_WINDOW(
|
||
GUID INTEGER NOT NULL IDENTITY(1,1),
|
||
PROCESS_ID INTEGER NOT NULL,
|
||
DESCRIPTION VARCHAR(250) NOT NULL DEFAULT '',
|
||
REGEX VARCHAR(500) NOT NULL,
|
||
SEQUENCE TINYINT NOT NULL DEFAULT 0,
|
||
ADDED_WHO VARCHAR(50) NOT NULL DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBCW_PROF_REL_WINDOW PRIMARY KEY (GUID),
|
||
CONSTRAINT FK_TBCW_PROF_REL_WINDOW_PROCESS_ID FOREIGN KEY (PROCESS_ID) REFERENCES TBCW_PROFILE_PROCESS (GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBCW_PROF_REL_WINDOW_AFT_UPD ON TBCW_PROF_REL_WINDOW
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBCW_PROF_REL_WINDOW SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBCW_PROF_REL_WINDOW.GUID = INSERTED.GUID
|
||
GO
|
||
CREATE TRIGGER [dbo].[TBCW_PROF_REL_WINDOW_AFT_INS] ON [dbo].TBCW_PROF_REL_WINDOW
|
||
WITH EXECUTE AS CALLER
|
||
FOR INSERT
|
||
AS
|
||
BEGIN TRY
|
||
DECLARE @SEQUENCE TINYINT
|
||
,@MAX_SEQUENCE TINYINT
|
||
,@PROCESS_ID INT
|
||
,@GUID INTEGER
|
||
SELECT @SEQUENCE = SEQUENCE
|
||
,@PROCESS_ID = PROCESS_ID
|
||
,@GUID = GUID FROM inserted
|
||
|
||
SELECT @MAX_SEQUENCE = ISNULL(MAX(SEQUENCE),0) FROM TBCW_PROF_REL_WINDOW WHERE PROCESS_ID = @PROCESS_ID AND GUID <> @GUID
|
||
UPDATE TBCW_PROF_REL_WINDOW SET SEQUENCE = @MAX_SEQUENCE
|
||
FROM INSERTED
|
||
WHERE TBCW_PROF_REL_WINDOW.GUID = INSERTED.GUID
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'ERROR IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE())
|
||
+ ' - ERROR-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
END CATCH
|
||
GO
|
||
CREATE TABLE TBCW_PROF_REL_CONTROL(
|
||
GUID INTEGER NOT NULL IDENTITY(1,1),
|
||
DESCRIPTION VARCHAR(250) NOT NULL,
|
||
WINDOW_ID INTEGER NOT NULL,
|
||
CONTROL_NAME VARCHAR(500) NOT NULL DEFAULT '',
|
||
[TOPLEFT_TOP] INTEGER NOT NULL DEFAULT 0,
|
||
[TOPLEFT_LEFT] INTEGER NOT NULL DEFAULT 0,
|
||
[TOPLEFT_RIGHT] INTEGER NOT NULL DEFAULT 0,
|
||
[TOPLEFT_BOTTOM] INTEGER NOT NULL DEFAULT 0,
|
||
[TOPRIGHT_TOP] INTEGER NOT NULL DEFAULT 0,
|
||
[TOPRIGHT_LEFT] INTEGER NOT NULL DEFAULT 0,
|
||
[TOPRIGHT_RIGHT] INTEGER NOT NULL DEFAULT 0,
|
||
[TOPRIGHT_BOTTOM] INTEGER NOT NULL DEFAULT 0,
|
||
[BOTTOMLEFT_TOP] INTEGER NOT NULL DEFAULT 0,
|
||
[BOTTOMLEFT_LEFT] INTEGER NOT NULL DEFAULT 0,
|
||
[BOTTOMLEFT_RIGHT] INTEGER NOT NULL DEFAULT 0,
|
||
[BOTTOMLEFT_BOTTOM] INTEGER NOT NULL DEFAULT 0,
|
||
[BOTTOMRIGHT_TOP] INTEGER NOT NULL DEFAULT 0,
|
||
[BOTTOMRIGHT_LEFT] INTEGER NOT NULL DEFAULT 0,
|
||
[BOTTOMRIGHT_RIGHT] INTEGER NOT NULL DEFAULT 0,
|
||
[BOTTOMRIGHT_BOTTOM] INTEGER NOT NULL DEFAULT 0,
|
||
SEQUENCE TINYINT NOT NULL DEFAULT 0,
|
||
ADDED_WHO VARCHAR(50) NOT NULL DEFAULT 'DEFAULT',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBCW_PROF_REL_CONTROL PRIMARY KEY (GUID),
|
||
CONSTRAINT FK_TBCW_PROF_REL_CONTROL_WINDOW_ID FOREIGN KEY (WINDOW_ID) REFERENCES TBCW_PROF_REL_WINDOW (GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBCW_PROF_REL_CONTROL_AFT_UPD ON TBCW_PROF_REL_CONTROL
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBCW_PROF_REL_CONTROL SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBCW_PROF_REL_CONTROL.GUID = INSERTED.GUID
|
||
GO
|
||
|
||
CREATE TRIGGER TBCW_PROF_REL_CONTROL_AFT_INS ON TBCW_PROF_REL_CONTROL
|
||
WITH EXECUTE AS CALLER
|
||
FOR INSERT
|
||
AS
|
||
BEGIN TRY
|
||
DECLARE @SEQUENCE TINYINT
|
||
,@MAX_SEQUENCE TINYINT
|
||
,@WINDOW_ID INT
|
||
,@GUID INTEGER
|
||
SELECT @SEQUENCE = SEQUENCE
|
||
,@WINDOW_ID = WINDOW_ID
|
||
,@GUID = GUID FROM inserted
|
||
|
||
SELECT @MAX_SEQUENCE = ISNULL(MAX(SEQUENCE),0) FROM TBCW_PROF_REL_CONTROL WHERE WINDOW_ID = @WINDOW_ID AND GUID <> @GUID
|
||
UPDATE TBCW_PROF_REL_CONTROL SET SEQUENCE = @MAX_SEQUENCE
|
||
FROM INSERTED
|
||
WHERE TBCW_PROF_REL_CONTROL.GUID = INSERTED.GUID
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'ERROR IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE())
|
||
+ ' - ERROR-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
END CATCH
|
||
GO
|
||
CREATE TRIGGER [dbo].[TBCW_PROF_REL_CONTROLAFT_INS] ON [dbo].TBCW_PROF_REL_CONTROL
|
||
WITH EXECUTE AS CALLER
|
||
FOR INSERT
|
||
AS
|
||
BEGIN TRY
|
||
DECLARE @SEQUENCE TINYINT
|
||
,@MAX_SEQUENCE TINYINT
|
||
,@WINDOW_ID INT
|
||
,@GUID INTEGER
|
||
SELECT @SEQUENCE = SEQUENCE
|
||
,@WINDOW_ID = @WINDOW_ID
|
||
,@GUID = GUID FROM inserted
|
||
|
||
SELECT @MAX_SEQUENCE = ISNULL(MAX(SEQUENCE),0) FROM TBCW_PROF_REL_CONTROL WHERE @WINDOW_ID = @WINDOW_ID AND GUID <> @GUID
|
||
UPDATE TBCW_PROF_REL_CONTROL SET SEQUENCE = @MAX_SEQUENCE
|
||
FROM INSERTED
|
||
WHERE TBCW_PROF_REL_CONTROL.GUID = INSERTED.GUID
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'ERROR IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE())
|
||
+ ' - ERROR-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
END CATCH
|
||
GO
|
||
/*##### PROCEDURES ####*/
|
||
CREATE PROCEDURE [dbo].[PRCW_DELETE_PROFILE](@pPROFILE_ID INT)
|
||
AS
|
||
BEGIN TRY
|
||
delete from TBCW_PROF_DATA_SEARCH where PROFILE_ID = @pPROFILE_ID
|
||
delete from TBCW_PROF_DOC_SEARCH where PROFILE_ID = @pPROFILE_ID
|
||
|
||
delete from TBCW_PROF_REL_CONTROL where WINDOW_ID IN (SELECT GUID FROM TBCW_PROF_REL_WINDOW WHERE PROCESS_ID IN (SELECT GUID FROM TBCW_PROFILE_PROCESS WHERE PROFILE_ID = @pPROFILE_ID))
|
||
delete from TBCW_PROF_REL_WINDOW where PROCESS_ID IN (SELECT GUID FROM TBCW_PROFILE_PROCESS WHERE PROFILE_ID = @pPROFILE_ID)
|
||
delete from TBCW_PROFILE_PROCESS where PROFILE_ID = @pPROFILE_ID
|
||
|
||
delete from TBCW_USER_PROFILE where PROFILE_ID = @pPROFILE_ID
|
||
delete from TBCW_PROFILES where GUID = @pPROFILE_ID
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'FEHLER IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE()) + ' - ZEILE: ' + CONVERT(VARCHAR(10),ERROR_LINE())
|
||
+ ' - FEHLER-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
END CATCH
|
||
GO
|
||
CREATE PROCEDURE [dbo].[PRCW_DELETE_PROCESS](@pPROCESS_ID INT)
|
||
AS
|
||
BEGIN TRY
|
||
delete from TBCW_PROF_REL_CONTROL where WINDOW_ID IN (SELECT GUID FROM TBCW_PROF_REL_WINDOW WHERE PROCESS_ID = @pPROCESS_ID)
|
||
delete from TBCW_PROF_REL_WINDOW where PROCESS_ID = @pPROCESS_ID
|
||
delete from TBCW_PROFILE_PROCESS where GUID = @pPROCESS_ID
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'FEHLER IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE()) + ' - ZEILE: ' + CONVERT(VARCHAR(10),ERROR_LINE())
|
||
+ ' - FEHLER-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
END CATCH
|
||
GO
|
||
CREATE PROCEDURE [dbo].[PRCW_DELETE_WINDOW](@pWINDOW_ID INT)
|
||
AS
|
||
BEGIN TRY
|
||
delete from TBCW_PROF_REL_CONTROL where WINDOW_ID = @pWINDOW_ID
|
||
delete from TBCW_PROF_REL_WINDOW where GUID = @pWINDOW_ID
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'FEHLER IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE()) + ' - ZEILE: ' + CONVERT(VARCHAR(10),ERROR_LINE())
|
||
+ ' - FEHLER-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
END CATCH
|
||
GO
|
||
CREATE FUNCTION FNCW_GET_SEARCH_COUNT_FOR_CONNECTION(@CONNECTION_ID int)
|
||
RETURNS int
|
||
AS
|
||
BEGIN
|
||
DECLARE @RESULT int
|
||
|
||
SELECT @RESULT = SUM(t.CNT) FROM (
|
||
SELECT COUNT(*) AS CNT FROM TBCW_PROF_DATA_SEARCH WHERE CONN_ID = @CONNECTION_ID
|
||
UNION ALL
|
||
SELECT COUNT(*) AS CNT FROM TBCW_PROF_DOC_SEARCH WHERE CONN_ID = @CONNECTION_ID
|
||
) t
|
||
|
||
RETURN @RESULT
|
||
END
|
||
GO
|
||
|
||
/*##### VIEWS ####*/
|
||
CREATE VIEW [dbo].[VWCW_GROUP_PROFILE] AS
|
||
SELECT
|
||
T1.GUID,
|
||
T.GUID AS PROFIL_ID,
|
||
T.NAME AS PROFIL_NAME,
|
||
T.REGEX_EXPRESSION,
|
||
T.COMMENT,
|
||
T.ACTIVE,
|
||
T.PROFILE_TYPE,
|
||
T1.GROUP_ID,
|
||
T3.NAME AS GROUP_NAME
|
||
FROM
|
||
TBCW_PROFILES T
|
||
,TBCW_GROUP_PROFILE T1
|
||
, TBDD_GROUPS T3
|
||
WHERE
|
||
T.GUID = T1.PROFILE_ID
|
||
AND T1.GROUP_ID = T3.GUID;
|
||
GO
|
||
--Changed 29.01.2025 MS Prozesse raus, Union Gruppen
|
||
CREATE VIEW [dbo].[VWCW_USER_PROFILE] AS
|
||
SELECT DISTINCT
|
||
T.GUID,
|
||
T.GUID AS PROFIL_ID,
|
||
T.NAME AS PROFIL_NAME,
|
||
T.REGEX_EXPRESSION,
|
||
T.COMMENT,
|
||
T.ACTIVE,
|
||
T.PROFILE_TYPE,
|
||
T1.USER_ID AS [USER_ID],
|
||
USR.NAME AS USER_SURNAME,
|
||
USR.PRENAME AS USER_PRENAME,
|
||
USR.USERNAME,
|
||
'USER_PROFILE' AS SOURCE
|
||
FROM TBCW_PROFILES T
|
||
INNER JOIN TBCW_USER_PROFILE T1 ON T.GUID = T1.PROFILE_ID
|
||
INNER JOIN TBDD_USER USR ON T1.USER_ID = USR.GUID
|
||
UNION
|
||
SELECT DISTINCT
|
||
GP.PROFIL_ID AS GUID,
|
||
GP.PROFIL_ID,
|
||
GP.PROFIL_NAME,
|
||
GP.REGEX_EXPRESSION,
|
||
GP.COMMENT,
|
||
GP.ACTIVE,
|
||
GP.PROFILE_TYPE,
|
||
GU.USR_ID AS [USER_ID],
|
||
USR.NAME AS USER_SURNAME,
|
||
USR.PRENAME AS USER_PRENAME,
|
||
USR.USERNAME,
|
||
'GROUP_PROFILE' AS SOURCE
|
||
|
||
FROM
|
||
VWCW_GROUP_PROFILE GP INNER JOIN
|
||
VWDD_GROUPS_USER GU ON GP.GROUP_ID = GU.GRP_ID INNER JOIN
|
||
TBDD_USER USR ON GU.USR_ID = USR.GUID ;
|
||
GO
|
||
|
||
CREATE VIEW VWCW_PROFILE_REL_WINDOW AS
|
||
SELECT DISTINCT TOP 100 PERCENT
|
||
T.GUID
|
||
,T.PROCESS_ID
|
||
,T2.USER_ID
|
||
,T1.PROC_NAME AS PROCESS_NAME
|
||
,T1.PROFILE_ID
|
||
,T.DESCRIPTION
|
||
,T.REGEX
|
||
,T.SEQUENCE
|
||
FROM
|
||
TBCW_PROF_REL_WINDOW T
|
||
,TBCW_PROFILE_PROCESS T1
|
||
,VWCW_USER_PROFILE T2
|
||
WHERE
|
||
T.PROCESS_ID = T1.GUID AND
|
||
T1.PROFILE_ID = T2.PROFIL_ID
|
||
|
||
ORDER BY T.SEQUENCE;
|
||
GO
|
||
|
||
CREATE VIEW VWCW_PROFILE_REL_CONTROL AS
|
||
SELECT DISTINCT TOP 100 PERCENT
|
||
T.GUID
|
||
,T1.USER_ID
|
||
,TP.PROC_NAME AS PROCESS_NAME
|
||
,T1.PROFIL_ID AS PROFILE_ID
|
||
,T.WINDOW_ID
|
||
,T.DESCRIPTION
|
||
,T.SEQUENCE
|
||
,T.CONTROL_NAME
|
||
,T.TOPLEFT_LEFT
|
||
,T.TOPLEFT_RIGHT
|
||
,T.TOPLEFT_TOP
|
||
,T.TOPLEFT_BOTTOM
|
||
,T.TOPRIGHT_LEFT
|
||
,T.TOPRIGHT_RIGHT
|
||
,T.TOPRIGHT_TOP
|
||
,T.TOPRIGHT_BOTTOM
|
||
,T.BOTTOMLEFT_LEFT
|
||
,T.BOTTOMLEFT_RIGHT
|
||
,T.BOTTOMLEFT_TOP
|
||
,T.BOTTOMLEFT_BOTTOM
|
||
,T.BOTTOMRIGHT_LEFT
|
||
,T.BOTTOMRIGHT_RIGHT
|
||
,T.BOTTOMRIGHT_TOP
|
||
,T.BOTTOMRIGHT_BOTTOM
|
||
FROM
|
||
TBCW_PROF_REL_CONTROL T
|
||
,TBCW_PROF_REL_WINDOW TW
|
||
,TBCW_PROFILE_PROCESS TP
|
||
,VWCW_USER_PROFILE T1
|
||
WHERE
|
||
T.WINDOW_ID = TW.GUID AND
|
||
TW.PROCESS_ID = TP.GUID AND
|
||
TP.PROFILE_ID = T1.PROFIL_ID
|
||
ORDER BY T.SEQUENCE;
|
||
GO
|
||
--################################ taskFLOW #################################################################
|
||
UPDATE TBDD_MODULES SET DB_VERSION = '2.2.2.2' where NAME = 'Process-Manager'
|
||
GO
|
||
INSERT INTO TBDD_USER_MODULES (USER_ID,MODULE_ID,IS_ADMIN) SELECT GUID,(SELECT GUID FROM TBDD_MODULES WHERE SHORT_NAME = 'PM'),1 FROM TBDD_USER where USERNAME IN (SELECT USR_NAME FROM TBIMPORT_USER);
|
||
INSERT INTO TBDD_CLIENT_USER (USER_ID,CLIENT_ID) SELECT GUID,1 FROM TBDD_USER WHERE GUID NOT IN (SELECT USER_ID FROM TBDD_CLIENT_USER WHERE CLIENT_ID = 1);
|
||
INSERT INTO TBDD_GROUPS_USER (USER_ID,GROUP_ID)
|
||
SELECT GUID,(SELECT GUID FROM TBDD_GROUPS WHERE NAME = 'PM_ADMINS') FROM TBDD_USER WHERE USERNAME IN (SELECT USR_NAME FROM TBIMPORT_USER)
|
||
GO
|
||
CREATE TABLE TBPM_KONFIGURATION
|
||
(
|
||
GUID TINYINT,
|
||
LIZENZEN VARCHAR(2000),
|
||
INTERVALL_CKECK_NO_OF_FILES smallint NOT NULL DEFAULT 2,
|
||
VEKTOR_DELIMITER VARCHAR(1) NOT NULL DEFAULT '~',
|
||
EMAIL_ACTIVE BIT NOT NULL DEFAULT 0,
|
||
EMAIL_FROM VARCHAR(50),
|
||
EMAIL_SMTP VARCHAR(50),
|
||
EMAIL_USER VARCHAR(50),
|
||
EMAIL_PW VARCHAR(50),
|
||
EMAIL_REMINDER_HEADER VARCHAR(250),
|
||
EMAIL_REMINDER_FOOTER VARCHAR(250),
|
||
ADMIN_PW VARCHAR(100) NOT NULL DEFAULT 'ZGQ=',
|
||
ADMIN_SECURITY BIT NOT NULL DEFAULT 0,
|
||
SQL_PROFILE_MAIN_VIEW VARCHAR(MAX)NOT NULL DEFAULT '',
|
||
[SERVICE_SCHEDULE] VARCHAR(100) NOT NULL DEFAULT '07-18;1111100',
|
||
[SERVICE_IDXNAME_DOCID] VARCHAR(50) NOT NULL DEFAULT 'Dokument-ID',
|
||
[SERVICE_WMDRIVE_LETTER] VARCHAR(1) NOT NULL DEFAULT 'W',
|
||
[SERVICE_IDXNAME_CREATED] VARCHAR(50) NOT NULL DEFAULT 'DMS erstellt',
|
||
[SERVICE_LOG_ERRORS_ONLY] BIT NOT NULL DEFAULT 1,
|
||
WM_REL_PATH VARCHAR(100) NOT NULL DEFAULT '\\windream\objects',
|
||
WM_DRIVE_LETTER VARCHAR(1) NOT NULL DEFAULT 'W',
|
||
ERFASSTWER VARCHAR(50) DEFAULT 'PER DMSLite' NOT NULL,
|
||
ERSTELLTWER VARCHAR(50) DEFAULT 'DMSLite-Admin' NOT NULL,
|
||
ERSTELLTWANN DATETIME DEFAULT GETDATE() NOT NULL,
|
||
GEAENDERTWER VARCHAR(50),
|
||
GEAENDERTWANN DATETIME,
|
||
CONSTRAINT PK_TBPM_KONFIGURATION_GUID PRIMARY KEY(GUID),
|
||
CONSTRAINT CH_TBPM_KONFIGURATION_GUID CHECK(GUID = 1)
|
||
)
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
CREATE TRIGGER TBPM_KONFIGURATION_AFT_UPD ON TBPM_KONFIGURATION
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBPM_KONFIGURATION SET GEAENDERTWANN = GETDATE() FROM INSERTED WHERE TBPM_KONFIGURATION.GUID = INSERTED.GUID
|
||
GO
|
||
|
||
INSERT INTO TBPM_KONFIGURATION(GUID,LIZENZEN,EMAIL_REMINDER_HEADER,EMAIL_REMINDER_FOOTER)
|
||
VALUES
|
||
(1,'Y/R9cI8qEID774g/fqXzkrCdW5bhcB62jsBmRgJx2rI=','Der Process-Manager informiert Sie hiermit <20>ber nicht erledigte Dokumentenprozesse:<p>','<p>Bitte starten Sie Ihren Process-Manager und bearbeiten die entsprechenden Prozesse.<br>Vielen Dank.')
|
||
GO
|
||
--------------------------------------------------------------------------------
|
||
CREATE TABLE TBPM_TYPE
|
||
(
|
||
GUID SMALLINT NOT NULL IDENTITY (1, 1),
|
||
BEZEICHNUNG VARCHAR(100) NOT NULL UNIQUE,
|
||
ADDED_WHO VARCHAR(30) NOT NULL DEFAULT 'Digital Data',
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT (GETDATE()),
|
||
CHANGED_WHO VARCHAR(30),
|
||
CHANGED_WHEN DATETIME,
|
||
|
||
CONSTRAINT PK_TBPM_TYPE_GUID PRIMARY KEY (GUID)
|
||
)
|
||
GO
|
||
INSERT INTO TBPM_TYPE(BEZEICHNUNG) VALUES ('Metadata based')
|
||
GO
|
||
INSERT INTO TBPM_TYPE(BEZEICHNUNG) VALUES ('Serially')
|
||
GO
|
||
CREATE TRIGGER TBPM_TYPE_AFT_UPD ON TBPM_TYPE
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBPM_TYPE SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBPM_TYPE.GUID = INSERTED.GUID
|
||
GO
|
||
CREATE TABLE TBPM_PROFILE
|
||
(
|
||
GUID INTEGER NOT NULL IDENTITY (1, 1),
|
||
NAME VARCHAR(100) NOT NULL UNIQUE,
|
||
TITLE VARCHAR(150) NOT NULL DEFAULT 'DEFAULT-TITLE',
|
||
WD_OBJECTTYPE VARCHAR(200) NOT NULL,
|
||
PRIORITY INTEGER NOT NULL DEFAULT 1,
|
||
DESCRIPTION VARCHAR(250) ,
|
||
TYPE SMALLINT NOT NULL,
|
||
DISPLAY_MODE VARCHAR(20) NOT NULL DEFAULT 'Overview and Detail',
|
||
SHOW_DOCUMENT BIT NOT NULL DEFAULT 1,
|
||
LOG_INDEX VARCHAR(50) NOT NULL DEFAULT '',
|
||
IN_WORK BIT NOT NULL DEFAULT 0,
|
||
ACTIVE BIT NOT NULL DEFAULT 0,
|
||
WD_SEARCH NVARCHAR(MAX) NOT NULL,
|
||
PM_VEKTOR_INDEX VARCHAR(50) NOT NULL DEFAULT '',
|
||
NO_OF_DOCUMENTS INTEGER NOT NULL DEFAULT 0,
|
||
FINAL_PROFILE BIT NOT NULL DEFAULT 0,
|
||
FINAL_TEXT VARCHAR(250),
|
||
MOVE2FOLDER NVARCHAR(1000),
|
||
SORT_BY_LATEST BIT NOT NULL DEFAULT 0,
|
||
WORK_HISTORY_ENTRY VARCHAR(500),
|
||
TARGET_PATH_BLIND_FILE VARCHAR(500) NOT NULL DEFAULT '',
|
||
ANNOTATE_ALL_WORK_HISTORY_ENTRIES BIT NOT NULL DEFAULT 0,
|
||
ANNOTATE_WORK_HISTORY_ENTRY BIT NOT NULL DEFAULT 0,
|
||
SQL_VIEW NVARCHAR(MAX) NOT NULL DEFAULT '',
|
||
SQL_PROFILE_MAIN_VIEW NVARCHAR(MAX) NOT NULL DEFAULT '',
|
||
SQL_GROUP_COLOR NVARCHAR(MAX) NOT NULL DEFAULT '',
|
||
SQL_GROUP_TEXT NVARCHAR(MAX) NOT NULL DEFAULT '',
|
||
SQL_BTN_FINISH NVARCHAR(MAX) NOT NULL DEFAULT '',
|
||
SQL_BTN_REJECT NVARCHAR(MAX) NOT NULL DEFAULT '',
|
||
BTN_REJECT_CAPTION NVARCHAR(100) NOT NULL DEFAULT '',
|
||
REJECT_SQL_REASONS NVARCHAR(3000) NOT NULL DEFAULT '',
|
||
REJECT_ACTIONS_ATTRIBUTE VARCHAR(100) NOT NULL DEFAULT '',
|
||
REJECT_COMMENT_ATTRIBUTE VARCHAR(100) NOT NULL DEFAULT '',
|
||
BTN_NOT_RESP_CAPTION NVARCHAR(100) NOT NULL DEFAULT '',
|
||
NOT_RESP_SQL VARCHAR(3000) NOT NULL DEFAULT '',
|
||
NOT_RESP_COMMENT_ATTRIBUTE VARCHAR(150) NOT NULL DEFAULT '',
|
||
ADDED_WHO VARCHAR(30) NOT NULL DEFAULT 'Digital Data',
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT (GETDATE()),
|
||
CHANGED_WHO VARCHAR(30),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBPM_PROFILE_GUID PRIMARY KEY (GUID),
|
||
CONSTRAINT FK_TBPM_PROFILE_TYPE FOREIGN KEY (TYPE) REFERENCES TBPM_TYPE (GUID)
|
||
)
|
||
GO
|
||
--ALTER TABLE dbo.TBPM_PROFILE WITH NOCHECK
|
||
--ADD CONSTRAINT FK_TBPM_PROFILE_TYPE FOREIGN KEY (TYPE) REFERENCES TBPM_TYPE (GUID) ;
|
||
|
||
CREATE TRIGGER TBPM_PROFILE_AFT_UPD ON TBPM_PROFILE
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBPM_PROFILE SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBPM_PROFILE.GUID = INSERTED.GUID
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
CREATE TABLE TBPM_PROFILE_FILES
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
DOC_ID BIGINT NOT NULL DEFAULT 0,
|
||
PROFIL_ID INTEGER NOT NULL,
|
||
FILE_PATH VARCHAR(1000),
|
||
EDIT BIT NOT NULL DEFAULT 0,
|
||
DMS_ERSTELLT_DATE DATE,
|
||
IN_WORK BIT NOT NULL DEFAULT 0,
|
||
IN_WORK_WHEN DATETIME,
|
||
WORK_USER VARCHAR(100),
|
||
ACTIVE BIT NOT NULL DEFAULT 0,
|
||
REFRESHED BIT NOT NULL DEFAULT 1,
|
||
REFRESHED_WHEN DATETIME,
|
||
ERSTELLTWER VARCHAR(50) DEFAULT 'PM_REFRESH_MANAGER' NOT NULL,
|
||
ERSTELLTWANN DATETIME DEFAULT GETDATE() NOT NULL,
|
||
CONSTRAINT PK_TBPM_PROFILE_FILES_GUID PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBPM_PROFILE_FILES_PROFIL_ID FOREIGN KEY (PROFIL_ID) REFERENCES TBPM_PROFILE (GUID)
|
||
)
|
||
GO
|
||
CREATE TABLE TBPM_PROFILE_FILES_TEMP
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
DocID BIGINT NOT NULL DEFAULT 0,
|
||
PROFIL_ID INTEGER NOT NULL,
|
||
FILE_PATH VARCHAR(1000),
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE() NOT NULL
|
||
)
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
|
||
CREATE TABLE TBPM_SERIELL_DOC
|
||
(
|
||
GUID BIGINT IDENTITY(1,1),
|
||
PROFIL_ID INTEGER NOT NULL,
|
||
OBJ_ID BIGINT NOT NULL,
|
||
WF_FINISHED DATETIME,
|
||
ADDED_WHO VARCHAR(100) DEFAULT 'SYSTEM' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(100),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBPM_SERIELL_DOC PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBPM_SERIELL_DOC_PROFIL_ID FOREIGN KEY (PROFIL_ID) REFERENCES TBPM_PROFILE (GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBPM_SERIELL_DOC_AFT_UPD ON TBPM_SERIELL_DOC
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBPM_SERIELL_DOC SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBPM_SERIELL_DOC.GUID = INSERTED.GUID
|
||
GO
|
||
|
||
CREATE TABLE TBPM_PROFILE_SERIELL_PARTIES
|
||
(
|
||
GUID BIGINT IDENTITY(1,1),
|
||
PROFIL_ID INTEGER NOT NULL,
|
||
ENTITY_TYPE VARCHAR(50) NOT NULL,
|
||
USER_OR_GROUP_ID INTEGER NOT NULL,
|
||
CRITERIA_NEXT_STEP VARCHAR(500),
|
||
SEQUENCE TINYINT NOT NULL DEFAULT 0,
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'SYSTEM' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBPM_PROFILE_SERIELL_PARTIES PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBPM_PROFILE_SERIELL_PARTIES_PROFIL_ID FOREIGN KEY (PROFIL_ID) REFERENCES TBPM_PROFILE (GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBPM_PROFILE_SERIELL_PARTIES_AFT_UPD ON TBPM_PROFILE_SERIELL_PARTIES
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBPM_PROFILE_SERIELL_PARTIES SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBPM_PROFILE_SERIELL_PARTIES.GUID = INSERTED.GUID
|
||
GO
|
||
|
||
CREATE TABLE TBPM_SERIELL_PARTIES_STATE
|
||
(
|
||
GUID BIGINT IDENTITY(1,1),
|
||
SPID_ID BIGINT NOT NULL,
|
||
ENTITY_TYPE VARCHAR(50) NOT NULL,
|
||
USER_OR_GROUP_ID INTEGER NOT NULL,
|
||
STATE_DESC VARCHAR(500) NOT NULL,
|
||
COMMENT VARCHAR(500),
|
||
ADDED_WHO VARCHAR(50) DEFAULT 'SYSTEM' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME ,
|
||
CONSTRAINT PK_TBPM_SP_STATE PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBPM_SP_STATE_SPID_ID FOREIGN KEY (SPID_ID) REFERENCES TBPM_PROFILE_SERIELL_PARTIES (GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBPM_SERIELL_PARTIES_STATE_AFT_UPD ON TBPM_SERIELL_PARTIES_STATE
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBPM_SERIELL_PARTIES_STATE SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBPM_SERIELL_PARTIES_STATE.GUID = INSERTED.GUID
|
||
GO
|
||
CREATE TABLE TBPM_FILES_USER_NOT_INDEXED
|
||
(
|
||
[GUID] BIGINT NOT NULL IDENTITY (1, 1),
|
||
USR_NAME VARCHAR(50),
|
||
USRID INTEGER NOT NULL DEFAULT 0,
|
||
PROFIL_ID INTEGER,
|
||
DocGUID BigInt NOT NULL DEFAULT 0,
|
||
FILE_PATH VARCHAR(500),
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT GETDATE()
|
||
UNIQUE (USR_NAME,PROFIL_ID,FILE_PATH)
|
||
)
|
||
GO
|
||
CREATE NONCLUSTERED INDEX [IDXTBPM_FILES_USER_NOT_INDEXED_USRID_AW]
|
||
ON [dbo].[TBPM_FILES_USER_NOT_INDEXED] ([USRID])
|
||
INCLUDE ([ADDED_WHEN])
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
CREATE TABLE TBPM_FILES_WORK_HISTORY
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
PROFIL_ID INTEGER NOT NULL,
|
||
DOC_ID INTEGER NOT NULL DEFAULT 0,
|
||
WORKED_BY VARCHAR(100) NOT NULL,
|
||
WORKED_WHEN DATETIME NOT NULL DEFAULT GETDATE(),
|
||
WORKED_WHERE VARCHAR(100) NOT NULL,
|
||
STATUS_COMMENT VARCHAR(500),
|
||
COMMENT VARCHAR(MAX),
|
||
CONSTRAINT [PK_TBPM_FILES_WORK_HISTORY] PRIMARY KEY (GUID)
|
||
)
|
||
GO
|
||
------------------------------------------------------------------------------
|
||
--CREATE TABLE TBPM_ERROR_LOG
|
||
--(
|
||
-- GUID INT NOT NULL IDENTITY (1, 1),
|
||
-- PROFIL_ID INTEGER NOT NULL,
|
||
-- ERROR_MSG VARCHAR(1000) NOT NULL,
|
||
-- ADDED_WHO VARCHAR(50) NOT NULL,
|
||
-- ADDED_WHEN DATETIME NOT NULL DEFAULT GETDATE(),
|
||
-- MACHINE_NAME VARCHAR(50),
|
||
-- CONSTRAINT PK_TBPM_ERROR_LOG_GUID PRIMARY KEY(GUID),
|
||
-- CONSTRAINT FK_TBPM_ERROR_LOG_PROFILE FOREIGN KEY (PROFIL_ID) REFERENCES TBPM_PROFILE (GUID)
|
||
--)
|
||
--GO
|
||
CREATE TABLE TBPM_PROFILE_CONTROLS
|
||
(
|
||
GUID INTEGER NOT NULL IDENTITY (1, 1),
|
||
PROFIL_ID INTEGER NOT NULL,
|
||
NAME VARCHAR(100) NOT NULL,
|
||
CTRL_TYPE VARCHAR(10) NOT NULL, --TXT,LBL,COMBO,DTP
|
||
CTRL_TEXT VARCHAR(100) NOT NULL DEFAULT 'CTRL TEXT',
|
||
X_LOC FLOAT NOT NULL,
|
||
Y_LOC FLOAT NOT NULL,
|
||
HEIGHT SMALLINT NOT NULL DEFAULT 25,
|
||
WIDTH SMALLINT NOT NULL DEFAULT 200,
|
||
INDEX_NAME VARCHAR(100),
|
||
TYP VARCHAR(50),
|
||
[VALIDATION] BIT NOT NULL DEFAULT 0,
|
||
CHOICE_LIST VARCHAR(50),
|
||
CONNECTION_ID SMALLINT,
|
||
DEFAULT_VALUE VARCHAR(100),
|
||
MULTISELECT BIT DEFAULT 0 NOT NULL,
|
||
VKT_ADD_ITEM BIT DEFAULT 0 NOT NULL,
|
||
VKT_PREVENT_MULTIPLE_VALUES BIT DEFAULT 0 NOT NULL,
|
||
IMAGE_CONTROL VARBINARY(MAX),
|
||
BACKGROUND_COLOR VARCHAR(50),
|
||
BACKCOLOR_IF VARCHAR(500) NOT NULL DEFAULT '',
|
||
SQL_UEBERPRUEFUNG NVARCHAR(MAX) DEFAULT '',
|
||
SQL2 NVARCHAR(MAX),
|
||
SQL_ENABLE NVARCHAR(MAX),
|
||
SQL_ENABLE_ON_LOAD NVARCHAR(MAX),
|
||
SQL_ENABLE_ON_LOAD_CONID TINYINT,
|
||
SAVE_CHANGE_ON_ENABLED BIT NOT NULL DEFAULT 0,
|
||
OVERWRITE_DATA BIT NOT NULL DEFAULT 0,
|
||
SET_CONTROL_DATA NVARCHAR(MAX),
|
||
REGEX_MATCH NVARCHAR(1000),
|
||
REGEX_MESSAGE_DE VARCHAR(1000) NOT NULL DEFAULT '',
|
||
REGEX_MESSAGE_EN VARCHAR(1000) NOT NULL DEFAULT '',
|
||
[READ_ONLY] BIT NOT NULL DEFAULT 0,
|
||
LOAD_IDX_VALUE BIT NOT NULL DEFAULT 1,
|
||
CONTROL_ACTIVE BIT NOT NULL DEFAULT 1,
|
||
FORMAT_STRING VARCHAR(200) NOT NULL DEFAULT '',
|
||
|
||
FONT_STYLE smallint,
|
||
FONT_SIZE smallint,
|
||
FONT_FAMILY varchar(50),
|
||
FONT_COLOR bigint,
|
||
TABLE_ORDER_COLUMN VARCHAR(250) NOT NULL DEFAULT (''),
|
||
ADDED_WHO VARCHAR(30) NOT NULL DEFAULT 'Digital Data',
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT (GETDATE()),
|
||
CHANGED_WHO VARCHAR(30),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBPM_PROFILE_CONTROLS_GUID PRIMARY KEY (GUID),
|
||
CONSTRAINT FK_TBPM_PROFILE_CONTROLS_PROFILE FOREIGN KEY (PROFIL_ID) REFERENCES TBPM_PROFILE (GUID),
|
||
CONSTRAINT UQ_TBPM_PROFILE_CONTROLS UNIQUE(PROFIL_ID,NAME)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBPM_PROFILE_CONTROLS_AFT_UPD ON TBPM_PROFILE_CONTROLS
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
DECLARE @NAME VARCHAR(50),@WHO VARCHAR(100), @CTRL_TYPE VARCHAR(10),@CTRL_TEXT VARCHAR(100),@CTRL_CONFIG_TITLE VARCHAR(100),@OLD_CTRL_NAME VARCHAR(100)
|
||
SELECT @NAME = [NAME], @WHO = CHANGED_WHO, @CTRL_TYPE = CTRL_TYPE, @CTRL_TEXT = CTRL_TEXT FROM inserted
|
||
SELECT @OLD_CTRL_NAME = [NAME] FROM DELETED
|
||
IF (UPDATE (NAME) OR UPDATE (CTRL_TEXT))
|
||
IF @CTRL_TYPE in ('LBL','CHK','BUTTON')
|
||
BEGIN
|
||
SET @CTRL_CONFIG_TITLE = @CTRL_TYPE + '.' + @NAME
|
||
|
||
--IF NOT @OLD_CTRL_NAME <> @NAME
|
||
BEGIN
|
||
PRINT '@CTRL_CONFIG_TITLE:' + @CTRL_CONFIG_TITLE
|
||
IF NOT LEN(@WHO) > 0
|
||
SET @WHO = 'DD Automatic'
|
||
DECLARE @LANG_CODECONF VARCHAR(5)
|
||
DECLARE cursorLanguage CURSOR FOR
|
||
select LANG_CODE from TBDD_GUI_LANGUAGE
|
||
OPEN cursorLanguage
|
||
FETCH NEXT FROM cursorLanguage INTO @LANG_CODECONF
|
||
WHILE @@FETCH_STATUS = 0
|
||
BEGIN
|
||
PRINT 'Checking language: ' + @LANG_CODECONF
|
||
IF NOT EXISTS(SELECT GUID FROM TBDD_GUI_LANGUAGE_PHRASE WHERE MODULE = 'PM' AND CAPT_TYPE = 'Caption Validator Control'
|
||
AND UPPER(TITLE) = UPPER(@CTRL_CONFIG_TITLE) AND LANGUAGE = @LANG_CODECONF AND OBJ_NAME = 'frmValidator')
|
||
INSERT INTO TBDD_GUI_LANGUAGE_PHRASE (MODULE,TITLE, LANGUAGE, CAPT_TYPE,STRING1,STRING2,ADDED_WHO, OBJ_NAME)
|
||
VALUES ('PM',@CTRL_CONFIG_TITLE ,@LANG_CODECONF,'Caption Validator Control',@CTRL_TEXT,'',@WHO,'frmValidator')
|
||
ELSE
|
||
PRINT 'SEEMS 2 EXIST: ' + @CTRL_CONFIG_TITLE
|
||
FETCH NEXT FROM cursorLanguage INTO @LANG_CODECONF
|
||
END
|
||
CLOSE cursorLanguage
|
||
DEALLOCATE cursorLanguage
|
||
END
|
||
|
||
|
||
|
||
|
||
|
||
|
||
END
|
||
|
||
|
||
UPDATE TBPM_PROFILE_CONTROLS SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBPM_PROFILE_CONTROLS.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
CREATE TABLE TBPM_CONTROL_TABLE
|
||
(
|
||
GUID INTEGER NOT NULL IDENTITY (1, 1),
|
||
CONTROL_ID INTEGER NOT NULL,
|
||
SPALTENNAME VARCHAR(100) NOT NULL,
|
||
SPALTEN_HEADER VARCHAR(100) NOT NULL,
|
||
SPALTENBREITE INTEGER NOT NULL,
|
||
[VALIDATION] BIT NOT NULL DEFAULT 0,
|
||
CHOICE_LIST VARCHAR(50),
|
||
CONNECTION_ID SMALLINT,
|
||
SQL_COMMAND NVARCHAR(MAX),
|
||
REGEX_MESSAGE_DE VARCHAR(1000) NOT NULL DEFAULT '',
|
||
REGEX_MESSAGE_EN VARCHAR(1000) NOT NULL DEFAULT '',
|
||
REGEX_MATCH VARCHAR(1000) NOT NULL DEFAULT '',
|
||
[READ_ONLY] BIT NOT NULL DEFAULT 0,
|
||
LOAD_IDX_VALUE BIT NOT NULL DEFAULT 1,
|
||
LOAD_AFT_LOAD_CONTROL BIT NOT NULL DEFAULT 0,
|
||
[SEQUENCE] INTEGER NOT NULL DEFAULT 0,
|
||
FORMATTYPE VARCHAR(100) NOT NULL DEFAULT '',
|
||
FORMATSTRING VARCHAR(10) NOT NULL DEFAULT '',
|
||
DEFAULT_VALUE VARCHAR (MAX) NOT NULL DEFAULT '',
|
||
ADVANCED_LOOKUP BIT NOT NULL DEFAULT 0,
|
||
[SUMMARY_FUNCTION] VARCHAR(20) NOT NULL DEFAULT ('NONE'),
|
||
TYPE_COLUMN VARCHAR(20) NOT NULL DEFAULT ('TEXT'),
|
||
LU_CAPTION VARCHAR(150) NOT NULL DEFAULT 'NONE',
|
||
ADDED_WHO VARCHAR(30) NOT NULL DEFAULT 'Digital Data',
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT (GETDATE()),
|
||
CHANGED_WHO VARCHAR(30),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBPM_CONTROL_TABLE_GUID PRIMARY KEY (GUID),
|
||
CONSTRAINT FK_TBPM_CONTROL_TABLE_CONTROL FOREIGN KEY (CONTROL_ID) REFERENCES TBPM_PROFILE_CONTROLS (GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBPM_CONTROL_TABLE_AFT_UPD ON TBPM_CONTROL_TABLE
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBPM_CONTROL_TABLE SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBPM_CONTROL_TABLE.GUID = INSERTED.GUID
|
||
GO
|
||
----------------
|
||
CREATE TABLE TBPM_CONTOL_TABLE_LANG
|
||
(
|
||
GUID BIGINT IDENTITY(1,1),
|
||
COL_ID INTEGER NOT NULL,
|
||
CAPTION VARCHAR(250) NOT NULL,
|
||
LANG_CODE VARCHAR(5) NOT NULL,
|
||
ADDED_WHO VARCHAR(100) DEFAULT 'SYSTEM' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(100),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBPM_CONTOL_TABLE_LANG PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBPM_CONTOL_TABLE_LANG_COLID FOREIGN KEY (COL_ID) REFERENCES TBPM_CONTROL_TABLE (GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBPM_CONTOL_TABLE_LANG_AFT_UPD ON TBPM_CONTOL_TABLE_LANG
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBPM_CONTOL_TABLE_LANG SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBPM_CONTOL_TABLE_LANG.GUID = INSERTED.GUID
|
||
GO
|
||
CREATE TABLE TBPM_PROFILE_USER
|
||
(
|
||
GUID INTEGER NOT NULL IDENTITY (1, 1),
|
||
PROFIL_ID INTEGER NOT NULL,
|
||
USER_ID INTEGER NOT NULL,
|
||
ADDED_WHO VARCHAR(30) NOT NULL DEFAULT 'Digital Data',
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT (GETDATE()),
|
||
CHANGED_WHO VARCHAR(30),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBPM_PROFILE_USER_GUID PRIMARY KEY (GUID),
|
||
UNIQUE (PROFIL_ID,USER_ID),
|
||
CONSTRAINT FK_TBPM_PROFILE_USER_PROFILE FOREIGN KEY (PROFIL_ID) REFERENCES TBPM_PROFILE (GUID),
|
||
CONSTRAINT FK_TBPM_PROFILE_USER_USER FOREIGN KEY (USER_ID) REFERENCES TBDD_USER (GUID),
|
||
CONSTRAINT UQ_TBPM_PROFILE_USER UNIQUE (PROFIL_ID,USER_ID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBPM_PROFILE_USER_AFT_UPD ON TBPM_PROFILE_USER
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBPM_PROFILE_USER SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBPM_PROFILE_USER.GUID = INSERTED.GUID
|
||
GO
|
||
CREATE TABLE TBPM_PROFILE_GROUP
|
||
(
|
||
GUID INTEGER NOT NULL IDENTITY (1, 1),
|
||
PROFIL_ID INTEGER NOT NULL,
|
||
GROUP_ID INTEGER NOT NULL,
|
||
ADDED_WHO VARCHAR(30) NOT NULL DEFAULT 'Digital Data',
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT (GETDATE()),
|
||
CHANGED_WHO VARCHAR(30),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBPM_PROFILE_GROUP_GUID PRIMARY KEY (GUID),
|
||
UNIQUE (PROFIL_ID,GROUP_ID),
|
||
CONSTRAINT FK_TBPM_PROFILE_GROUP_PROFILE FOREIGN KEY (PROFIL_ID) REFERENCES TBPM_PROFILE (GUID),
|
||
CONSTRAINT FK_TBPM_PROFILE_GROUP_GROUP FOREIGN KEY (GROUP_ID) REFERENCES TBDD_GROUPS (GUID),
|
||
CONSTRAINT UQ_TBPM_PROFILE_GROUP UNIQUE (PROFIL_ID,GROUP_ID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBPM_PROFILE_GROUP_AFT_UPD ON TBPM_PROFILE_GROUP
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBPM_PROFILE_GROUP SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBPM_PROFILE_GROUP.GUID = INSERTED.GUID
|
||
GO
|
||
CREATE TABLE TBPM_PROFILE_FINAL_INDEXING
|
||
(
|
||
GUID INTEGER NOT NULL IDENTITY (1, 1),
|
||
PROFIL_ID INTEGER NOT NULL,
|
||
CONNECTION_ID SMALLINT NOT NULL DEFAULT 0,
|
||
SQL_COMMAND VARCHAR(MAX) NOT NULL DEFAULT '',
|
||
INDEXNAME VARCHAR(100) NOT NULL,
|
||
VALUE VARCHAR(100) NOT NULL,
|
||
ACTIVE BIT NOT NULL DEFAULT 1,
|
||
[DESCRIPTION] VARCHAR(MAX) NOT NULL DEFAULT '',
|
||
PREVENT_DUPLICATES BIT NOT NULL DEFAULT (0),
|
||
ALLOW_NEW_VALUES BIT NOT NULL DEFAULT (0),
|
||
IF_VEKTOR_BEHAVIOUR VARCHAR(25) NOT NULL DEFAULT '',
|
||
[SEQUENCE] TINYINT NOT NULL DEFAULT 0,
|
||
[CONTINUE_INDETERMINED] BIT NOT NULL DEFAULT 0,
|
||
ADDED_WHO VARCHAR(30) NOT NULL DEFAULT 'Digital Data',
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT (GETDATE()),
|
||
CHANGED_WHO VARCHAR(30),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBPM_PROFILE_FINAL_INDEXING_GUID PRIMARY KEY (GUID),
|
||
CONSTRAINT FK_TBPM_PROFILE_FINAL_INDEXING_PROFILE FOREIGN KEY (PROFIL_ID) REFERENCES TBPM_PROFILE (GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBPM_PROFILE_FINAL_INDEXING_AFT_UPD ON TBPM_PROFILE_FINAL_INDEXING
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBPM_PROFILE_FINAL_INDEXING SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBPM_PROFILE_FINAL_INDEXING.GUID = INSERTED.GUID
|
||
GO
|
||
CREATE TABLE TBPM_PROFILE_SEARCH
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
PROFILE_ID INTEGER NOT NULL,
|
||
TYPE VARCHAR(50) NOT NULL DEFAULT 'SQL',
|
||
CONN_ID INTEGER NOT NULL DEFAULT '0',
|
||
TAB_TITLE VARCHAR(50) NOT NULL DEFAULT 'UndefinedTitle',
|
||
LOAD_ON_START bit NOT NULL DEFAULT 1,
|
||
TAB_INDEX TINYINT DEFAULT 0 NOT NULL,
|
||
SQL_COMMAND VARCHAR(3000) NOT NULL,
|
||
RUN_MANUAL BIT DEFAULT 1 NOT NULL,
|
||
ACTIVE BIT DEFAULT 0 NOT NULL,
|
||
CREATED_WHO VARCHAR(50) DEFAULT 'DEFAULT' NOT NULL,
|
||
CREATED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CONSTRAINT PK_TBPM_PROFILE_SEARCH PRIMARY KEY(GUID),
|
||
CONSTRAINT FK_TBPM_PROFILE_SEARCH_PROFILE_ID FOREIGN KEY (PROFILE_ID) REFERENCES TBPM_PROFILE (GUID)
|
||
)
|
||
GO
|
||
CREATE TABLE TBPM_MAIN_VIEW_GROUPS
|
||
(
|
||
GUID INTEGER IDENTITY(1,1),
|
||
GROUPNAME VARCHAR(100) NOT NULL,
|
||
ACTIVE BIT DEFAULT 1 NOT NULL,
|
||
CREATED_WHO VARCHAR(50) DEFAULT 'DEFAULT' NOT NULL,
|
||
CREATED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50) DEFAULT 'DEFAULT' NOT NULL,
|
||
CHANGED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CONSTRAINT PK_TBPM_MAIN_VIEW_GROUPS PRIMARY KEY(GUID)
|
||
)
|
||
GO
|
||
CREATE TRIGGER [dbo].[TBPM_MAIN_VIEW_GROUPS_AFT_UPD] ON [dbo].[TBPM_MAIN_VIEW_GROUPS]
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBPM_MAIN_VIEW_GROUPS SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBPM_MAIN_VIEW_GROUPS.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
INSERT INTO TBPM_MAIN_VIEW_GROUPS (GROUPNAME) VALUES ('GROUP_TEXT')
|
||
GO
|
||
CREATE TABLE [dbo].[TBPM_CHART](
|
||
GUID INTEGER IDENTITY(1,1) NOT NULL,
|
||
SQL_COMMAND VARCHAR(MAX) NOT NULL,
|
||
TYPE_CHART VARCHAR(50) NOT NULL,
|
||
ARGUMENT VARCHAR(50) NOT NULL,
|
||
[VALUE] VARCHAR(50) NOT NULL,
|
||
TITLE VARCHAR(50) NOT NULL DEFAULT '',
|
||
ADDED_WHO VARCHAR(50) DEFAULT '',
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CHANGED_WHO VARCHAR(50),
|
||
CHANGED_WHEN DATETIME,
|
||
GROUP_ID VARCHAR(50) DEFAULT '',
|
||
CONSTRAINT PK_TBPM_CHART_GUID PRIMARY KEY (GUID)
|
||
|
||
)
|
||
GO
|
||
|
||
CREATE TABLE TBPM_LOG_DEBUG
|
||
(
|
||
GUID BIGINT NOT NULL IDENTITY (1, 1),
|
||
USERID INTEGER NOT NULL,
|
||
LOGMSG VARCHAR(MAX) NOT NULL,
|
||
DATE_STR VARCHAR(20) NOT NULL,
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT (GETDATE()),
|
||
CONSTRAINT PK_TBPM_LOG_DEBUG PRIMARY KEY (GUID)
|
||
)
|
||
GO
|
||
CREATE TABLE TBPM_MONITOR_KONFIG
|
||
(
|
||
GUID INTEGER NOT NULL,
|
||
GRID_TITLE VARCHAR(100) NOT NULL,
|
||
GRID_SQL VARCHAR(MAX) NOT NULL,
|
||
DEPENDING_GRID INTEGER NOT NULL DEFAULT 0,
|
||
COMMENT VARCHAR(500),
|
||
ADDED_WHO VARCHAR(30) NOT NULL DEFAULT 'Digital Data',
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT (GETDATE()),
|
||
CHANGED_WHO VARCHAR(30),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBPM_MONITOR_KONFIG PRIMARY KEY (GUID),
|
||
CONSTRAINT UQ_TBPM_MONITOR_KONFIG_TITLE UNIQUE (GRID_TITLE)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBPM_MONITOR_KONFIG_AFT_UPD ON [dbo].[TBPM_MONITOR_KONFIG]
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBPM_MONITOR_KONFIG SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBPM_MONITOR_KONFIG.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
|
||
CREATE TABLE [dbo].[TBPM_CUST_USER_DOC_JOB](
|
||
[GUID] [int] IDENTITY(1,1) NOT NULL,
|
||
[DocID] [bigint] NULL,
|
||
[UserID] [int] NULL,
|
||
[InWork] [bit] NOT NULL,
|
||
[ADDED_WHEN] [datetime] NOT NULL,
|
||
[CHANGED_WHEN] [datetime] NULL,
|
||
[ProfileID] [int] NOT NULL,
|
||
CONSTRAINT [PK_TBPM_CUST_USER_DOC_JOB] PRIMARY KEY CLUSTERED
|
||
(
|
||
[GUID] ASC
|
||
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY],
|
||
CONSTRAINT [UQ_TBPM_CUST_USER_DOC_JOB] UNIQUE NONCLUSTERED
|
||
(
|
||
[DocID] ASC,
|
||
[UserID] 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
|
||
|
||
ALTER TABLE [dbo].[TBPM_CUST_USER_DOC_JOB] ADD DEFAULT ((0)) FOR [InWork]
|
||
GO
|
||
|
||
ALTER TABLE [dbo].[TBPM_CUST_USER_DOC_JOB] ADD DEFAULT (getdate()) FOR [ADDED_WHEN]
|
||
GO
|
||
|
||
ALTER TABLE [dbo].[TBPM_CUST_USER_DOC_JOB] ADD CONSTRAINT [DF_TBPM_CUST_USER_DOC_JOB_ProfileID] DEFAULT ((0)) FOR [ProfileID]
|
||
GO
|
||
|
||
CREATE TABLE TBPM_FURTHER_KONFIG_VIEW
|
||
(
|
||
GUID INTEGER NOT NULL,
|
||
GRID_TITLE VARCHAR(100) NOT NULL,
|
||
GRID_SQL VARCHAR(MAX) NOT NULL,
|
||
DEPENDING_GRID INTEGER NOT NULL DEFAULT 0,
|
||
COMMENT VARCHAR(500),
|
||
ADDED_WHO VARCHAR(30) NOT NULL DEFAULT 'Digital Data',
|
||
ADDED_WHEN DATETIME NOT NULL DEFAULT (GETDATE()),
|
||
CHANGED_WHO VARCHAR(30),
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBPM_FURTHER_KONFIG_VIEW PRIMARY KEY (GUID),
|
||
CONSTRAINT UQ_TBPM_FURTHER_KONFIG_VIEW_TITLE UNIQUE (GRID_TITLE)
|
||
)
|
||
GO
|
||
CREATE TRIGGER TBPM_FURTHER_KONFIG_VIEW_AFT_UPD ON [dbo].[TBPM_FURTHER_KONFIG_VIEW]
|
||
FOR UPDATE
|
||
AS
|
||
BEGIN
|
||
UPDATE TBPM_FURTHER_KONFIG_VIEW SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBPM_FURTHER_KONFIG_VIEW.GUID = INSERTED.GUID
|
||
END
|
||
GO
|
||
CREATE TABLE [dbo].[TBPM_DOCWALKOVER](
|
||
[DocID] [bigint] NOT NULL,
|
||
[UserID] [int] NOT NULL,
|
||
[ADDED_WHEN] [datetime] NOT NULL
|
||
) ON [PRIMARY]
|
||
|
||
GO
|
||
ALTER TABLE [dbo].[TBPM_DOCWALKOVER] ADD CONSTRAINT [DF_TBPM_CUST_DocWalkOver_ADDED_WHEN] DEFAULT (getdate()) FOR [ADDED_WHEN]
|
||
GO
|
||
CREATE TABLE TBPM_VALIDATION_PROFILE_GROUP_USER
|
||
(
|
||
GUID BIGINT IDENTITY(1,1),
|
||
PROFIL_ID INTEGER NOT NULL,
|
||
DocID BIGINT NOT NULL,
|
||
UserID INTEGER NOT NULL,
|
||
ADDED_WHO VARCHAR(100) DEFAULT 'SYSTEM' NOT NULL,
|
||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||
CONSTRAINT PK_TBPM_VALIDATION_PROFILE_GROUP_USER PRIMARY KEY(GUID),
|
||
CONSTRAINT UQ_TBPM_VALIDATION_PROFILE_GROUP_USER UNIQUE (PROFIL_ID,DocID,UserID)
|
||
)
|
||
GO
|
||
--############################################
|
||
--##########PROCEDURES########################
|
||
--############################################
|
||
-- =============================================
|
||
-- Author: Digital Data MS
|
||
-- Create date: 11.06.2021
|
||
-- Description: Gets the next DocumentID in Workflow
|
||
-- Changed: 07.04.2022 TabPM_VALIDATION_PROFILE_GROUP_USER
|
||
-- Changed_ 21.06.2022 Files2bValidated disappeared during transport
|
||
-- =============================================
|
||
CREATE PROCEDURE [dbo].[PRPM_GET_NEXT_DOC_INFO]
|
||
(
|
||
@PROFIL_ID Integer,
|
||
@DocID BigInt,
|
||
@UserID Integer
|
||
)
|
||
AS
|
||
BEGIN
|
||
|
||
IF @DocID = 0 And EXISTS(SELECT GUID FROM TBPM_FILES_USER_NOT_INDEXED WHERE DATEDIFF(second,ADDED_WHEN,GETDATE()) < 4 AND USRID = @UserID)
|
||
BEGIN
|
||
PRINT 'NO DocID and datdiff < 5 sec'
|
||
DECLARE @FILEPATH VARCHAR(512)
|
||
SELECT @FILEPATH = FILE_PATH FROM TBPM_FILES_USER_NOT_INDEXED WHERE DATEDIFF(second,ADDED_WHEN,GETDATE()) < 4 AND USRID = @UserID;
|
||
PRINT '@FILEPATH'
|
||
select @DocID = DOC_ID From TBPM_PROFILE_FILES where FILE_PATH = @FILEPATH;
|
||
END
|
||
|
||
INSERT INTO TBPM_DOCWALKOVER (DocID,UserID) VALUES (@DocID,@UserID)
|
||
|
||
--SELECT GUID as DocGUID ,DOC_ID as DocID FROM TBPM_PROFILE_FILES WHERE GUID = (
|
||
-- SELECT MIN(T.DocGUID) FROM [dbPRPM_GET_NEXTo].[FNPM_CUST_GET_DOCID_FOR_USER_OVERVIEW] (@UserID) T where PROFILE_ID = @PROFIL_ID and T.DocID not in
|
||
-- (SELECT DISTINCT DocID FROM TBPM_DOCWALKOVER WHERE UserID = @UserID))
|
||
SELECT GUID as DocGUID ,DOC_ID as DocID ,
|
||
(SELECT COUNT(GUID) FROM TBPM_VALIDATION_PROFILE_GROUP_USER A WHERE A.DocID NOT IN (SELECT DocID FROM TBPM_DOCWALKOVER WHERE UserID = @UserID)
|
||
and UserID = @UserID) FILES2BValidated
|
||
FROM TBPM_PROFILE_FILES WHERE PROFIL_ID = @PROFIL_ID AND DOC_ID = (
|
||
SELECT MIN(DocID) FROM TBPM_VALIDATION_PROFILE_GROUP_USER WHERE UserID = @UserID AND DocID not in (SELECT DISTINCT DocID FROM TBPM_DOCWALKOVER WHERE UserID = @UserID) )
|
||
|
||
|
||
|
||
RETURN
|
||
END
|
||
GO
|
||
CREATE PROCEDURE [dbo].[PRPM_COPY_PROFILE] (@pProfileID as Integer,@pAddedWho Varchar(100))
|
||
AS
|
||
DECLARE @NEWPROFILE_ID INTEGER
|
||
INSERT INTO [dbo].[TBPM_PROFILE]
|
||
([NAME]
|
||
,[TITLE]
|
||
,[WD_OBJECTTYPE]
|
||
,[PRIORITY]
|
||
,[DESCRIPTION]
|
||
,[TYPE]
|
||
,[LOG_INDEX]
|
||
,[IN_WORK]
|
||
,[ACTIVE]
|
||
,[WD_SEARCH]
|
||
,[PM_VEKTOR_INDEX]
|
||
,[NO_OF_DOCUMENTS]
|
||
,[FINAL_PROFILE]
|
||
,[FINAL_TEXT]
|
||
,[MOVE2FOLDER]
|
||
,[SORT_BY_LATEST]
|
||
,[WORK_HISTORY_ENTRY]
|
||
,[ANNOTATE_ALL_WORK_HISTORY_ENTRIES]
|
||
,[ANNOTATE_WORK_HISTORY_ENTRY]
|
||
,[SQL_VIEW]
|
||
,[ADDED_WHO]
|
||
,[DISPLAY_MODE]
|
||
,[SQL_BTN_FINISH])
|
||
SELECT [NAME] + ' - COPY'
|
||
,[TITLE] + ' - COPY'
|
||
,[WD_OBJECTTYPE]
|
||
,[PRIORITY]
|
||
,[DESCRIPTION]
|
||
,[TYPE]
|
||
,[LOG_INDEX]
|
||
,[IN_WORK]
|
||
,0
|
||
,[WD_SEARCH]
|
||
,[PM_VEKTOR_INDEX]
|
||
,[NO_OF_DOCUMENTS]
|
||
,[FINAL_PROFILE]
|
||
,[FINAL_TEXT]
|
||
,[MOVE2FOLDER]
|
||
,[SORT_BY_LATEST]
|
||
,[WORK_HISTORY_ENTRY]
|
||
,[ANNOTATE_ALL_WORK_HISTORY_ENTRIES]
|
||
,[ANNOTATE_WORK_HISTORY_ENTRY]
|
||
,[SQL_VIEW]
|
||
,@pAddedWho
|
||
,[DISPLAY_MODE]
|
||
,[SQL_BTN_FINISH] FROM TBPM_PROFILE WHERE GUID = @pProfileID;
|
||
|
||
SELECT @NEWPROFILE_ID = MAX(GUID) FROM TBPM_PROFILE WHERE ADDED_WHO = @pAddedWho;
|
||
|
||
INSERT INTO [dbo].[TBPM_PROFILE_FINAL_INDEXING]
|
||
([PROFIL_ID]
|
||
,[CONNECTION_ID]
|
||
,[SQL_COMMAND]
|
||
,[INDEXNAME]
|
||
,[VALUE]
|
||
,[ACTIVE]
|
||
,[DESCRIPTION]
|
||
,[ADDED_WHO]
|
||
,[PREVENT_DUPLICATES]
|
||
,[ALLOW_NEW_VALUES]
|
||
,[IF_VEKTOR_BEHAVIOUR]
|
||
,[SEQUENCE])
|
||
SELECT
|
||
@NEWPROFILE_ID
|
||
,[CONNECTION_ID]
|
||
,[SQL_COMMAND]
|
||
,[INDEXNAME]
|
||
,[VALUE]
|
||
,[ACTIVE]
|
||
,[DESCRIPTION]
|
||
,[ADDED_WHO]
|
||
,[PREVENT_DUPLICATES]
|
||
,[ALLOW_NEW_VALUES]
|
||
,[IF_VEKTOR_BEHAVIOUR]
|
||
,[SEQUENCE]
|
||
FROM [TBPM_PROFILE_FINAL_INDEXING] WHERE PROFIL_ID = @pProfileID
|
||
|
||
|
||
|
||
|
||
|
||
INSERT INTO [dbo].[TBPM_PROFILE_CONTROLS]
|
||
([PROFIL_ID]
|
||
,[NAME]
|
||
,[CTRL_TYPE]
|
||
,[CTRL_TEXT]
|
||
,[X_LOC]
|
||
,[Y_LOC]
|
||
,[HEIGHT]
|
||
,[WIDTH]
|
||
,[INDEX_NAME]
|
||
,[TYP]
|
||
,[VALIDATION]
|
||
,[CHOICE_LIST]
|
||
,[CONNECTION_ID]
|
||
,[DEFAULT_VALUE]
|
||
,[SQL_UEBERPRUEFUNG]
|
||
,[READ_ONLY]
|
||
,[LOAD_IDX_VALUE]
|
||
,[FONT_STYLE]
|
||
,[FONT_SIZE]
|
||
,[FONT_FAMILY]
|
||
,[FONT_COLOR]
|
||
,[ADDED_WHO]
|
||
,[MULTISELECT]
|
||
,[VKT_ADD_ITEM]
|
||
,[VKT_PREVENT_MULTIPLE_VALUES]
|
||
,[REGEX_MATCH]
|
||
,[REGEX_MESSAGE_DE]
|
||
,[REGEX_MESSAGE_EN]
|
||
,[IMAGE_CONTROL]
|
||
,[SQL2]
|
||
,[SQL_ENABLE]
|
||
,[BACKGROUND_COLOR]
|
||
,[OVERWRITE_DATA]
|
||
,[SET_CONTROL_DATA])
|
||
SELECT @NEWPROFILE_ID
|
||
,[NAME]
|
||
,[CTRL_TYPE]
|
||
,[CTRL_TEXT]
|
||
,[X_LOC]
|
||
,[Y_LOC]
|
||
,[HEIGHT]
|
||
,[WIDTH]
|
||
,[INDEX_NAME]
|
||
,[TYP]
|
||
,[VALIDATION]
|
||
,[CHOICE_LIST]
|
||
,[CONNECTION_ID]
|
||
,[DEFAULT_VALUE]
|
||
,[SQL_UEBERPRUEFUNG]
|
||
,[READ_ONLY]
|
||
,[LOAD_IDX_VALUE]
|
||
,[FONT_STYLE]
|
||
,[FONT_SIZE]
|
||
,[FONT_FAMILY]
|
||
,[FONT_COLOR]
|
||
,@pAddedWho
|
||
,[MULTISELECT]
|
||
,[VKT_ADD_ITEM]
|
||
,[VKT_PREVENT_MULTIPLE_VALUES]
|
||
,[REGEX_MATCH]
|
||
,[REGEX_MESSAGE_DE]
|
||
,[REGEX_MESSAGE_EN]
|
||
,[IMAGE_CONTROL]
|
||
,[SQL2]
|
||
,[SQL_ENABLE]
|
||
,[BACKGROUND_COLOR]
|
||
,[OVERWRITE_DATA]
|
||
,[SET_CONTROL_DATA] FROM [TBPM_PROFILE_CONTROLS] WHERE PROFIL_ID = @pProfileID;
|
||
|
||
DECLARE
|
||
@OLD_ID INTEGER,
|
||
@NEW_ID INTEGER
|
||
|
||
DECLARE cursor1 CURSOR FOR
|
||
select T.GUID, T1.GUID from TBPM_PROFILE_CONTROLS T,TBPM_PROFILE_CONTROLS T1 WHERE
|
||
T.CTRL_TYPE = 'TABLE' and T1.CTRL_TYPE = 'TABLE' AND T.PROFIL_ID = @pProfileID AND T1.PROFIL_ID = @NEWPROFILE_ID AND T.NAME = T1.NAME
|
||
OPEN cursor1
|
||
FETCH NEXT FROM cursor1 INTO @OLD_ID,@NEW_ID
|
||
WHILE @@FETCH_STATUS = 0
|
||
BEGIN
|
||
INSERT INTO [dbo].[TBPM_CONTROL_TABLE]
|
||
([CONTROL_ID]
|
||
,[SPALTENNAME]
|
||
,[SPALTEN_HEADER]
|
||
,[SPALTENBREITE]
|
||
,[VALIDATION]
|
||
,[CHOICE_LIST]
|
||
,[CONNECTION_ID]
|
||
,[SQL_COMMAND]
|
||
,[READ_ONLY]
|
||
,[LOAD_IDX_VALUE]
|
||
,[ADDED_WHO]
|
||
,[REGEX_MESSAGE_DE]
|
||
,[REGEX_MESSAGE_EN]
|
||
,[REGEX_MATCH]
|
||
,[LOAD_AFT_LOAD_CONTROL]
|
||
,[SEQUENCE])
|
||
SELECT @NEW_ID
|
||
,[SPALTENNAME]
|
||
,[SPALTEN_HEADER]
|
||
,[SPALTENBREITE]
|
||
,[VALIDATION]
|
||
,[CHOICE_LIST]
|
||
,[CONNECTION_ID]
|
||
,[SQL_COMMAND]
|
||
,[READ_ONLY]
|
||
,[LOAD_IDX_VALUE]
|
||
,@pAddedWho
|
||
,[REGEX_MESSAGE_DE]
|
||
,[REGEX_MESSAGE_EN]
|
||
,[REGEX_MATCH]
|
||
,[LOAD_AFT_LOAD_CONTROL]
|
||
,[SEQUENCE] FROM [TBPM_CONTROL_TABLE] WHERE CONTROL_ID = @OLD_ID ORDER BY SEQUENCE
|
||
|
||
|
||
FETCH NEXT FROM cursor1 INTO @OLD_ID,@NEW_ID
|
||
END
|
||
CLOSE cursor1
|
||
DEALLOCATE cursor1
|
||
|
||
GO
|
||
CREATE PROCEDURE [dbo].[PRPM_CUST_DocHANDLE] @pDocID BIGINT
|
||
AS
|
||
BEGIN
|
||
/*INDIVIDUAL HANDLING FOR DOC IN PM GOES HERE*/
|
||
PRINT 'Starting INDIVIDUAL HANDLING FOR DOC IN PM'
|
||
END
|
||
GO
|
||
CREATE PROCEDURE [dbo].[PRPM_DELETE_USER](@pUSER_ID INT)
|
||
AS
|
||
BEGIN TRY
|
||
IF OBJECT_ID(N'dbo.TBPM_PROFILE_USER', N'U') IS NOT NULL
|
||
DELETE FROM TBPM_PROFILE_USER WHERE USER_ID = @pUSER_ID
|
||
IF OBJECT_ID(N'dbo.TBPM_PROFILE_USER', N'U') IS NOT NULL
|
||
DELETE FROM TBPM_PROFILE_USER WHERE USER_ID = @pUSER_ID
|
||
DELETE FROM TBDD_USER_MODULES WHERE USER_ID = @pUSER_ID AND MODULE_ID = (SELECT GUID FROM TBDD_MODULES WHERE SHORT_NAME = 'PM')
|
||
END TRY
|
||
BEGIN CATCH
|
||
PRINT 'FEHLER IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE()) + ' - ZEILE: ' + CONVERT(VARCHAR(10),ERROR_LINE())
|
||
+ ' - FEHLER-MESSAGE: '
|
||
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
||
END CATCH
|
||
GO
|
||
|
||
-- =============================================
|
||
-- Author: Digital Data, MS
|
||
-- Create date: 05.07.2019
|
||
-- =============================================
|
||
CREATE PROCEDURE [dbo].[PRPM_FILES_NOT_INDEXED]
|
||
-- Add the parameters for the stored procedure here
|
||
@USER_NAME VARCHAR(50),
|
||
@PROFIL_ID INTEGER,
|
||
@FILEPATH VARCHAR(500),
|
||
@DocGUID BIGINT
|
||
AS
|
||
BEGIN
|
||
DECLARE @USRID INTEGER
|
||
SELECT @USRID = GUID FROM TBDD_USER WHERE USERNAME = @USER_NAME;
|
||
SET @FILEPATH = REPLACE(@FILEPATH,'Windream\\','Windream\')
|
||
IF NOT EXISTS(SELECT * FROM TBPM_FILES_USER_NOT_INDEXED WHERE
|
||
USRID = @USRID
|
||
AND PROFIL_ID = @PROFIL_ID AND FILE_PATH = @FILEPATH)
|
||
INSERT INTO TBPM_FILES_USER_NOT_INDEXED (USR_NAME,PROFIL_ID,FILE_PATH,DocGUID,USRID) VALUES (@USER_NAME, @PROFIL_ID, @FILEPATH,@DocGUID,@USRID)
|
||
ELSE
|
||
UPDATE TBPM_FILES_USER_NOT_INDEXED SET ADDED_WHEN = GETDATE()
|
||
WHERE USRID = @USRID AND PROFIL_ID = @PROFIL_ID AND FILE_PATH = @FILEPATH
|
||
END
|
||
GO
|
||
CREATE PROCEDURE PRPM_CHECK_NEXT_WF @pGUID BIGINT
|
||
AS
|
||
BEGIN
|
||
DECLARE @DocID BIGINT
|
||
SELECT @DocID = DOC_ID FROM TBPM_PROFILE_FILES WHERE GUID = @pGUID
|
||
DELETE FROM TBPM_PROFILE_FILES WHERE GUID = @pGUID
|
||
/*TO DO HERE*/
|
||
EXEC PRPM_CUST_DocHANDLE @DocID
|
||
END
|
||
GO
|
||
CREATE PROCEDURE [dbo].[PRPM_CHANGE_CONTROL_CAPTION] (@pCTRL_ID INT,@NEW_CAPTION VARCHAR(100), @WHO VARCHAR(100),@LANG_CODE VARCHAR(5))
|
||
AS
|
||
DECLARE @RESULT VARCHAR(250), @CTRL_CONFIG_TITLE VARCHAR(100)
|
||
SELECT @CTRL_CONFIG_TITLE = CTRL_TYPE + '.' + NAME FROM TBPM_PROFILE_CONTROLS WHERE GUID = @pCTRL_ID
|
||
|
||
UPDATE TBDD_GUI_LANGUAGE_PHRASE SET STRING1 = @NEW_CAPTION, CHANGED_WHO = @WHO
|
||
WHERE OBJ_NAME = 'frmValidator' AND MODULE = 'PM' AND TITLE = @CTRL_CONFIG_TITLE AND UPPER(LANGUAGE) = UPPER(@LANG_CODE)
|
||
GO
|
||
-- =============================================
|
||
-- Author: Digital Data Gmbh
|
||
-- =============================================
|
||
CREATE PROCEDURE [dbo].[PRPM_REFRESH_FILES_SQL] as
|
||
BEGIN
|
||
DECLARE @PROFIL_ID INTEGER, @NAME VARCHAR(100),@SEARCH NVARCHAR(2000)
|
||
--#### Der Cursor f<>r alle Profile
|
||
DECLARE CursorProfile CURSOR LOCAL FOR
|
||
select GUID,NAME,WD_SEARCH FROM TBPM_PROFILE WHERE
|
||
ACTIVE = 1 and WD_SEARCH like '%select%' --AND GUID = 12
|
||
ORDER BY PRIORITY
|
||
OPEN CursorProfile
|
||
FETCH NEXT FROM CursorProfile INTO @PROFIL_ID,@NAME,@SEARCH
|
||
WHILE @@FETCH_STATUS = 0
|
||
BEGIN
|
||
PRINT '++++ REFRESH FILES WORKING ON ProfilID:' + CONVERT(VARCHAR(4),@PROFIL_ID) + ' ++++'
|
||
delete from TBPM_PROFILE_FILES_TEMP where PROFIL_ID = @PROFIL_ID;
|
||
DECLARE @SQL NVARCHAR(2000)
|
||
--Objekte zu Profil in Hilfstabelle inserten
|
||
SET @SQL = 'INSERT INTO DD_ECM.dbo.TBPM_PROFILE_FILES_TEMP (PROFIL_ID,DocId,FILE_PATH,ADDED_WHEN) ' + @SEARCH
|
||
--Print @SQL
|
||
exec(@SQL);
|
||
--Print 'INSERT INTO DD_ECM.dbo.TBPM_PROFILE_FILES_TEMP EXECUTED'
|
||
DECLARE @DocID BIGINT, @Path VARCHAR(500), @CREATED DATETIME, @COUNT_DOC INTEGER
|
||
SET @COUNT_DOC = 0
|
||
--Der Cursor f<>r NEUE Objekte
|
||
DECLARE cursorNewObjects CURSOR FOR
|
||
SELECT A.DocId,A.FILE_PATH,A.ADDED_WHEN
|
||
FROM TBPM_PROFILE_FILES_TEMP A WHERE A.PROFIL_ID = @PROFIL_ID AND(SELECT COUNT(DOC_ID)
|
||
FROM TBPM_PROFILE_FILES B WHERE B.DOC_ID = A.DocId AND B.PROFIL_ID = @PROFIL_ID) = 0;
|
||
OPEN cursorNewObjects
|
||
FETCH NEXT FROM cursorNewObjects INTO @DocID,@Path,@CREATED
|
||
WHILE @@FETCH_STATUS = 0
|
||
BEGIN
|
||
SET @COUNT_DOC += 1
|
||
--PRINT 'WORKING ON NEW OBJECT#:' + CONVERT(VARCHAR(4),@COUNT_DOC) + '#ProfilID:' + CONVERT(VARCHAR(4),@PROFIL_ID)
|
||
INSERT INTO TBPM_PROFILE_FILES (PROFIL_ID,FILE_PATH,ACTIVE,DMS_ERSTELLT_DATE,DOC_ID) VALUES
|
||
(@PROFIL_ID,@Path,1,@CREATED,@DocID)
|
||
FETCH NEXT FROM cursorNewObjects INTO @DocID,@Path,@CREATED
|
||
END
|
||
CLOSE cursorNewObjects
|
||
DEALLOCATE cursorNewObjects
|
||
|
||
DECLARE @DocIDInvalid BIGINT
|
||
--Der Cursor f<>r ung<6E>ltige Objekte
|
||
DECLARE cursorInvalidObjects CURSOR FOR
|
||
SELECT A.DOC_ID FROM TBPM_PROFILE_FILES A where A.PROFIL_ID = @PROFIL_ID
|
||
AND A.DOC_ID NOT IN (select DocId from TBPM_PROFILE_FILES_TEMP where PROFIL_ID = @PROFIL_ID)
|
||
OPEN cursorInvalidObjects
|
||
FETCH NEXT FROM cursorInvalidObjects INTO @DocIDInvalid
|
||
WHILE @@FETCH_STATUS = 0
|
||
BEGIN
|
||
SET @COUNT_DOC += 1
|
||
--PRINT 'WORKING ON INVALID OBJECT#:' + CONVERT(VARCHAR(4),@COUNT_DOC) + '#ProfilID:' + CONVERT(VARCHAR(4),@PROFIL_ID)
|
||
DELETE FROM TBPM_PROFILE_FILES WHERE DOC_ID = @DocIDInvalid and PROFIL_ID = @PROFIL_ID
|
||
FETCH NEXT FROM cursorInvalidObjects INTO @DocIDInvalid
|
||
END
|
||
CLOSE cursorInvalidObjects
|
||
DEALLOCATE cursorInvalidObjects
|
||
FETCH NEXT FROM CursorProfile INTO @PROFIL_ID,@NAME,@SEARCH
|
||
END
|
||
CLOSE CursorProfile
|
||
DEALLOCATE CursorProfile
|
||
DELETE FROM TBPM_PROFILE_FILES WHERE EDIT = 1;
|
||
--EXEC PRPM_REMOVE_NE_FILES;
|
||
UPDATE TBPM_PROFILE_FILES SET IN_WORK = 0, WORK_USER = NULL, IN_WORK_WHEN = NULL where
|
||
datediff(MINUTE,IN_WORK_WHEN,Getdate()) >= 25;
|
||
END
|
||
GO
|
||
--##############################
|
||
--##########FUNCTIONS###########
|
||
--##############################
|
||
CREATE FUNCTION [dbo].[FNPM_IDB_LAST_EDITED_DOC](@pPROFIL_ID INTEGER,@pDOC_ID INTEGER)
|
||
RETURNS DATETIME
|
||
AS
|
||
BEGIN
|
||
DECLARE @RESULT DATETIME
|
||
|
||
IF EXISTS(SELECT CHANGED_WHEN FROM IDB.dbo.TBIDB_OBJECT_METADATA_CHANGE WHERE IDB_OBJ_ID = @pDOC_ID)
|
||
SELECT @RESULT = MAX(CHANGED_WHEN) FROM IDB.dbo.TBIDB_OBJECT_METADATA_CHANGE WHERE IDB_OBJ_ID = @pDOC_ID
|
||
ELSE
|
||
SELECT @RESULT = convert(date,T.DMS_ERSTELLT_DATE) FROM TBPM_PROFILE_FILES T
|
||
WHERE T.PROFIL_ID = @pPROFIL_ID AND T.DOC_ID = @pDOC_ID
|
||
RETURN @RESULT
|
||
END
|
||
GO
|
||
CREATE FUNCTION [dbo].[FNPM_GET_FILEPATH] (@pDOCGUID BIGINT,@STANDARD As INT = 0)
|
||
RETURNS VARCHAR(MAX)
|
||
AS
|
||
BEGIN
|
||
DECLARE @RELPATH VARCHAR(100),@FILEPATH VARCHAR(500),@NAVPATH as VARCHAR(MAX)
|
||
IF @STANDARD = 1
|
||
SET @RELPATH = '\\windream\objects'
|
||
ELSE
|
||
SELECT @RELPATH = WM_REL_PATH FROM TBPM_KONFIGURATION WHERE GUID = 1
|
||
SELECT @FILEPATH = REPLACE(FILE_PATH,'W:\','') FROM TBPM_PROFILE_FILES WHERE (GUID = @pDOCGUID)
|
||
SET @NAVPATH = @RELPATH + '\' + @FILEPATH
|
||
IF @NAVPATH IS NULL
|
||
SET @NAVPATH = ''
|
||
RETURN @NAVPATH
|
||
END
|
||
GO
|
||
-- =============================================
|
||
-- Author: Digital Data MS
|
||
-- Create date: 05.07.2019
|
||
-- Description: Gets the next DocumentID
|
||
-- =============================================
|
||
CREATE FUNCTION [dbo].[FNPM_GET_NEXT_DOC_GUID]
|
||
(
|
||
-- Add the parameters for the function here
|
||
@PROFIL_ID Integer,
|
||
@OrderByNewest Bit, @DocGUID BigInt, @USERNAME VARCHAR(50)
|
||
)
|
||
RETURNS BIGINT
|
||
AS
|
||
BEGIN
|
||
DECLARE @NEXT_DOC_GUID BIGINT
|
||
IF @OrderByNewest = 0
|
||
SELECT Top 1 @NEXT_DOC_GUID = GUID FROM TBPM_PROFILE_FILES WHERE
|
||
PROFIL_ID = @PROFIL_ID AND EDIT = 0 AND IN_WORK = 0 AND
|
||
GUID <> @DocGUID AND GUID NOT IN (
|
||
SELECT DocGUID
|
||
FROM TBPM_FILES_USER_NOT_INDEXED
|
||
WHERE (PROFIL_ID = @PROFIL_ID) AND (UPPER(USR_NAME) = UPPER(@USERNAME))
|
||
)
|
||
ELSE
|
||
SELECT Top 1 @NEXT_DOC_GUID = GUID FROM TBPM_PROFILE_FILES WHERE
|
||
PROFIL_ID = @PROFIL_ID AND EDIT = 0 AND IN_WORK = 0 AND
|
||
GUID <> @DocGUID AND GUID NOT IN (
|
||
SELECT DocGUID
|
||
FROM TBPM_FILES_USER_NOT_INDEXED
|
||
WHERE (PROFIL_ID = @PROFIL_ID) AND (UPPER(USR_NAME) = UPPER(@USERNAME)))
|
||
ORDER BY DMS_ERSTELLT_DATE DESC,GUID DESC
|
||
IF @NEXT_DOC_GUID IS NULL
|
||
SET @NEXT_DOC_GUID = 0
|
||
RETURN @NEXT_DOC_GUID
|
||
END
|
||
GO
|
||
CREATE FUNCTION [dbo].[FNPM_PROFILE_GROUP_TEXT](@pPROFIL_ID AS INTEGER)
|
||
RETURNS VARCHAR(250)
|
||
AS
|
||
BEGIN
|
||
DECLARE @RESULT VARCHAR(250), @RESULT2 VARCHAR(250)
|
||
|
||
SELECT @RESULT = TITLE,@RESULT2 = NAME FROM TBPM_PROFILE WHERE GUID = @pPROFIL_ID
|
||
--SET @RESULT2 = 'Additional and configurable text for profile ' + @RESULT2
|
||
SET @RESULT = @RESULT --+ ' | ' + @RESULT2
|
||
RETURN @RESULT
|
||
END
|
||
GO
|
||
CREATE FUNCTION [dbo].[FNPM_PROFILE_GROUP_FONT_COLOR](@pPROFIL_ID AS INTEGER)
|
||
RETURNS VARCHAR(20)
|
||
AS
|
||
BEGIN
|
||
DECLARE @RESULT VARCHAR(20)
|
||
SET @RESULT = 'Black'
|
||
IF @pPROFIL_ID = 11 --Abgelehnt
|
||
SET @RESULT = 'White'
|
||
|
||
RETURN @RESULT
|
||
END
|
||
GO
|
||
|
||
--GRANT EXECUTE ON [dbo].[FNPM_PROFILE_GROUP_TEXT] TO [dd_ecm]
|
||
--GO
|
||
|
||
CREATE FUNCTION [dbo].[FNPM_LAST_WORKUSER_DOC](@pPROFIL_ID INTEGER,@pDOC_ID INTEGER)
|
||
RETURNS VARCHAR(250)
|
||
AS
|
||
BEGIN
|
||
DECLARE @RESULT VARCHAR(250)
|
||
SELECT @RESULT = WORKED_BY FROM TBPM_FILES_WORK_HISTORY WHERE GUID =
|
||
(SELECT MAX(GUID) FROM TBPM_FILES_WORK_HISTORY WHERE PROFIL_ID = @pPROFIL_ID AND DOC_ID = @pDOC_ID)
|
||
IF LEN(@RESULT) = 0
|
||
SET @RESULT = ''
|
||
RETURN @RESULT
|
||
END
|
||
GO
|
||
--GRANT EXECUTE ON [dbo].[FNPM_LAST_WORKUSER_DOC] TO [dd_ecm]
|
||
--GO
|
||
CREATE FUNCTION [dbo].[FNPM_LAST_EDITED_DOC](@pPROFIL_ID INTEGER,@pDOC_ID INTEGER)
|
||
RETURNS DATETIME
|
||
AS
|
||
BEGIN
|
||
DECLARE @RESULT DATETIME
|
||
IF EXISTS(SELECT GUID FROM TBPM_FILES_WORK_HISTORY WHERE PROFIL_ID = @pPROFIL_ID AND DOC_ID = @pDOC_ID)
|
||
SELECT @RESULT = WORKED_WHEN FROM TBPM_FILES_WORK_HISTORY WHERE GUID =
|
||
(SELECT MAX(GUID) FROM TBPM_FILES_WORK_HISTORY WHERE PROFIL_ID = @pPROFIL_ID AND DOC_ID = @pDOC_ID)
|
||
ELSE
|
||
SELECT @RESULT = convert(date,T.DMS_ERSTELLT_DATE) FROM TBPM_PROFILE_FILES T
|
||
WHERE T.PROFIL_ID = @pPROFIL_ID AND T.DOC_ID = @pDOC_ID
|
||
RETURN @RESULT
|
||
END
|
||
GO
|
||
|
||
--GRANT EXECUTE ON [dbo].[FNPM_LAST_EDITED_DOC] TO [dd_ecm]
|
||
--GO
|
||
CREATE FUNCTION [dbo].[FNPM_PROFILE_GROUP_COLOR](@pPROFIL_ID AS INTEGER)
|
||
RETURNS VARCHAR(20)
|
||
AS
|
||
BEGIN
|
||
DECLARE @RESULT VARCHAR(20)
|
||
SET @RESULT = 'Grey'
|
||
IF @pPROFIL_ID = 1
|
||
SET @RESULT = 'Red'
|
||
ELSE
|
||
SET @RESULT = 'Yellow'
|
||
RETURN @RESULT
|
||
END
|
||
GO
|
||
--GRANT EXECUTE ON [dbo].[FNPM_PROFILE_GROUP_COLOR] TO [dd_ecm]
|
||
--GO
|
||
--GRANT EXECUTE ON [dbo].[FNPM_PROFILE_GROUP_TEXT] TO [dd_ecm]
|
||
--GO
|
||
CREATE FUNCTION [dbo].[FNPM_GET_FREE_USER_FOR_PROFILE] (@pPROFILE_ID INTEGER)
|
||
RETURNS
|
||
@Table TABLE
|
||
(SequentialOrder INT IDENTITY(1, 1),
|
||
USER_ID INTEGER,
|
||
USER_NAME VARCHAR(50),
|
||
USER_PRENAME VARCHAR(50),
|
||
USER_SURNAME VARCHAR(50),
|
||
USER_SHORTNAME VARCHAR(50),
|
||
USER_EMAIL VARCHAR(100),
|
||
USER_LANGUAGE VARCHAR(10),
|
||
USER_COMMENT VARCHAR(500))
|
||
AS
|
||
BEGIN
|
||
/* This function returns all free users per profile */
|
||
INSERT INTO @Table (USER_ID,USER_NAME, USER_PRENAME, USER_SURNAME,USER_SHORTNAME,USER_EMAIL,USER_LANGUAGE,USER_COMMENT)
|
||
SELECT
|
||
T.USER_ID
|
||
,T.USER_NAME
|
||
,T.USER_PRENAME
|
||
,T.USER_SURNAME
|
||
,T.USER_SHORTNAME
|
||
,T.USER_EMAIL
|
||
,T.USER_LANGUAGE
|
||
,T.USER_COMMENT
|
||
FROM
|
||
[dbo].FNDD_GET_USER_FOR_MODULE ('PM',1) T WHERE T.USER_ID NOT IN (SELECT USER_ID FROM TBPM_PROFILE_USER WHERE PROFIL_ID = @pPROFILE_ID)
|
||
RETURN
|
||
END
|
||
GO
|
||
CREATE FUNCTION [dbo].[FNPM_GET_ACTIVE_PROFILES_USER] (@USER_ID INTEGER)
|
||
RETURNS
|
||
@Table TABLE
|
||
(SCOPE VARCHAR(50),PROFILE_ID INTEGER, P_NAME VARCHAR(50),SequentialOrder INT IDENTITY(1, 1))
|
||
AS
|
||
BEGIN
|
||
DECLARE
|
||
@P_ID INTEGER,
|
||
@P_NAME VARCHAR(50)
|
||
|
||
DECLARE cursProfileUser CURSOR FOR
|
||
select T.PROFIL_ID, T1.NAME FROM TBPM_PROFILE_USER T, TBPM_PROFILE T1 WHERE T.PROFIL_ID = T1.GUID AND T.USER_ID = @USER_ID
|
||
OPEN cursProfileUser
|
||
FETCH NEXT FROM cursProfileUser INTO @P_ID,@P_NAME
|
||
WHILE @@FETCH_STATUS = 0
|
||
BEGIN
|
||
INSERT INTO @Table (SCOPE,PROFILE_ID,P_NAME) VALUES ('PROFILE-USER',@P_ID,@P_NAME)
|
||
FETCH NEXT FROM cursProfileUser INTO @P_ID,@P_NAME
|
||
END
|
||
CLOSE cursProfileUser
|
||
DEALLOCATE cursProfileUser
|
||
|
||
DECLARE cursProfileGROUP CURSOR FOR
|
||
SELECT T.PROFIL_ID, TP.NAME FROM TBPM_PROFILE_GROUP T,TBDD_GROUPS T1,TBPM_PROFILE TP,TBDD_GROUPS_USER T2 WHERE
|
||
T.GROUP_ID = T1.GUID AND T.PROFIL_ID = TP.GUID AND TP.TYPE = 1 AND T1.GUID = T2.GROUP_ID AND T2.USER_ID = @USER_ID
|
||
|
||
OPEN cursProfileGROUP
|
||
FETCH NEXT FROM cursProfileGROUP INTO @P_ID,@P_NAME
|
||
WHILE @@FETCH_STATUS = 0
|
||
BEGIN
|
||
IF NOT EXISTS(SELECT * FROM @Table WHERE PROFILE_ID = @P_ID)
|
||
INSERT INTO @Table (SCOPE,PROFILE_ID,P_NAME) VALUES ('PROFILE-GROUP',@P_ID,@P_NAME)
|
||
FETCH NEXT FROM cursProfileGROUP INTO @P_ID,@P_NAME
|
||
END
|
||
CLOSE cursProfileGROUP
|
||
DEALLOCATE cursProfileGROUP
|
||
|
||
DECLARE cursSQLProfile CURSOR FOR
|
||
SELECT T.PROFIL_ID, TP.NAME FROM TBPM_PROFILE_GROUP T,TBDD_GROUPS T1,TBPM_PROFILE TP WHERE
|
||
T.GROUP_ID = T1.GUID AND T.PROFIL_ID = TP.GUID AND TP.TYPE = 1 AND T1.NAME = 'PM_SQL_BASED' and NO_OF_DOCUMENTS > 0
|
||
|
||
OPEN cursSQLProfile
|
||
FETCH NEXT FROM cursSQLProfile INTO @P_ID,@P_NAME
|
||
WHILE @@FETCH_STATUS = 0
|
||
BEGIN
|
||
IF NOT EXISTS(SELECT * FROM @Table WHERE PROFILE_ID = @P_ID)
|
||
INSERT INTO @Table (SCOPE,PROFILE_ID,P_NAME) VALUES ('PROFILE-SQL',@P_ID,@P_NAME)
|
||
FETCH NEXT FROM cursSQLProfile INTO @P_ID,@P_NAME
|
||
END
|
||
CLOSE cursSQLProfile
|
||
DEALLOCATE cursSQLProfile
|
||
INSERT INTO @Table (SCOPE,PROFILE_ID,P_NAME)
|
||
select DISTINCT 'TBPM_CUST_USER_DOC_JOB',T.ProfileID,T1.NAME
|
||
from TBPM_CUST_USER_DOC_JOB T INNER JOIN TBPM_PROFILE T1 ON T.ProfileID = T1.GUID
|
||
INNER JOIN TBPM_PROFILE_FILES T2 ON T.ProfileID = T2.PROFIL_ID
|
||
where T.UserID = @USER_ID and T2.EDIT = 0 AND T2.ACTIVE = 1 AND T2.IN_WORK = 0 --@USER_ID
|
||
RETURN
|
||
END
|
||
GO
|
||
CREATE FUNCTION [dbo].[FNPM_BTN_OVERRIDE] (@ParamString as VARCHAR(3000))
|
||
RETURNS
|
||
@Table TABLE
|
||
(ActionType Varchar(100),Question VARCHAR(500),Title VARCHAR(100), CaptionButton Varchar(100),Color Varchar(10),OverrideAll Bit)
|
||
AS
|
||
BEGIN
|
||
--INSERT INTO @Table (ActionType, Question,Title,CaptionButton,Color) VALUES ('Override_Direct','')
|
||
INSERT INTO @Table (ActionType, Question,Title,CaptionButton,Color,OverrideAll) VALUES ('Override_Question','Wollen Sie den Beleg wirklich an den Posteingang zur<75>ckgeben?','Best<EFBFBD>tigen:','R<EFBFBD>ckgabe','Red',1)
|
||
RETURN
|
||
END
|
||
GO
|
||
-- =============================================
|
||
-- Author: Digital Data MS
|
||
-- Create date: 27.11.2019
|
||
-- Description: Gets the next DocumentID
|
||
-- =============================================
|
||
CREATE FUNCTION [dbo].[FNPM_GET_NEXT_DOC_INFO]
|
||
(
|
||
-- Add the parameters for the function here
|
||
@PROFIL_ID Integer,
|
||
@OrderByNewest Bit, @DocGUID BigInt, @USERNAME VARCHAR(50)
|
||
)
|
||
RETURNS @Output TABLE (DocGUID BIGINT,DocID BIGINT)
|
||
|
||
AS
|
||
BEGIN
|
||
IF @OrderByNewest = 0
|
||
INSERT INTO @Output (DocGUID,DocID)
|
||
SELECT Top 1 GUID, DOC_ID FROM TBPM_PROFILE_FILES WHERE
|
||
PROFIL_ID = @PROFIL_ID AND EDIT = 0 AND IN_WORK = 0 AND
|
||
GUID <> @DocGUID AND GUID NOT IN (
|
||
SELECT DocGUID
|
||
FROM TBPM_FILES_USER_NOT_INDEXED
|
||
WHERE (PROFIL_ID = @PROFIL_ID) AND (UPPER(USR_NAME) = UPPER(@USERNAME))
|
||
)
|
||
ELSE
|
||
INSERT INTO @Output (DocGUID,DocID)
|
||
SELECT Top 1 GUID, DOC_ID FROM TBPM_PROFILE_FILES WHERE
|
||
PROFIL_ID = @PROFIL_ID AND EDIT = 0 AND IN_WORK = 0 AND
|
||
GUID <> @DocGUID AND GUID NOT IN (
|
||
SELECT DocGUID
|
||
FROM TBPM_FILES_USER_NOT_INDEXED
|
||
WHERE (PROFIL_ID = @PROFIL_ID) AND (UPPER(USR_NAME) = UPPER(@USERNAME)))
|
||
ORDER BY DMS_ERSTELLT_DATE DESC,GUID DESC
|
||
|
||
RETURN
|
||
END
|
||
GO
|
||
CREATE FUNCTION [dbo].[FNPM_LANGUAGE_CONTROL_TEXT](@pCTRL_NAME VARCHAR(100),@pLANG_CODE VARCHAR(5), @pCTRL_TYPE VARCHAR(10),@pRETURN VARCHAR(500) = '')
|
||
RETURNS VARCHAR(500)
|
||
AS
|
||
BEGIN
|
||
DECLARE @RESULT VARCHAR(250), @CTRL_CONFIG_TITLE VARCHAR(100)
|
||
IF @pCTRL_TYPE not in ('LBL','CHK','BUTTON')
|
||
SET @RESULT = ''
|
||
ELSE
|
||
BEGIN
|
||
SET @CTRL_CONFIG_TITLE = @pCTRL_TYPE + '.' + @pCTRL_NAME
|
||
SELECT @RESULT = STRING1 FROM TBDD_GUI_LANGUAGE_PHRASE
|
||
WHERE MODULE = 'PM' AND CAPT_TYPE = 'Caption Validator Control' AND UPPER(TITLE) = UPPER(@CTRL_CONFIG_TITLE)
|
||
AND UPPER(LANGUAGE) = UPPER(@pLANG_CODE) AND OBJ_NAME = 'frmValidator'
|
||
IF LEN(@RESULT) > 0
|
||
SET @RESULT = @RESULT
|
||
ELSE
|
||
SET @RESULT = @pRETURN + ' (NLConf)' --'NO LANGUAGE CONFIGURATION SO FAR - CONTROL-NAME [' + @CTRL_CONFIG_TITLE + '] - LANG-CODE [' + @pLANG_CODE + ']'
|
||
--IF @pRETURN = ''
|
||
-- SET @RESULT = 'NO LANGUAGE CONFIGURATION SO FAR - CONTROL-NAME [' + @pCTRL_NAME + '] - LANG-CODE [' + @pLANG_CODE + ']'
|
||
--ELSE
|
||
-- SET @RESULT = @pRETURN
|
||
END
|
||
RETURN @RESULT
|
||
END
|
||
GO
|
||
--####################################
|
||
--##############VIEWS#################
|
||
--####################################
|
||
CREATE VIEW [dbo].[VWPM_CONTROL_INDEX] AS
|
||
SELECT TOP 100 PERCENT
|
||
T1.GUID,
|
||
T.GUID PROFIL_ID,
|
||
T.NAME PROFIL_NAME,
|
||
T.LOG_INDEX,
|
||
T1.NAME CTRL_NAME,
|
||
T1.CTRL_TYPE,
|
||
T1.CTRL_TEXT,
|
||
T1.X_LOC,
|
||
T1.Y_LOC,
|
||
T1.FONT_COLOR,
|
||
T1.FONT_FAMILY,
|
||
T1.FONT_SIZE,
|
||
T1.FONT_STYLE,
|
||
T1.WIDTH,
|
||
T1.HEIGHT,
|
||
COALESCE(T1.INDEX_NAME,'') INDEX_NAME,
|
||
COALESCE((SELECT TYP_ID FROM IDB.dbo.TBIDB_ATTRIBUTE WHERE TITLE = COALESCE(T1.INDEX_NAME,'')),'0') AS IDB_TYP,
|
||
T1.VALIDATION,
|
||
T1.CHOICE_LIST,
|
||
T1.TYP,
|
||
T1.CONNECTION_ID,
|
||
CASE WHEN T1.[SQL_UEBERPRUEFUNG] IS NULL THEN '' ELSE T1.[SQL_UEBERPRUEFUNG] END AS [SQL_UEBERPRUEFUNG],
|
||
T1.[READ_ONLY],
|
||
T1.LOAD_IDX_VALUE,
|
||
T1.DEFAULT_VALUE,
|
||
T1.REGEX_MATCH,
|
||
T1.REGEX_MESSAGE_DE,
|
||
T1.REGEX_MESSAGE_EN,
|
||
T1.OVERWRITE_DATA,
|
||
T1.SET_CONTROL_DATA,
|
||
T1.SAVE_CHANGE_ON_ENABLED,
|
||
T1.FORMAT_STRING CTRL_FORMAT_STRING,
|
||
T1.BACKCOLOR_IF CTRL_BACKCOLOR_IF
|
||
FROM
|
||
TBPM_PROFILE T,
|
||
TBPM_PROFILE_CONTROLS T1
|
||
WHERE
|
||
T.GUID = T1.PROFIL_ID
|
||
AND T1.CONTROL_ACTIVE = 1
|
||
ORDER BY
|
||
T.GUID,
|
||
T1.X_LOC,
|
||
T1.Y_LOC
|
||
GO
|
||
CREATE VIEW [dbo].[VWPM_PROFILE_USER_UNION] AS
|
||
SELECT
|
||
'USER' SCOPE,
|
||
T.GUID PROFIL_ID,
|
||
T.NAME PROFIL_NAME,
|
||
T.TITLE,
|
||
T.DESCRIPTION,
|
||
T.WD_OBJECTTYPE,
|
||
T.PRIORITY,
|
||
T.WD_SEARCH,
|
||
COALESCE(T.MOVE2FOLDER,'') as MOVE2Folder,
|
||
T.ACTIVE,
|
||
T.IN_WORK,
|
||
T.NO_OF_DOCUMENTS,
|
||
T.FINAL_PROFILE,
|
||
T.FINAL_TEXT,
|
||
T.LOG_INDEX,
|
||
T.PM_VEKTOR_INDEX,
|
||
T.DISPLAY_MODE,
|
||
T2.GUID AS USER_ID,
|
||
T2.PRENAME,
|
||
T2.NAME,
|
||
T2.USERNAME,
|
||
T2.EMAIL,
|
||
--T2.PM_RIGHT_FILE_DELETE as RIGHT_FILE_DELETE,
|
||
[dbo].[FNPM_PROFILE_GROUP_COLOR] (T.GUID) AS 'PROFILE_GROUP_COLOR',
|
||
[dbo].[FNPM_PROFILE_GROUP_TEXT] (T.GUID) AS 'PROFILE_GROUP_TEXT'
|
||
FROM
|
||
TBPM_PROFILE T,
|
||
TBPM_PROFILE_USER T1,
|
||
TBDD_USER T2
|
||
WHERE
|
||
T.TYPE = 1 AND
|
||
T.GUID = T1.PROFIL_ID AND
|
||
T1.USER_ID = T2.GUID
|
||
UNION
|
||
SELECT
|
||
'GROUP' SCOPE,
|
||
T.GUID PROFIL_ID,
|
||
T.NAME PROFIL_NAME,
|
||
T.TITLE,
|
||
T.DESCRIPTION,
|
||
T.WD_OBJECTTYPE,
|
||
T.PRIORITY,
|
||
T.WD_SEARCH,
|
||
COALESCE(T.MOVE2FOLDER,'') as MOVE2Folder,
|
||
T.ACTIVE,
|
||
T.IN_WORK,
|
||
T.NO_OF_DOCUMENTS,
|
||
T.FINAL_PROFILE,
|
||
T.FINAL_TEXT,
|
||
T.LOG_INDEX,
|
||
T.PM_VEKTOR_INDEX,
|
||
T.DISPLAY_MODE,
|
||
T4.GUID AS USER_ID,
|
||
T4.PRENAME,
|
||
T4.NAME,
|
||
T4.USERNAME,
|
||
T4.EMAIL,
|
||
--T4.PM_RIGHT_FILE_DELETE as RIGHT_FILE_DELETE,
|
||
[dbo].[FNPM_PROFILE_GROUP_COLOR] (T.GUID) AS 'PROFILE_GROUP_COLOR',
|
||
[dbo].[FNPM_PROFILE_GROUP_TEXT] (T.GUID) AS 'PROFILE_GROUP_TEXT'
|
||
FROM
|
||
TBPM_PROFILE T,
|
||
TBPM_PROFILE_GROUP T1,
|
||
TBDD_GROUPS T2,
|
||
TBDD_GROUPS_USER T3,
|
||
TBDD_USER T4
|
||
WHERE
|
||
T.TYPE = 1 AND
|
||
T.GUID = T1.PROFIL_ID AND
|
||
T1.GROUP_ID = T2.GUID AND
|
||
T2.GUID = T3.GROUP_ID AND
|
||
T3.USER_ID = T4.GUID
|
||
GO
|
||
|
||
CREATE VIEW VWPM_PROFILE_USER AS
|
||
SELECT DISTINCT * FROM VWPM_PROFILE_USER_UNION
|
||
GO
|
||
CREATE VIEW [dbo].[VWPM_EMAIL_PROFIL] AS
|
||
SELECT
|
||
T.PROFIL_ID,
|
||
T2.TITLE AS PROFIL_TITLE,
|
||
T2.NAME AS PROFIL_NAME,
|
||
T.USER_ID,
|
||
T1.USERNAME,
|
||
T1.EMAIL,
|
||
'' AS LAST_HOUR,
|
||
'' as EMAIL_ONCE_DAY,
|
||
(SELECT COUNT(GUID) FROM TBPM_PROFILE_FILES WHERE PROFIL_ID = T.PROFIL_ID) AS ANZ_FILES
|
||
FROM
|
||
TBPM_PROFILE_USER T,
|
||
TBDD_USER T1,
|
||
TBPM_PROFILE T2
|
||
WHERE
|
||
T.USER_ID = T1.GUID AND
|
||
T.PROFIL_ID = T2.GUID AND
|
||
T1.EMAIL IS NOT NULL
|
||
|
||
GO
|
||
CREATE VIEW VWPM_PROFILE_ACTIVE AS
|
||
SELECT
|
||
T1.[GUID]
|
||
,T1.[NAME]
|
||
,T1.[TITLE]
|
||
,T1.[WD_OBJECTTYPE]
|
||
,T1.[PRIORITY]
|
||
,T1.[DESCRIPTION]
|
||
,T1.[TYPE]
|
||
,T1.[LOG_INDEX]
|
||
,T1.[IN_WORK]
|
||
,T1.[ACTIVE]
|
||
,T1.[WD_SEARCH]
|
||
,T1.[PM_VEKTOR_INDEX]
|
||
,T1.[NO_OF_DOCUMENTS]
|
||
,T1.[FINAL_PROFILE]
|
||
,T1.[FINAL_TEXT]
|
||
,T1.[MOVE2FOLDER]
|
||
,T1.[SORT_BY_LATEST]
|
||
,T1.[WORK_HISTORY_ENTRY]
|
||
,T1.[ANNOTATE_ALL_WORK_HISTORY_ENTRIES]
|
||
,T1.[ANNOTATE_WORK_HISTORY_ENTRY]
|
||
,T1.[SQL_VIEW]
|
||
,T1.[ADDED_WHO]
|
||
,T1.[ADDED_WHEN]
|
||
,T1.[CHANGED_WHO]
|
||
,T1.[CHANGED_WHEN]
|
||
-- ,T1.[SQL_GROUP_COLOR]
|
||
-- ,T1.[SQL_GROUP_TEXT]
|
||
,T1.[DISPLAY_MODE]
|
||
,T1.SHOW_DOCUMENT
|
||
|
||
|
||
,(SELECT COUNT(GUID) FROM TBPM_PROFILE_FILES WHERE PROFIL_ID = T1.GUID) AS FILE_COUNT,
|
||
[dbo].[FNPM_PROFILE_GROUP_COLOR] (T1.GUID) AS 'GROUP_COLOR',
|
||
dbo.FNPM_PROFILE_GROUP_FONT_COLOR (T1.GUID) AS 'GROUP_FONT_COLOR',
|
||
[dbo].[FNPM_PROFILE_GROUP_TEXT] (T1.GUID) AS 'GROUP_TEXT'
|
||
FROM
|
||
TBPM_PROFILE T1
|
||
WHERE
|
||
T1.ACTIVE = 1
|
||
GO
|
||
|
||
|
||
CREATE view [dbo].[VWPM_CHART_TOP5] as
|
||
SELECT 'Kreditor1' as KRED_NAME
|
||
,'56' as ANZ_BELEG
|
||
,convert(decimal(19,2),125565478.8) as Netto
|
||
,convert(decimal(19,2),10000) as Skonto
|
||
UNION
|
||
SELECT 'Kreditor2' as KRED_NAME
|
||
,'49' as ANZ_BELEG
|
||
,convert(decimal(19,2),8575222.48) as Netto
|
||
,convert(decimal(19,2),8555.4) as Skonto
|
||
UNION
|
||
SELECT 'Kreditor3' as KRED_NAME
|
||
,'43' as ANZ_BELEG
|
||
,convert(decimal(19,2),2582222.8) as Netto
|
||
,convert(decimal(19,2),5647.2) as Skonto
|
||
UNION
|
||
SELECT 'Kreditor4' as KRED_NAME
|
||
,'3' as ANZ_BELEG
|
||
,convert(decimal(19,2),68589.89) as Netto
|
||
,convert(decimal(19,2),48.96) as Skonto
|
||
GO
|
||
|
||
CREATE VIEW [dbo].[VWPM_CHART_INVOICE_MONITOR_SERIES]
|
||
AS
|
||
select 'Alle Rechnungen' as Title
|
||
,15 Anzahl
|
||
,500000 NettoSumme
|
||
,1 SEQ
|
||
--,convert(varchar,format(SUM(500000),'###,###,###.00','de-de')) NettoSumme
|
||
UNION
|
||
SELECT 'Posteingang' as Title
|
||
,10 Anzahl
|
||
,12000 NettoSumme
|
||
,2 SEQ
|
||
--,convert(varchar,format(SUM(12000),'###,###,###.00','de-de')) NettoSumme
|
||
UNION
|
||
SELECT 'Fachliche Freigabe' as Title
|
||
,5 Anzahl
|
||
,13658.5 NettoSumme
|
||
,3 SEQ
|
||
--,convert(varchar,format(13658.5,'###,###,###.00','de-de')) NettoSumme
|
||
UNION
|
||
SELECT 'Finale Freigabe' as Title
|
||
,53 Anzahl
|
||
,658555.65 NettoSumme
|
||
,4 SEQ
|
||
--,convert(varchar,format(658555.65,'###,###,###.00','de-de')) NettoSumme
|
||
UNION
|
||
SELECT 'Zeitkritisch' as Title
|
||
,0 Anzahl
|
||
,'0.000' NettoSumme
|
||
,5 SEQ
|
||
--ORDER BY SEQ
|
||
|
||
GO
|
||
|
||
CREATE OR ALTER FUNCTION [dbo].[FNDD_CHECK_USER_MODULE] (@pUSERNAME VARCHAR(100), @pMODULE_SHORT_NAME VARCHAR(10),@pCLIENTID INTEGER)
|
||
RETURNS @Table TABLE
|
||
(SequentialOrder INT IDENTITY(1, 1),
|
||
USER_ID INTEGER,
|
||
USER_PRENAME VARCHAR(50),
|
||
USER_SURNAME VARCHAR(50),
|
||
USER_SHORTNAME VARCHAR(50),
|
||
USER_EMAIL VARCHAR(100),
|
||
USER_LANGUAGE VARCHAR(10),
|
||
USER_DATE_FORMAT VARCHAR(10),
|
||
USER_RIGHT_FILE_DEL BIT,
|
||
MODULE_ACCESS BIT,
|
||
IS_ADMIN BIT,
|
||
USERCOUNT_LOGGED_IN INTEGER,
|
||
COMMENT VARCHAR(500),
|
||
USER_RIGHT2 BIT NOT NULL DEFAULT 1,
|
||
USER_RIGHT3 BIT NOT NULL DEFAULT 0,
|
||
USER_RIGHT4 BIT NOT NULL DEFAULT 0,
|
||
USER_RIGHT5 BIT NOT NULL DEFAULT 0,
|
||
WORKING_MODE VARCHAR(5000) NOT NULL DEFAULT ''
|
||
,ADDITIONAL_TITLE VARCHAR(200))
|
||
AS
|
||
BEGIN
|
||
/*
|
||
This function checks all user-relevant relations an
|
||
*/
|
||
DECLARE
|
||
@RESULT VARCHAR(500),
|
||
@USER_ID INTEGER,
|
||
@USER_PRENAME VARCHAR(50),
|
||
@USER_SURNAME VARCHAR(50),
|
||
@USER_SHORTNAME VARCHAR(50),
|
||
@USER_EMAIL VARCHAR(50),
|
||
@USER_LANGUAGE VARCHAR(10),
|
||
@USER_DATE_FORMAT VARCHAR(10),
|
||
@IS_IN_MODULE BIT,
|
||
@IS_ADMIN BIT,
|
||
@USER_RIGHT_FILE_DEL BIT,
|
||
@USER_RIGHT2 BIT,
|
||
@USER_RIGHT3 BIT,
|
||
@USER_RIGHT4 BIT,
|
||
@USER_RIGHT5 BIT,
|
||
@USERCOUNT_LOGGED_IN INTEGER,
|
||
@MODULE_NAME VARCHAR(100),
|
||
@MODULE_GUID INTEGER,
|
||
@USER_GROUPNAME VARCHAR(100),
|
||
@ADMIN_GROUPNAME VARCHAR(100),
|
||
@WORKING_MODE VARCHAR(1000)
|
||
--'PM#NO_MASS_VALIDATOR;PM#FORCE_LAYOUT_OVERVIEW;PM#NO_CHARTS;PM#DEBUG_LOG'
|
||
|
||
SET @USER_RIGHT2 = 1 --1 = DocumentPropertyView only View
|
||
SET @USER_RIGHT3 = 0
|
||
SET @USER_RIGHT4 = 0
|
||
SET @USER_RIGHT5 = 0
|
||
DECLARE @CONN_ID_IDB INTEGER
|
||
SELECT @CONN_ID_IDB = GUID FROM TBDD_CONNECTION WHERE SYS_CONNECTION = 1 AND BEZEICHNUNG = 'IDB'
|
||
SET @WORKING_MODE = ''
|
||
IF @pMODULE_SHORT_NAME = 'PM'
|
||
SET @WORKING_MODE = 'PM.NO_MASS_VALIDATOR#PM.FORCE_LAYOUT_OVERVIEW#PM.NO_CHARTS#PM.DEBUG_LOG'--#PM.IDBWITHWMFS#PM.IDB_CONID!' + CONVERT(VARCHAR(2),@CONN_ID_IDB)
|
||
+'#PM.MONITORING#PM.COLORSCHEME=Purple'
|
||
|
||
SET @USER_ID = 0
|
||
SET @IS_ADMIN = 0
|
||
SET @IS_IN_MODULE = 0
|
||
SET @USERCOUNT_LOGGED_IN = 0
|
||
SET @RESULT = ''
|
||
IF @pMODULE_SHORT_NAME = 'PM'
|
||
BEGIN
|
||
SET @USER_GROUPNAME = 'PM_USER'
|
||
SET @ADMIN_GROUPNAME = 'PM_ADMINS'
|
||
END
|
||
ELSE IF @pMODULE_SHORT_NAME = 'CW'
|
||
BEGIN
|
||
SET @USER_GROUPNAME = 'CW_USER'
|
||
SET @ADMIN_GROUPNAME = 'CW_ADMINS'
|
||
END
|
||
ELSE IF @pMODULE_SHORT_NAME = 'ADDI'
|
||
BEGIN
|
||
SET @USER_GROUPNAME = 'ADDI_USER'
|
||
SET @ADMIN_GROUPNAME = 'ADDI_ADMINS'
|
||
END
|
||
ELSE IF @pMODULE_SHORT_NAME = 'GLOBIX'
|
||
BEGIN
|
||
SET @USER_GROUPNAME = 'GLOBIX_USER'
|
||
SET @ADMIN_GROUPNAME = 'GLOBIX_ADMINS'
|
||
END
|
||
ELSE IF @pMODULE_SHORT_NAME = 'UM'
|
||
BEGIN
|
||
SET @USER_GROUPNAME = 'XXXX'
|
||
SET @ADMIN_GROUPNAME = 'UM_ADMINS'
|
||
END
|
||
|
||
SELECT @MODULE_GUID = GUID, @MODULE_NAME = NAME FROM TBDD_MODULES WHERE SHORT_NAME = @pMODULE_SHORT_NAME
|
||
|
||
IF NOT EXISTS(SELECT GUID FROM TBDD_USER WHERE UPPER(USERNAME) = UPPER(@pUSERNAME))
|
||
BEGIN
|
||
SET @RESULT = 'USER NOT CONFIGURED OR LISTED'
|
||
END
|
||
ELSE
|
||
BEGIN
|
||
SELECT @USER_ID = GUID,@USER_PRENAME = PRENAME,
|
||
@USER_SURNAME = NAME, @USER_SHORTNAME = SHORTNAME,@USER_EMAIL = EMAIL,@USER_LANGUAGE = LANGUAGE,@USER_DATE_FORMAT = DATE_FORMAT FROM TBDD_USER WHERE UPPER(USERNAME) = UPPER(@pUSERNAME)
|
||
|
||
--##### LICENSE COUNT
|
||
--SELECT @USERCOUNT_LOGGED_IN = [dbo].[FNDD_GET_LICENSE_COUNT] (@pCLIENTID)
|
||
|
||
SELECT @USERCOUNT_LOGGED_IN = COUNT(*) FROM TBDD_USER_MODULE_LOG_IN WHERE UPPER(MODULE) = UPPER(@MODULE_NAME) AND CLIENT_ID = @pCLIENTID
|
||
--CHECK USER <20>S IN MODULE_USER_GROUP
|
||
IF EXISTS(select T1.* from TBDD_GROUPS T, TBDD_GROUPS_USER T1 WHERE T.GUID = T1.GROUP_ID AND T1.USER_ID = @USER_ID AND UPPER(T.NAME) = @USER_GROUPNAME)
|
||
BEGIN
|
||
SET @IS_IN_MODULE = 1
|
||
SET @RESULT = 'User is part of Group (' + @USER_GROUPNAME + ')'
|
||
IF EXISTS(select T.* from TBDD_USER_MODULES T WHERE T.USER_ID = @USER_ID AND T.MODULE_ID = @MODULE_GUID)
|
||
BEGIN
|
||
SET @RESULT = @RESULT + '| User is also configured in User-Modules'
|
||
select @IS_ADMIN = T.IS_ADMIN,@USER_RIGHT_FILE_DEL = T.RIGHT1 from TBDD_USER_MODULES T WHERE T.USER_ID = @USER_ID AND T.MODULE_ID = @MODULE_GUID
|
||
END
|
||
END
|
||
ELSE
|
||
BEGIN
|
||
SET @RESULT = 'User not part of group (' + @USER_GROUPNAME + ')'
|
||
IF EXISTS(select T.* from TBDD_USER_MODULES T WHERE T.USER_ID = @USER_ID AND T.MODULE_ID = @MODULE_GUID)
|
||
BEGIN
|
||
SET @RESULT = @RESULT + '| BUT User configured in User-Modules'
|
||
select @IS_ADMIN = T.IS_ADMIN,@USER_RIGHT_FILE_DEL = T.RIGHT1
|
||
--,@USER_RIGHT2 = T.RIGHT2
|
||
from TBDD_USER_MODULES T WHERE T.USER_ID = @USER_ID AND T.MODULE_ID = @MODULE_GUID
|
||
END
|
||
END
|
||
|
||
IF EXISTS(select T1.* from TBDD_GROUPS T, TBDD_GROUPS_USER T1 WHERE T.GUID = T1.GROUP_ID AND T1.USER_ID = @USER_ID AND UPPER(T.NAME) = @ADMIN_GROUPNAME)
|
||
BEGIN
|
||
SET @RESULT = @RESULT + '| User is part of group (' + @ADMIN_GROUPNAME + ')'
|
||
SET @IS_ADMIN = 1
|
||
SET @IS_IN_MODULE = 1
|
||
END
|
||
|
||
END
|
||
|
||
INSERT INTO @Table (USER_ID,USER_PRENAME, USER_SURNAME,USER_SHORTNAME,USER_EMAIL,USER_LANGUAGE,USER_DATE_FORMAT, USER_RIGHT_FILE_DEL,
|
||
MODULE_ACCESS,IS_ADMIN,USERCOUNT_LOGGED_IN, COMMENT,WORKING_MODE,USER_RIGHT2,USER_RIGHT3,USER_RIGHT4,USER_RIGHT5
|
||
,ADDITIONAL_TITLE)
|
||
VALUES (@USER_ID,@USER_PRENAME,@USER_SURNAME,@USER_SHORTNAME,@USER_EMAIL,@USER_LANGUAGE,@USER_DATE_FORMAT,@USER_RIGHT_FILE_DEL,
|
||
@IS_IN_MODULE,@IS_ADMIN,@USERCOUNT_LOGGED_IN,@RESULT,@WORKING_MODE,@USER_RIGHT2,@USER_RIGHT3,@USER_RIGHT4,@USER_RIGHT5
|
||
,'PROD')
|
||
|
||
RETURN
|
||
END
|
||
GO
|
||
CREATE PROCEDURE [dbo].[PRPM_DELETE_PROFILE](@pPID INT)
|
||
AS
|
||
delete from TBPM_CONTROL_TABLE where CONTROL_ID in (SELECT GUID FROM TBPM_PROFILE_CONTROLS where PROFIL_ID = @pPID);
|
||
IF OBJECT_ID (N'TBPM_ADHOC_WF_SERIEL_PARTIES', N'U') IS NOT NULL
|
||
Delete from TBPM_ADHOC_WF_SERIEL_PARTIES WHERE AH_WF_ID In (SELECT GUID
|
||
FROM [DD_ECM].[dbo].[TBPM_ADHOC_WF_OBJECT] where PROFIL_ID = @pPID);
|
||
IF OBJECT_ID (N'TBPM_ADHOC_WF_OBJECT', N'U') IS NOT NULL
|
||
DELETE FROM [DD_ECM].[dbo].[TBPM_ADHOC_WF_OBJECT] where PROFIL_ID = @pPID;
|
||
IF OBJECT_ID (N'TBPM_ERROR_LOG', N'U') IS NOT NULL
|
||
DELETE FROM TBPM_ERROR_LOG WHERE PROFIL_ID = @pPID;
|
||
DELETE FROM TBPM_PROFILE_FILES WHERE PROFIL_ID = @pPID;
|
||
DELETE FROM TBPM_PROFILE_SEARCH WHERE PROFILE_ID = @pPID;
|
||
IF OBJECT_ID (N'TBPM_ADHOC_WF_OBJECT', N'U') IS NOT NULL
|
||
DELETE FROm TBPM_ADHOC_WF_OBJECT WHERE PROFIL_ID = @pPID;
|
||
DELETE FROM TBPM_PROFILE_FINAL_INDEXING WHERE PROFIL_ID = @pPID;
|
||
delete from TBPM_CONTROL_TABLE where CONTROL_ID in (select GUID FROM TBPM_PROFILE_CONTROLS WHERE PROFIL_ID = @pPID);
|
||
DELETE FROM TBPM_PROFILE_CONTROLS WHERE PROFIL_ID = @pPID;
|
||
DELETE FROM TBPM_PROFILE_USER WHERE PROFIL_ID = @pPID;
|
||
DELETE FROM TBPM_PROFILE_GROUP WHERE PROFIL_ID = @pPID;
|
||
DELETE FROM TBPM_PROFILE WHERE GUID = @pPID;
|
||
|
||
GO
|
||
CREATE FUNCTION [dbo].[FNPM_GET_WM_FILE_PATH] (@pDOCGUID BIGINT,@STANDARD As INT = 0)
|
||
RETURNS VARCHAR(MAX)
|
||
AS
|
||
BEGIN
|
||
DECLARE @RELPATH VARCHAR(100),@FILEPATH VARCHAR(500),@NAVPATH as VARCHAR(MAX)
|
||
IF @STANDARD = 1
|
||
SET @RELPATH = '\\windream\objects'
|
||
ELSE
|
||
SELECT @RELPATH = WM_REL_PATH FROM TBPM_KONFIGURATION WHERE GUID = 1
|
||
SELECT @FILEPATH = REPLACE(FILE_PATH,'W:\','') FROM TBPM_PROFILE_FILES WHERE (GUID = @pDOCGUID)
|
||
SET @NAVPATH = @RELPATH + '\' + @FILEPATH
|
||
IF @NAVPATH IS NULL
|
||
SET @NAVPATH = ''
|
||
RETURN @NAVPATH
|
||
END
|
||
GO
|
||
|
||
-- =============================================
|
||
-- Author: Digital Data MS
|
||
-- Create date: 08.01.2020
|
||
-- Description: Checks whether Doc is in use or not
|
||
-- =============================================
|
||
CREATE FUNCTION [dbo].[FNPM_CHECK_DocGUID_Valid](@DocGUID BigInt)
|
||
RETURNS BIT
|
||
AS
|
||
BEGIN
|
||
DECLARE @RESULT BIT
|
||
SET @RESULT = 1
|
||
IF EXISTS(SELECT GUID FROM TBPM_PROFILE_FILES WHERE GUID = @DocGUID)
|
||
BEGIN
|
||
IF EXISTS(SELECT GUID FROM TBPM_PROFILE_FILES WHERE GUID = @DocGUID AND (IN_WORK = 1 OR EDIT = 1 OR ACTIVE = 0))
|
||
SET @RESULT = 0
|
||
END
|
||
ELSE
|
||
SET @RESULT = 0
|
||
RETURN @RESULT
|
||
END
|
||
GO
|
||
|
||
IF NOT EXISTS(SELECT * FROM TBDD_SQL_COMMANDS WHERE TITLE = 'PM_PROFILES_USER')
|
||
INSERT INTO TBDD_SQL_COMMANDS (TITLE,SQL_COMMAND,ADDED_WHO) VALUES ('PM_PROFILES_USER', 'select T.* FROm VWPM_PROFILE_ACTIVE T where T.FILE_COUNT > 0 and T.GUID IN (SELECT PROFILE_ID FROm dbo.FNPM_GET_ACTIVE_PROFILES_USER (@USER_ID))
|
||
UNION
|
||
select T.* FROm VWPM_PROFILE_ACTIVE T where T.DISPLAY_MODE like ''AdHoc BlindFile%'' and T.GUID IN (SELECT PROFILE_ID FROm dbo.FNPM_GET_ACTIVE_PROFILES_USER (@USER_ID))'
|
||
,'Digital Data')
|
||
ELSE
|
||
UPDATE TBDD_SQL_COMMANDS SET SQL_COMMAND =
|
||
'select T.* FROm VWPM_PROFILE_ACTIVE T where T.FILE_COUNT > 0 and T.GUID IN (SELECT PROFILE_ID FROm dbo.FNPM_GET_ACTIVE_PROFILES_USER (@USER_ID))
|
||
UNION
|
||
select T.* FROm VWPM_PROFILE_ACTIVE T where T.DISPLAY_MODE like ''AdHoc BlindFile%'' and T.GUID IN (SELECT PROFILE_ID FROm dbo.FNPM_GET_ACTIVE_PROFILES_USER (@USER_ID))'
|
||
WHERE TITLE = 'PM_PROFILES_USER'
|
||
GO
|
||
IF NOT EXISTS(SELECT * FROM TBDD_SQL_COMMANDS WHERE TITLE = 'PM_PROFILES_USER')
|
||
INSERT INTO TBDD_SQL_COMMANDS (TITLE,SQL_COMMAND,ADDED_WHO) VALUES ('PM_PROFILES_USER', 'select T.* FROm VWPM_PROFILE_ACTIVE T where T.FILE_COUNT > 0 and T.GUID IN (SELECT PROFILE_ID FROm dbo.FNPM_GET_ACTIVE_PROFILES_USER (@USER_ID))
|
||
UNION
|
||
select T.* FROm VWPM_PROFILE_ACTIVE T where T.DISPLAY_MODE like ''AdHoc BlindFile%'' and T.GUID IN (SELECT PROFILE_ID FROm dbo.FNPM_GET_ACTIVE_PROFILES_USER (@USER_ID))'
|
||
,'Digital Data')
|
||
ELSE
|
||
UPDATE TBDD_SQL_COMMANDS SET SQL_COMMAND =
|
||
'select T.* FROm VWPM_PROFILE_ACTIVE T where T.FILE_COUNT > 0 and T.GUID IN (SELECT PROFILE_ID FROm dbo.FNPM_GET_ACTIVE_PROFILES_USER (@USER_ID))
|
||
UNION
|
||
select T.* FROm VWPM_PROFILE_ACTIVE T where T.DISPLAY_MODE like ''AdHoc BlindFile%'' and T.GUID IN (SELECT PROFILE_ID FROm dbo.FNPM_GET_ACTIVE_PROFILES_USER (@USER_ID))'
|
||
WHERE TITLE = 'PM_PROFILES_USER'
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'GridView_Docs.ViewCaption', 'de-DE', 'Caption', 'Gesamt<EFBFBD>bersicht', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'GridView_Docs.ViewCaption', 'en-US', 'Caption', 'Overview', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'GridView_Docs.ViewCaption', 'fr-FR', 'Caption', 'Aper<EFBFBD>u g<>n<EFBFBD>ral', '')
|
||
GO
|
||
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'GridView_Docs.DetailCaption', 'de-DE', 'Caption', 'Detailansicht Profil:', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'GridView_Docs.DetailCaption', 'en-US', 'Caption', 'Detail view profile', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'GridView_Docs.DetailCaption', 'fr-FR', 'Caption', 'Vue d<>taill<6C>e du profil:', '')
|
||
GO
|
||
|
||
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'INACTIVITYRecognized', 'de-DE', 'Information', 'Sie wurden aufgrund von Inaktivit<69>t automatisch abgemeldet!', '')
|
||
GO
|
||
|
||
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'INACTIVITYRecognized', 'en-US', 'Information', 'Due to inactivity we closed all actions and You have been logged out automatically!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'INACTIVITYRecognized', 'fr-FR', 'Information', 'Vous avez <20>t<EFBFBD> automatiquement d<>connect<63> pour cause d''inactivit<EFBFBD>!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'MASS_NO_WF_SELECTED', 'de-DE', 'Information', 'Bitte selektieren Sie mindestens einen Vorgang!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'MASS_NO_WF_SELECTED', 'en-US', 'Information', 'Please select at least one item!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'MASS_NO_WF_SELECTED', 'fr-FR', 'Information', 'Veuillez s<>lectionner au moins une op<6F>ration!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'MASS_ERROR_WINDREAM', 'de-DE', 'Information', 'Massenabschluss konnte nicht ausgef<65>hrt werden, weil windream nicht initialisiert werden konnte!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'MASS_ERROR_WINDREAM', 'en-US', 'Information', 'Massvalidation could not be completed because of an error in windream!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'MASS_ERROR_WINDREAM', 'fr-FR', 'Information', 'La cl<63>ture en masse n''a pas pu <20>tre ex<65>cut<75>e parce que windream n''a pas pu <20>tre initialis<69> !', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('All Modules', 1, 'General', 'MsgboxTitleWarning', 'de-DE', 'Caption', 'Warnung:', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('All Modules', 1, 'General', 'MsgboxTitleWarning', 'en-US', 'Caption', 'Warning:', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('All Modules', 1, 'General', 'MsgboxTitleWarning', 'fr-FR', 'Caption', 'Avertissement:', '')
|
||
GO
|
||
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('All Modules', 1, 'General', 'MsgboxTitleAttention', 'de-DE', 'Caption', 'Achtung:', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('All Modules', 1, 'General', 'MsgboxTitleAttention', 'en-US', 'Caption', 'Attention:', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('All Modules', 1, 'General', 'MsgboxTitleAttention', 'fr-FR', 'Caption', 'Attention:', '')
|
||
GO
|
||
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'WorkflowIsActive1', 'de-DE', 'Caption', 'Bitte schliessen Sie den aktiven Workflow!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'WorkflowIsActive1', 'en-US', 'Caption', 'Please close the active workflow!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'WorkflowIsActive1', 'fr-FR', 'Caption', 'Veuillez fermer le workflow actif!', '')
|
||
GO
|
||
DELETE FROM TBDD_GUI_LANGUAGE_PHRASE WHERE TITLE = 'LicenseCountCaption';
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'NumberLicenses', 'de-DE', 'Caption', 'Anzahl Lizenzen:', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'NumberLicenses', 'en-US', 'Caption', 'Number of licenses:', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'NumberLicenses', 'fr-FR', 'Caption', 'Nombre de licences
|
||
:', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'NumberUserLoggedIn', 'de-DE', 'Caption', 'Anzahl User angemeldet:', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'NumberUserLoggedIn', 'en-US', 'Caption', 'Number of users logged in:', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'NumberUserLoggedIn', 'fr-FR', 'Caption', 'Nombre d''utilisateurs connect<63>s:', '')
|
||
GO
|
||
|
||
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'DescItems', 'de-DE', 'Caption', 'Vorg<EFBFBD>nge', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'DescItems', 'en-US', 'Caption', 'objects', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'DescItems', 'fr-FR', 'Caption', 'Op<EFBFBD>rations', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'WorkflowIsActive', 'de-DE', 'Caption', 'Bitte schliessen Sie den aktiven Workflow!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'WorkflowIsActive', 'en-US', 'Caption', 'Please close the active workflow!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'WorkflowIsActive', 'fr-FR', 'Caption', 'Veuillez fermer le workflow actif!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'WorkflowIsActive2', 'de-DE', 'Caption', 'Es ist bereits ein Workflow ge<67>ffnet!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'WorkflowIsActive2', 'en-US', 'Caption', 'There is already a workflow active!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'WorkflowIsActive2', 'fr-FR', 'Caption', 'Un workflow est d<>j<EFBFBD> ouvert!', '')
|
||
GO
|
||
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'WFInWork', 'de-DE', 'Caption', 'Achtung: der gew<65>hlte Vorgang ist durch einen anderen Benutzer bereits in Bearbeitung oder anderweitig gesperrt!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'WFInWork', 'en-US', 'Caption', 'Attention: the selected operation is already being processed by another user or is otherwise blocked!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'WFInWork', 'fr-FR', 'Caption', 'Attention : la demande s<>lectionn<6E>e est d<>j<EFBFBD> en cours de traitement par un autre utilisateur ou est bloqu<71>e d''une autre mani<6E>re.!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'NoWorkflowData', 'de-DE', 'Caption', 'Aktuell keine Workflowdaten vorhanden!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'NoWorkflowData', 'en-US', 'Caption', 'No workflow data available at the moment!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'NoWorkflowData', 'fr-FR', 'Caption', 'Aucune donn<6E>e de workflow disponible actuellement!', '')
|
||
GO
|
||
--#### AB HIER FRANZ<4E>SISCH INTEGRIERT
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'DebugModeActive', 'de-DE', 'Caption', 'HINWEIS: UserDebugMode ist eingeschaltet!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'DebugModeActive', 'en-US', 'Caption', 'NOTE: UserDebugMode is activated!', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'DebugModeActive', 'fr-FR', 'Caption', 'REMARQUE : UserDebugMode est activ<69> !', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'CaptionDeactivateDebugMode', 'de-DE', 'Caption', 'Ghost Mode inaktivieren', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'CaptionDeactivateDebugMode', 'en-US', 'Caption', 'Disable Ghost Mode', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'CaptionDeactivateDebugMode', 'fr-FR', 'Caption', 'D<EFBFBD>sactiver le mode fant<6E>me', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'DescFilterActive', 'de-DE', 'Caption', 'Filter aktiv', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'DescFilterActive', 'en-US', 'Caption', 'Filter active', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'DescFilterActive', 'fr-FR', 'Caption', 'Filtre actif', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'Workflows', 'de-DE', 'Translation', 'Workflows', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'Workflows', 'en-US', 'Translation', 'Workflows', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'Workflows', 'fr-FR', 'Translation', 'Workflows', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'CaptLastSync', 'de-DE', 'Translation', 'Letzte Synchronisation', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'CaptLastSync', 'en-US', 'Translation', 'Last synchronization', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmMain', 'CaptLastSync', 'fr-FR', 'Translation', 'Derni<EFBFBD>re synchronisation', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'remainingOps', 'de-DE', 'Translation', 'Verbleibende Vorg<72>nge', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'remainingOps', 'en-US', 'Translation', 'Remaining operations', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'remainingOps', 'fr-FR', 'Translation', 'Op<EFBFBD>rations restantes', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'msgEndOfProfile', 'de-DE', 'Message', 'Ende des Profils - Keine weiteren Vorg<72>nge', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'msgEndOfProfile', 'en-US', 'Message', 'End of the profile - No further operations', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'msgEndOfProfile', 'fr-FR', 'Message', 'Fin du profil - aucune autre op<6F>ration', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'F2forSave', 'de-DE', 'Caption', 'F2 f<>r Speichern', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'F2forSave', 'en-US', 'Caption', 'F2 for save', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'F2forSave', 'fr-FR', 'Caption', 'F2 pour enregistrer', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'InputSaved', 'de-DE', 'Caption', 'Eingaben gespeichert', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'InputSaved', 'en-US', 'Caption', 'Inputs saved', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'InputSaved', 'fr-FR', 'Caption', 'Saisies enregistr<74>es', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'Application', 'App.ReminderPipeline', 'fr-FR', 'Information', 'Vous avez encore des t<>ches <20> accomplir dans votre domaine de responsabilit<69>.', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'frmValidator.Conversation_Delete', 'fr-FR', 'MsgboxResult', 'Vous voulez mettre fin <20> la conversation?', 'Demande')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'frmValidator.MissingInput', 'fr-FR', 'Information', 'Veuillez valider les champs marqu<71>s en rouge!', '')
|
||
GO
|
||
DELETE FROM TBDD_GUI_LANGUAGE_PHRASE WHERE TITLE = 'frmValidator.NoMoreDocument'
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'frmValidator.NoMoreDocument', 'fr-FR', 'MsgBox', 'Aucune autre op<6F>ration trouv<75>e - fin du profil!', 'Remarque')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'frmValidator.NoMoreDocument', 'de-DE', 'MsgBox', 'Keine weiteren Vorg<72>nge gefunden - Ende des Profils!', 'Hinweis')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'frmValidator.NoMoreDocument', 'en-US', 'MsgBox', 'Aucune autre op<6F>ration trouv<75>e - fin du profil!', 'Note')
|
||
GO
|
||
DELETE FROM TBDD_GUI_LANGUAGE_PHRASE WHERE TITLE = 'frmValidator.ValidationButton'
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'frmValidator.ValidationButton', 'fr-FR', 'Button', 'Enregistrer - Op<4F>ration suivante (F2)', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'frmValidator.ValidationButton', 'de-DE', 'Button', 'Speichern - N<>chster Vorgang (F2)', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'frmValidator.ValidationButton', 'en-US', 'Button', 'Save - Next operation (F2)', '')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'frmValidator', 'frmValidator.WrongInputControl', 'fr-FR', 'Information', 'Mauvaise saisie', '')
|
||
GO
|
||
DELETE FROM TBDD_GUI_LANGUAGE_PHRASE WHERE TITLE = 'No Client relation'
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'General', 'No Client relation', 'fr-FR', 'Information', 'Vous n''avez aucun lien avec un client!', 'Veuillez contacter l''administrateur du syst<73>me!')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'General', 'No Client relation', 'en-US', 'Information', 'You are not related to a client!', 'Please contact the system administrator!')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'General', 'No Client relation', 'de-DE', 'Information', 'Ihrem User ist kein Client zugeordnet!', 'Bitte wenden Sie sich an den Systemadministrator!')
|
||
GO
|
||
DELETE FROM TBDD_GUI_LANGUAGE_PHRASE WHERE TITLE = 'No Module Configuration'
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'General', 'No Module Configuration', 'fr-FR', 'Information', 'Attention : vous n''<EFBFBD>tes pas autoris<69> <20> utiliser TaskFlow!', 'Veuillez contacter l''administrateur du syst<73>me!')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'General', 'No Module Configuration', 'en-US', 'Information', 'Attention: You are not released for the use of TaskFlow!', 'Please contact the system administrator!')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'General', 'No Module Configuration', 'de-DE', 'Information', 'Achtung: Sie sind nicht f<>r die Nutzung von ProcessManager freigegeben!', 'Bitte wenden Sie sich an den Systemadministrator!')
|
||
GO
|
||
DELETE FROM TBDD_GUI_LANGUAGE_PHRASE WHERE TITLE = 'No Userconfig'
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'General', 'No Userconfig', 'fr-FR', 'Information', 'Attention : ils ne sont pas enregistr<74>s dans la gestion des utilisateurs!', 'Veuillez contacter l''administrateur du syst<73>me!')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'General', 'No Userconfig', 'en-US', 'Information', 'Attention: You are not stored in the user administration!', 'Please contact the system administrator!')
|
||
GO
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
([MODULE], [INTERNAL], [OBJ_NAME], [TITLE], [LANGUAGE], [CAPT_TYPE], [STRING1], STRING2)
|
||
VALUES
|
||
('PM', 1, 'General', 'No Userconfig', 'de-DE', 'Information', 'Achtung: Sie sind nicht f<>r die Nutzung von ProcessManager freigegeben!', 'Bitte wenden Sie sich an den Systemadministrator!')
|
||
GO
|
||
/****** Object: Job [PRPM_REFRESH_FILES_SQL] Script Date: 17.01.2022 13:23:39 ******/
|
||
BEGIN TRANSACTION
|
||
DECLARE @ReturnCode INT
|
||
SELECT @ReturnCode = 0
|
||
/****** Object: JobCategory [[Uncategorized (Local)]] Script Date: 17.01.2022 13:23:39 ******/
|
||
IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'[Uncategorized (Local)]' AND category_class=1)
|
||
BEGIN
|
||
EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'[Uncategorized (Local)]'
|
||
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
|
||
|
||
END
|
||
|
||
DECLARE @jobId BINARY(16)
|
||
EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'PRPM_REFRESH_FILES_SQL',
|
||
@enabled=1,
|
||
@notify_level_eventlog=0,
|
||
@notify_level_email=0,
|
||
@notify_level_netsend=0,
|
||
@notify_level_page=0,
|
||
@delete_level=0,
|
||
@description=N'Es ist keine Beschreibung verf<72>gbar.',
|
||
@category_name=N'[Uncategorized (Local)]',
|
||
@owner_login_name=N'sa', @job_id = @jobId OUTPUT
|
||
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
|
||
/****** Object: Step [PRPM_REFRESH_FILES_SQL] Script Date: 17.01.2022 13:23:39 ******/
|
||
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'PRPM_REFRESH_FILES_SQL',
|
||
@step_id=1,
|
||
@cmdexec_success_code=0,
|
||
@on_success_action=1,
|
||
@on_success_step_id=0,
|
||
@on_fail_action=2,
|
||
@on_fail_step_id=0,
|
||
@retry_attempts=0,
|
||
@retry_interval=0,
|
||
@os_run_priority=0, @subsystem=N'TSQL',
|
||
@command=N'EXEC PRPM_REFRESH_FILES_SQL;
|
||
GO',
|
||
@database_name=N'DD_ECM',
|
||
@flags=0
|
||
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
|
||
EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
|
||
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
|
||
EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'MO_FR',
|
||
@enabled=1,
|
||
@freq_type=8,
|
||
@freq_interval=62,
|
||
@freq_subday_type=4,
|
||
@freq_subday_interval=5,
|
||
@freq_relative_interval=0,
|
||
@freq_recurrence_factor=1,
|
||
@active_start_date=20200115,
|
||
@active_end_date=99991231,
|
||
@active_start_time=80000,
|
||
@active_end_time=170000,
|
||
@schedule_uid=N'ac93c8f9-3890-4111-a3de-768a66f97266'
|
||
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
|
||
EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
|
||
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
|
||
COMMIT TRANSACTION
|
||
GOTO EndSave
|
||
QuitWithRollback:
|
||
IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
|
||
EndSave:
|
||
GO
|
||
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
(OBJ_NAME,[MODULE],[TITLE],[LANGUAGE],[CAPT_TYPE],[STRING1],STRING2)
|
||
VALUES('frmRejectionCommit','PM','frmRejectionCommit.MSG1','de-DE','Information','Sie wollen diesen Beleg ablehnen?','');
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
(OBJ_NAME,[MODULE],[TITLE],[LANGUAGE],[CAPT_TYPE],[STRING1],STRING2)
|
||
VALUES('frmRejectionCommit','PM','frmRejectionCommit.MSG1','en-US','Information','You want to reject this receipt?','');
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
(OBJ_NAME,[MODULE],[TITLE],[LANGUAGE],[CAPT_TYPE],[STRING1],STRING2)
|
||
VALUES('frmRejectionCommit','PM','frmRejectionCommit.MSG2','de-DE','Information','Wenn ja, dann geben Sie bitte einen Grund f<>r die Ablehnung ein!','')
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
(OBJ_NAME,[MODULE],[TITLE],[LANGUAGE],[CAPT_TYPE],[STRING1],STRING2)
|
||
VALUES('frmRejectionCommit','PM','frmRejectionCommit.MSG2','en-US','Information','If yes, please enter a reason for your refusal!','')
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
(OBJ_NAME,[MODULE],[TITLE],[LANGUAGE],[CAPT_TYPE],[STRING1],STRING2)
|
||
VALUES('frmRejectionCommit','PM','frmRejectionCommit.Caption','de-DE','Information','Ablehnung - Best<73>tigung','');
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
(OBJ_NAME,[MODULE],[TITLE],[LANGUAGE],[CAPT_TYPE],[STRING1],STRING2)
|
||
VALUES('frmRejectionCommit','PM','frmRejectionCommit.Caption','en-US','Information','Rejection - Confirmation','');
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
(OBJ_NAME,[MODULE],[TITLE],[LANGUAGE],[CAPT_TYPE],[STRING1],STRING2)
|
||
VALUES('frmRejectionCommit','PM','frmRejectionCommit.MissingInput','de-DE','Message','Bitte w<>hlen Sie einen Grund und geben eine Begr<67>ndung ein!','');
|
||
INSERT INTO [dbo].[TBDD_GUI_LANGUAGE_PHRASE]
|
||
(OBJ_NAME,[MODULE],[TITLE],[LANGUAGE],[CAPT_TYPE],[STRING1],STRING2)
|
||
VALUES('frmRejectionCommit','PM','frmRejectionCommit.MissingInput','en-US','Message','Please select a reason and enter a justification!','');
|
||
ALTER TABLE TBPM_PROFILE ADD CURRENCY_ATTRIBUTE VARCHAR(100) NOT NULL DEFAULT ''
|
||
GO
|
||
CREATE TABLE [dbo].[TBTF_VALIDATOR_MESSAGE](
|
||
[GUID] [bigint] IDENTITY(1,1) NOT NULL,
|
||
[DocID] [bigint] NOT NULL,
|
||
[GUI_LANG_TITLE] [nvarchar](100) NOT NULL,
|
||
[ImageIndex] [tinyint] NOT NULL,
|
||
[Active] [bit] NOT NULL,
|
||
[ADDED_WHEN] [datetime] NOT NULL,
|
||
[ADDED_WHO] [varchar](100) NOT NULL,
|
||
[CHANGED_WHEN] [datetime] NULL,
|
||
[CHANGED_WHO] [varchar](100) NULL,
|
||
CONSTRAINT [PK_TBTFVALIDATOR_MESSAGE] PRIMARY KEY CLUSTERED
|
||
(
|
||
[GUID] 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
|
||
|
||
ALTER TABLE [dbo].[TBTF_VALIDATOR_MESSAGE] ADD CONSTRAINT [DF_TBTFVALIDATOR_MESSAGE_ACTIVE] DEFAULT ((1)) FOR [Active]
|
||
GO
|
||
|
||
ALTER TABLE [dbo].[TBTF_VALIDATOR_MESSAGE] ADD CONSTRAINT [DF_TBTFVALIDATOR_MESSAGE_ADDED_WHEN] DEFAULT (getdate()) FOR [ADDED_WHEN]
|
||
GO
|
||
|
||
CREATE TRIGGER [dbo].[TBTF_VALIDATOR_MESSAGE_AFT_UPD] ON [dbo].[TBTF_VALIDATOR_MESSAGE]
|
||
FOR UPDATE
|
||
AS
|
||
UPDATE TBTF_VALIDATOR_MESSAGE SET CHANGED_WHEN = GETDATE()
|
||
FROM INSERTED
|
||
WHERE TBTF_VALIDATOR_MESSAGE.GUID = INSERTED.GUID
|
||
GO
|
||
|
||
ALTER TABLE [dbo].[TBTF_VALIDATOR_MESSAGE] ENABLE TRIGGER [TBTF_VALIDATOR_MESSAGE_AFT_UPD]
|
||
GO
|
||
|
||
INSERT INTO [dbo].[TBDD_SQL_COMMANDS]
|
||
(TITLE,SQL_COMMAND)
|
||
VALUES('TF_WORKFLOW_MESSAGE','SELECT
|
||
CONVERT(VARCHAR(30), A.ADDED_WHEN,20) + '' - '' + B.STRING1 as MSG,A.ImageIndex
|
||
FROM
|
||
TBTF_VALIDATOR_MESSAGE A INNER JOIN
|
||
(SELECt * FROM TBDD_GUI_LANGUAGE_PHRASE
|
||
WHERE MODULE = ''PM'' AND OBJ_NAME = ''frmValidator'' AND CAPT_TYPE = ''WF_MESSAGE'') B ON A.GUI_LANG_TITLE = B.TITLE
|
||
WHERE
|
||
A.Active = 1 and (A.DocID = @DocID or A.DocID = 1) AND B.LANGUAGE = ''@LANGUAGE'' ORDER BY A.ADDED_WHEN DESC');
|
||
GO
|
||
-- =================================================================
|
||
-- Die Procedure f<>gt einen Datensatz in die Tabelle TBTF_VALIDATOR_MESSAGE ein.
|
||
--
|
||
-- =================================================================
|
||
-- Copyright (c) 2024 by Digital Data GmbH
|
||
--
|
||
-- Digital Data GmbH <20> Ludwig-Rinn-Strasse 16 <20> D-35452 Heuchelheim
|
||
-- Tel.: 0641/202360 <20> E-Mail: info-flow@digitaldata.works
|
||
-- =================================================================
|
||
-- Creation Date / Author: 29.08.2024 / MP
|
||
-- =================================================================
|
||
-- History:
|
||
-- 29.08.2024 / MP - Prozedur erstellt
|
||
|
||
CREATE PROCEDURE [dbo].[PRTF_NEW_VALIDATOR_MESSAGE]
|
||
@DOC_ID BIGINT -- DocID oder IDB_OBJ_ID / 1 f<>r alle Belege
|
||
, @MESSAGE_TITLE VARCHAR(100) -- Title aus GUI_LANGUAGE_PHRASE
|
||
, @ADDED_WHO VARCHAR(100) -- Wo/Von wem wurde die Prozedur aufgerufen
|
||
, @IMAGE_INDEX INTEGER = 0 -- ICON: 0 = Info / 1 = Fehlende Eingabe / 2 = Fehler
|
||
AS
|
||
BEGIN
|
||
SET NOCOUNT ON;
|
||
|
||
IF NOT EXISTS (SELECT 1 FROM TBDD_GUI_LANGUAGE_PHRASE
|
||
WHERE TITLE = @MESSAGE_TITLE AND MODULE = 'PM' AND CAPT_TYPE = 'WF_MESSAGE' AND OBJ_NAME = 'frmValidator')
|
||
BEGIN
|
||
-- Wenn es die Meldung nicht gibt, oder nicht korrekt konfiguriert ist, brechen wir hier ab
|
||
RETURN;
|
||
END
|
||
|
||
IF @IMAGE_INDEX > 2
|
||
BEGIN
|
||
SET @IMAGE_INDEX = 0;
|
||
END
|
||
|
||
INSERT INTO TBTF_VALIDATOR_MESSAGE
|
||
(
|
||
DocID
|
||
, GUI_LANG_TITLE
|
||
, ImageIndex
|
||
, Active
|
||
, ADDED_WHO
|
||
) VALUES (
|
||
@DOC_ID
|
||
, @MESSAGE_TITLE
|
||
, @IMAGE_INDEX
|
||
, 1 -- wir f<>gen nur aktive S<>tze ein
|
||
, @ADDED_WHO
|
||
);
|
||
END
|
||
GO
|
||
-- =================================================================
|
||
-- Die Procedure setzt einen Datensatz der Tabelle TBTF_VALIDATOR_MESSAGE
|
||
-- auf ACTIVE = 0
|
||
--
|
||
-- =================================================================
|
||
-- Copyright (c) 2024 by Digital Data GmbH
|
||
--
|
||
-- Digital Data GmbH <20> Ludwig-Rinn-Strasse 16 <20> D-35452 Heuchelheim
|
||
-- Tel.: 0641/202360 <20> E-Mail: info-flow@digitaldata.works
|
||
-- =================================================================
|
||
-- Creation Date / Author: 30.08.2024 / MP
|
||
-- =================================================================
|
||
-- History:
|
||
-- 30.08.2024 / MP - Prozedur erstellt
|
||
|
||
CREATE PROCEDURE [dbo].[PRTF_DEACTIVATE_VALIDATOR_MESSAGE]
|
||
@DOC_ID BIGINT -- DocID oder IDB_OBJ_ID / 1 f<>r alle Belege
|
||
, @MESSAGE_TITLE VARCHAR(100) -- Title aus GUI_LANGUAGE_PHRASE
|
||
, @CHANGED_WHO VARCHAR(100) -- Wo/Von wem wurde die Prozedur aufgerufen
|
||
, @ACTIVE_FLAG INTEGER = 0 -- optionales ACTIVE-Flag - Default = 0
|
||
AS
|
||
BEGIN
|
||
SET NOCOUNT ON;
|
||
|
||
UPDATE TBTF_VALIDATOR_MESSAGE SET
|
||
Active = @ACTIVE_FLAG,
|
||
CHANGED_WHO = @CHANGED_WHO
|
||
WHERE DocID = @DOC_ID
|
||
AND GUI_LANG_TITLE = @MESSAGE_TITLE;
|
||
|
||
END
|
||
GO
|
||
|
||
DECLARE @SQL NVARCHAR(max)
|
||
IF EXISTS (SELECT * FROM [TBDD_CATALOG] WHERE CAT_TITLE = 'USE_IDB_AS_METADATA' AND CAT_STRING = '1')
|
||
BEGIN
|
||
SET @SQL = 'ALTER VIEW [dbo].[VWPM_CONTROL_INDEX] AS
|
||
SELECT TOP 100 PERCENT
|
||
T1.GUID,
|
||
T.GUID PROFIL_ID,
|
||
T.NAME PROFIL_NAME,
|
||
T.LOG_INDEX,
|
||
T1.NAME CTRL_NAME,
|
||
T1.CTRL_TYPE,
|
||
T1.CTRL_TEXT,
|
||
T1.X_LOC,
|
||
T1.Y_LOC,
|
||
T1.FONT_COLOR,
|
||
T1.FONT_FAMILY,
|
||
T1.FONT_SIZE,
|
||
T1.FONT_STYLE,
|
||
T1.WIDTH,
|
||
T1.HEIGHT,
|
||
COALESCE(T1.INDEX_NAME,'''') INDEX_NAME,
|
||
COALESCE((SELECT TYP_ID FROM IDB.dbo.TBIDB_ATTRIBUTE WHERE TITLE = COALESCE(T1.INDEX_NAME,'''')),''0'') AS IDB_TYP,
|
||
T1.VALIDATION,
|
||
T1.CHOICE_LIST,
|
||
T1.TYP,
|
||
T1.CONNECTION_ID,
|
||
CASE WHEN T1.[SQL_UEBERPRUEFUNG] IS NULL THEN '''' ELSE T1.[SQL_UEBERPRUEFUNG] END AS [SQL_UEBERPRUEFUNG],
|
||
T1.[READ_ONLY],
|
||
T1.LOAD_IDX_VALUE,
|
||
T1.DEFAULT_VALUE,
|
||
T1.REGEX_MATCH,
|
||
T1.REGEX_MESSAGE_DE,
|
||
T1.REGEX_MESSAGE_EN,
|
||
T1.OVERWRITE_DATA,
|
||
T1.SET_CONTROL_DATA,
|
||
T1.SAVE_CHANGE_ON_ENABLED,
|
||
T1.FORMAT_STRING CTRL_FORMAT_STRING,
|
||
T1.BACKCOLOR_IF CTRL_BACKCOLOR_IF,
|
||
T1.VKT_ADD_ITEM
|
||
FROM
|
||
TBPM_PROFILE T,
|
||
TBPM_PROFILE_CONTROLS T1
|
||
WHERE
|
||
T.GUID = T1.PROFIL_ID
|
||
AND T1.CONTROL_ACTIVE = 1
|
||
ORDER BY
|
||
T.GUID,
|
||
T1.X_LOC,
|
||
T1.Y_LOC'
|
||
END
|
||
ELSE
|
||
BEGIN
|
||
SET @SQL = 'ALTER VIEW [dbo].[VWPM_CONTROL_INDEX] AS
|
||
SELECT TOP 100 PERCENT
|
||
T1.GUID,
|
||
T.GUID PROFIL_ID,
|
||
T.NAME PROFIL_NAME,
|
||
T.LOG_INDEX,
|
||
T1.NAME CTRL_NAME,
|
||
T1.CTRL_TYPE,
|
||
T1.CTRL_TEXT,
|
||
T1.X_LOC,
|
||
T1.Y_LOC,
|
||
T1.FONT_COLOR,
|
||
T1.FONT_FAMILY,
|
||
T1.FONT_SIZE,
|
||
T1.FONT_STYLE,
|
||
T1.WIDTH,
|
||
T1.HEIGHT,
|
||
COALESCE(T1.INDEX_NAME,'''') INDEX_NAME,
|
||
'' AS IDB_TYP,
|
||
T1.VALIDATION,
|
||
T1.CHOICE_LIST,
|
||
T1.TYP,
|
||
T1.CONNECTION_ID,
|
||
CASE WHEN T1.[SQL_UEBERPRUEFUNG] IS NULL THEN '''' ELSE T1.[SQL_UEBERPRUEFUNG] END AS [SQL_UEBERPRUEFUNG],
|
||
T1.[READ_ONLY],
|
||
T1.LOAD_IDX_VALUE,
|
||
T1.DEFAULT_VALUE,
|
||
T1.REGEX_MATCH,
|
||
T1.REGEX_MESSAGE_DE,
|
||
T1.REGEX_MESSAGE_EN,
|
||
T1.OVERWRITE_DATA,
|
||
T1.SET_CONTROL_DATA,
|
||
T1.SAVE_CHANGE_ON_ENABLED,
|
||
T1.FORMAT_STRING CTRL_FORMAT_STRING,
|
||
T1.BACKCOLOR_IF CTRL_BACKCOLOR_IF,
|
||
T1.VKT_ADD_ITEM
|
||
FROM
|
||
TBPM_PROFILE T,
|
||
TBPM_PROFILE_CONTROLS T1
|
||
WHERE
|
||
T.GUID = T1.PROFIL_ID
|
||
AND T1.CONTROL_ACTIVE = 1
|
||
ORDER BY
|
||
T.GUID,
|
||
T1.X_LOC,
|
||
T1.Y_LOC'
|
||
END
|
||
EXEC (@SQL);
|
||
GO
|
||
CREATE TABLE TBTF_PROFILE_FILES_WORK
|
||
(
|
||
GUID BIGINT NOT NULL IDENTITY(1,1),
|
||
ProfileID INTEGER NOT NULL,
|
||
DocID BIGINT NOT NULL,
|
||
InWork BIT NOT NULL DEFAULT 0,
|
||
Worked BIT NOT NULL DEFAULT 0,
|
||
Action_When DATETIME,
|
||
Action_UserID INTEGER,
|
||
ChangedWho_ID INTEGER,
|
||
CHANGED_WHEN DATETIME,
|
||
CONSTRAINT PK_TBTF_PROFILE_FILES_WORK PRIMARY KEY (GUID),
|
||
CONSTRAINT UQ_TBTF_PROFILE_FILES_WORK UNIQUE(ProfileID,DocID)
|
||
)
|
||
GO
|
||
|
||
CREATE PROCEDURE PRTF_PROFILE_FILES_WORK @pDocID BIGINT,@pProfilID INTEGER,@pUserID INTEGER, @pMode VARCHAR(100)
|
||
AS
|
||
BEGIN
|
||
IF NOT EXISTS(SELECT GUID FROM TBTF_PROFILE_FILES_WORK WHERE ProfileID = @pProfilID AND DocID = @pDocID)
|
||
BEGIN
|
||
INSERT INTO TBTF_PROFILE_FILES_WORK (ProfileID,DocID,Action_UserID,Action_When) VALUES (@pProfilID,@pDocID,@pUserID,GETDATE());
|
||
END
|
||
IF @pMode = 'FreeFile'
|
||
BEGIN
|
||
PRINT 'FreeFile ...'
|
||
UPDATE TBTF_PROFILE_FILES_WORK SET InWork = 0, Action_UserID = @pUserID
|
||
WHERE DocID = @pDocID AND ProfileID = @pProfilID AND InWork = 1;
|
||
END
|
||
ELSE IF @pMode = 'InWork'
|
||
UPDATE TBTF_PROFILE_FILES_WORK SET InWork = 1, Action_When = GETDATE(), Action_UserID = @pUserID
|
||
WHERE DocID = @pDocID AND ProfileID = @pProfilID AND InWork = 0;
|
||
ELSE IF @pMode = 'Worked'
|
||
UPDATE TBTF_PROFILE_FILES_WORK SET InWork = 0,Worked = 1, Action_When = GETDATE(), Action_UserID = @pUserID
|
||
WHERE DocID = @pDocID AND ProfileID = @pProfilID AND Worked = 0;
|
||
END
|
||
GO
|
||
DROP TABLE TBIMPORT_USER;
|
||
GO |