USE [master] GO /****** Object: Database [{DBName}] Script Date: 01/06/2012 15:49:32 ******/ IF EXISTS (SELECT name FROM sys.databases WHERE name = N'{DBName}') BEGIN PRINT 'Dropping existing database {DBName}' ALTER DATABASE [{DBName}] SET SINGLE_USER WITH ROLLBACK IMMEDIATE DROP DATABASE [{DBName}] END GO /****** Object: Database [{DBName}] Script Date: 01/06/2012 15:02:52 ******/ PRINT 'Creating Database {DBName} - {DBPath}\{DBName}.mdf' GO CREATE DATABASE [{DBName}] ON PRIMARY ( NAME = N'VEPROMS_Users', FILENAME = N'{DBPath}\{DBName}.mdf') LOG ON ( NAME = N'VEPROMS_Users_log', FILENAME = N'{DBPath}\{DBName}_1.ldf') COLLATE SQL_Latin1_General_CP1_CI_AS GO PRINT '{DBName} Created' GO EXEC dbo.sp_dbcmptlevel @dbname=N'{DBName}', @new_cmptlevel=90 GO PRINT '{sp_dbcmptlevel} Completed' GO IF (1 = FULLTEXTSERVICEPROPERTY('IsFullTextInstalled')) begin EXEC [{DBName}].[dbo].[sp_fulltext_database] @action = 'disable' end GO ALTER DATABASE [{DBName}] SET ANSI_NULL_DEFAULT OFF GO ALTER DATABASE [{DBName}] SET ANSI_NULLS OFF GO ALTER DATABASE [{DBName}] SET ANSI_PADDING OFF GO ALTER DATABASE [{DBName}] SET ANSI_WARNINGS OFF GO ALTER DATABASE [{DBName}] SET ARITHABORT OFF GO ALTER DATABASE [{DBName}] SET AUTO_CLOSE ON GO ALTER DATABASE [{DBName}] SET AUTO_CREATE_STATISTICS ON GO ALTER DATABASE [{DBName}] SET AUTO_SHRINK ON GO ALTER DATABASE [{DBName}] SET AUTO_UPDATE_STATISTICS ON GO ALTER DATABASE [{DBName}] SET CURSOR_CLOSE_ON_COMMIT OFF GO ALTER DATABASE [{DBName}] SET CURSOR_DEFAULT GLOBAL GO ALTER DATABASE [{DBName}] SET CONCAT_NULL_YIELDS_NULL OFF GO ALTER DATABASE [{DBName}] SET NUMERIC_ROUNDABORT OFF GO ALTER DATABASE [{DBName}] SET QUOTED_IDENTIFIER OFF GO ALTER DATABASE [{DBName}] SET RECURSIVE_TRIGGERS OFF GO ALTER DATABASE [{DBName}] SET DISABLE_BROKER GO ALTER DATABASE [{DBName}] SET AUTO_UPDATE_STATISTICS_ASYNC OFF GO ALTER DATABASE [{DBName}] SET DATE_CORRELATION_OPTIMIZATION OFF GO ALTER DATABASE [{DBName}] SET TRUSTWORTHY OFF GO ALTER DATABASE [{DBName}] SET ALLOW_SNAPSHOT_ISOLATION OFF GO ALTER DATABASE [{DBName}] SET PARAMETERIZATION SIMPLE GO ALTER DATABASE [{DBName}] SET READ_WRITE GO ALTER DATABASE [{DBName}] SET RECOVERY SIMPLE GO ALTER DATABASE [{DBName}] SET MULTI_USER GO ALTER DATABASE [{DBName}] SET PAGE_VERIFY CHECKSUM GO ALTER DATABASE [{DBName}] SET DB_CHAINING OFF GO USE [{DBName}] GO /****** Object: StoredProcedure [dbo].[sp_upgraddiagrams] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [sp_upgraddiagrams] AS BEGIN IF OBJECT_ID(N'dbo.sysdiagrams') IS NOT NULL return 0; CREATE TABLE dbo.sysdiagrams ( name sysname NOT NULL, principal_id int NOT NULL, -- we may change it to varbinary(85) diagram_id int PRIMARY KEY IDENTITY, version int, definition varbinary(max) CONSTRAINT UK_principal_name UNIQUE ( principal_id, name ) ); /* Add this if we need to have some form of extended properties for diagrams */ /* IF OBJECT_ID(N'dbo.sysdiagram_properties') IS NULL BEGIN CREATE TABLE dbo.sysdiagram_properties ( diagram_id int, name sysname, value varbinary(max) NOT NULL ) END */ IF OBJECT_ID(N'dbo.dtproperties') IS NOT NULL begin insert into dbo.sysdiagrams ( [name], [principal_id], [version], [definition] ) select convert(sysname, dgnm.[uvalue]), DATABASE_PRINCIPAL_ID(N'dbo'), -- will change to the sid of sa 0, -- zero for old format, dgdef.[version], dgdef.[lvalue] from dbo.[dtproperties] dgnm inner join dbo.[dtproperties] dggd on dggd.[property] = 'DtgSchemaGUID' and dggd.[objectid] = dgnm.[objectid] inner join dbo.[dtproperties] dgdef on dgdef.[property] = 'DtgSchemaDATA' and dgdef.[objectid] = dgnm.[objectid] where dgnm.[property] = 'DtgSchemaNAME' and dggd.[uvalue] like N'_EA3E6268-D998-11CE-9454-00AA00A3F36E_' return 2; end return 1; END GO /****** Object: UserDefinedFunction [dbo].[vefn_GetNewTranType] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Samples SELECT .dbo.[vefn_GetNewTranType] (1, 2, 6) SELECT .dbo.[vefn_GetNewTranType] (1, 2, 7) SELECT .dbo.[vefn_GetNewTranType] (27, 29, 10) SELECT .dbo.[vefn_GetNewTranType] (29, 27, 10) SELECT .dbo.[vefn_GetNewTranType] (27, 31, 10) --SELECT .dbo.[vefn_GetNewTranType] (29, 27, 10) */ CREATE FUNCTION [vefn_GetNewTranType] (@FormatID int, @NewFormatID int, @TranType int) RETURNS int WITH EXECUTE AS OWNER AS BEGIN -- IF @FormatID = @NewFormatID RETURN @TranType DECLARE @TransFormat varchar(max) DECLARE @NewTransFormat varchar(max) SET @TransFormat = isnull(.dbo.vefn_GetTransFormat(@FormatID, @TranType),'') SET @NewTransFormat = isnull(.dbo.vefn_GetTransFormat(@NewFormatID, @TranType),'') RETURN CASE WHEN @TransFormat = @NewTransFormat THEN @TranType WHEN @TransFormat LIKE '%{Last Step}%' THEN CASE WHEN @NewTransFormat LIKE '%{Last Step}%' THEN @TranType ELSE 3 -- This is a default 'range' type, all transition formats have it! END ELSE CASE WHEN @NewTransFormat LIKE '%{Last Step}%' THEN 0 ELSE @TranType -- This is a default 'single' type, all transition formats have it! END END END GO /****** Object: UserDefinedFunction [dbo].[vefn_GetTokens] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select * from vefn_GetTokens('abc{Header1}def{Header2}ghi') */ CREATE FUNCTION [vefn_GetTokens](@text varchar(64)) RETURNS @Tokens TABLE ( Token varchar(64) ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @index int SET @index = -1 WHILE (LEN(@text) > 0) BEGIN SET @index = CHARINDEX('{' , @text) IF @index = 0 BREAK DECLARE @index2 int SET @index2 = CHARINDEX('}' , @text) if @index2 = 0 BREAK INSERT INTO @Tokens VALUES (substring(@text, @index,1+@index2-@index)) SET @text = RIGHT(@text, (LEN(@text) - @index2)) END RETURN END GO /****** Object: UserDefinedFunction [dbo].[vefn_RemoveExtraText] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select text, .dbo.vefn_RemoveExtraText(text,2,0,0) StrippedText from Contents where ContentID=373 select text, .dbo.vefn_RemoveExtraText(text,1,0,0) StrippedText from Contents where ContentID=373 select text, .dbo.vefn_RemoveExtraText(text,0,0,0) StrippedText ,.dbo.vefn_FirstLink(text,0), PATINDEX('%[' + nchar(9516) + nchar(9574) + char(21) + ']%' , text) from Contents where ContentID=373 select .dbo.vefn_RemoveExtraText('\b Bold\b0',0,0,0) select .dbo.vefn_RemoveExtraText('\b Bold\b0',0,1,0) select .dbo.vefn_RemoveExtraText('A\u1?B\u12?C\u123?D\u1234?E',0,0,0) select .dbo.vefn_RemoveExtraText('A\u1?B\u12?C\u123?D\u1234?E',0,0,1) */ CREATE FUNCTION [vefn_RemoveExtraText](@text nvarchar(MAX),@includeLink int, @includeRtfFormatting int , @includeSpecialCharacters int) RETURNS varchar(MAX) WITH EXECUTE AS OWNER AS BEGIN DECLARE @index int DECLARE @index2 int -- Strip Links IF @includeLink = 0 -- Remove Links SET @text = [dbo].[vefn_RemoveRange](@text,'') IF @includeLink < 2 -- Remove Comments SET @text = [dbo].[vefn_RemoveRange](@text,'\v' ,'\v0') if(@includeRtfFormatting=0) -- Remove Rtf Formatting BEGIN SET @text = Replace(@text, '\b0 ', ''); SET @text = Replace(@text, '\b ', ''); SET @text = Replace(@text, '\ul0 ', ''); SET @text = Replace(@text, '\ul ', ''); SET @text = Replace(@text, '\i0 ', ''); SET @text = Replace(@text, '\i ', ''); SET @text = Replace(@text, '\super ', ''); SET @text = Replace(@text, '\sub ', ''); SET @text = Replace(@text, '\nosupersub ', ''); SET @text = Replace(@text, '\b0', ''); SET @text = Replace(@text, '\b', ''); SET @text = Replace(@text, '\ul0', ''); SET @text = Replace(@text, '\ul', ''); SET @text = Replace(@text, '\i0', ''); SET @text = Replace(@text, '\i', ''); SET @text = Replace(@text, '\super', ''); SET @text = Replace(@text, '\sub', ''); SET @text = Replace(@text, '\nosupersub', ''); END if(@includeSpecialCharacters=0) -- Remove Special Characters BEGIN SET @index = PATINDEX('%\u[0-9]?%',@text) while(@index != 0) BEGIN SET @text = substring(@text,1,@index-1) + substring(@text,@index+4,len(@text)) SET @index = PATINDEX('%\u[0-9]?%',@text) END SET @index = PATINDEX('%\u[0-9][0-9]?%',@text) while(@index != 0) BEGIN SET @text = substring(@text,1,@index-1) + substring(@text,@index+5,len(@text)) SET @index = PATINDEX('%\u[0-9][0-9]?%',@text) END SET @index = PATINDEX('%\u[0-9][0-9][0-9]?%',@text) while(@index != 0) BEGIN SET @text = substring(@text,1,@index-1) + substring(@text,@index+6,len(@text)) SET @index = PATINDEX('%\u[0-9][0-9][0-9]?%',@text) END SET @index = PATINDEX('%\u[0-9][0-9][0-9][0-9]?%',@text) while(@index != 0) BEGIN SET @text = substring(@text,1,@index-1) + substring(@text,@index+7,len(@text)) SET @index = PATINDEX('%\u[0-9][0-9][0-9][0-9]?%',@text) END SET @index = PATINDEX('%\''[0-9A-Fa-f][0-9A-Fa-f]%',@text) while(@index != 0) BEGIN SET @text = substring(@text,1,@index-1) + substring(@text,@index+4,len(@text)) SET @index = PATINDEX('%\''[0-9A-Fa-f][0-9A-Fa-f]%',@text) END END RETURN @text END GO /****** Object: UserDefinedFunction [dbo].[vefn_RemoveRange] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* SELECT ContentID, text, [dbo].[vefn_RemoveRange](text,'') StrippedText from contents where contentid in (select top 25 ContentID from contents where text like '%[[]END>%') select top 25 * from contents where text like '%[[]END>%' SELECT ContentID, [dbo].[vefn_RemoveRange](text,'') StrippedText from contents where contentid =189 */ CREATE FUNCTION [vefn_RemoveRange](@text nvarchar(MAX),@startToken nvarchar(MAX), @endToken nvarchar(MAX)) RETURNS varchar(MAX) WITH EXECUTE AS OWNER AS BEGIN DECLARE @index int DECLARE @index2 int DECLARE @lenStartToken int DECLARE @lenEndToken int SET @lenStartToken = len(@startToken) SET @lenEndToken = len(@endToken) SET @index = CHARINDEX(@startToken , @text) while (@index != 0) BEGIN SET @index2 = CHARINDEX(@endToken , @text, @index + @lenStartToken) SET @text = substring(@text,1,@index-1) + substring(@text,@index2+@lenEndToken,len(@text)) SET @index = CHARINDEX(@startToken , @text) END RETURN @text END GO /****** Object: Table [dbo].[Connections] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Connections]( [DBID] [int] IDENTITY(1,1) NOT NULL, [Name] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [Title] [nvarchar](510) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [ConnectionString] [nvarchar](510) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [ServerType] [int] NOT NULL CONSTRAINT [DF_Connections_ServerType] DEFAULT ((1)), [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Connections_DTS] DEFAULT (getdate()), [UsrID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Connections_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Connections] PRIMARY KEY CLUSTERED ( [DBID] 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 CREATE UNIQUE NONCLUSTERED INDEX [IX_Connections] ON [Connections] ( [Name] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'0 SQL Server' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Connections', @level2type=N'COLUMN',@level2name=N'ServerType' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Connections', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: UserDefinedFunction [dbo].[vefn_SplitInt] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO --select * from DocVersions where VersionID in(select * from vefn_SplitInt('1,2,4',',')) --select Type, Count(*) from Contents where Type in(select * from vefn_SplitInt('20001,20002,20004',',')) group by Type CREATE FUNCTION [vefn_SplitInt](@text varchar(MAX), @delimiter varchar(20) = ',') RETURNS @IDs TABLE ( ID int PRIMARY KEY ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @index int SET @index = -1 WHILE (LEN(@text) > 0) BEGIN SET @index = CHARINDEX(@delimiter , @text) IF (@index = 0) AND (LEN(@text) > 0) BEGIN INSERT INTO @IDs VALUES (CAST(@text AS INT )) BREAK END IF (@index > 1) BEGIN INSERT INTO @IDs VALUES (CAST(LEFT(@text, @index - 1) AS INT)) SET @text = RIGHT(@text, (LEN(@text) - @index)) END ELSE SET @text = RIGHT(@text, (LEN(@text) - @index)) END RETURN END GO /****** Object: UserDefinedFunction [dbo].[vefn_XmlPath] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE FUNCTION [vefn_XmlPath] (@xml XML) RETURNS varchar(255) WITH EXECUTE AS OWNER AS BEGIN return case when @xml.exist('*[1]') is null THEN '' ELSE @xml.value('local-name(*[1])','varchar(max)') + coalesce('[' + @xml.value('*[1]/@Type','varchar(255)')+']','[' + @xml.value('*[1]/@Index','varchar(255)')+']','') + '/' END END; GO /****** Object: Table [dbo].[RODbs] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [RODbs]( [RODbID] [int] IDENTITY(1,1) NOT NULL, [ROName] [nvarchar](255) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [FolderPath] [nvarchar](255) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [DBConnectionString] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_RODbs_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_RODbs_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_RODbs] PRIMARY KEY CLUSTERED ( [RODbID] 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 CREATE UNIQUE NONCLUSTERED INDEX [IX_RODbs_FolderPath] ON [RODbs] ( [FolderPath] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'Hook for future - to allow the user to select multiple RO Databases assocaiated with on DocVersion' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'RODbs', @level2type=N'COLUMN',@level2name=N'ROName' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'Path to the RO database' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'RODbs', @level2type=N'COLUMN',@level2name=N'FolderPath' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'Connection String - Default could just be the full path and name of the database' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'RODbs', @level2type=N'COLUMN',@level2name=N'DBConnectionString' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'RODbs', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[Locks] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Locks]( [LockID] [int] IDENTITY(1,1) NOT NULL, [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Locks_UserID] DEFAULT (upper(suser_sname())), [LockType] [tinyint] NOT NULL CONSTRAINT [DF_Locks_LockType] DEFAULT ((0)), [LockItemID] [int] NOT NULL CONSTRAINT [DF_Locks_LockItemID] DEFAULT ((0)), [Description] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Locks_DTS] DEFAULT (getdate()), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Locks] PRIMARY KEY CLUSTERED ( [LockID] 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 EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Locks', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[Documents] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO SET ANSI_PADDING ON GO CREATE TABLE [Documents]( [DocID] [int] IDENTITY(1,1) NOT NULL, [LibTitle] [nvarchar](1024) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DocContent] [varbinary](max) NULL, [DocAscii] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Documents_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Documents_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, [FileExtension] [nvarchar](10) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Documents_FileExtension] DEFAULT (N'.Doc'), CONSTRAINT [PK_Documents] PRIMARY KEY CLUSTERED ( [DocID] 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 SET ANSI_PADDING OFF GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'Actual content of a Word Document (RTF, DOC or XML Format)' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Documents', @level2type=N'COLUMN',@level2name=N'DocContent' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'Used for searching' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Documents', @level2type=N'COLUMN',@level2name=N'DocAscii' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Documents', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: StoredProcedure [dbo].[vesp_ListTables] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO create procedure [vesp_ListTables] WITH EXECUTE AS OWNER AS begin select o.name TableName,c.name ColumnName, case c.xtype when 56 then 'int' when 231 then 'nvarchar(' + case c.length when -1 then 'Max' else cast(c.length/2 as varchar(10)) end + ')' when 165 then 'varbinary(' + case c.length when -1 then 'Max' else cast(c.length as varchar(10)) end + ')' when 239 then 'nchar(' + case c.length when -1 then 'Max' else cast(c.length/2 as varchar(10)) end + ')' when 175 then 'char(' + case c.length when -1 then 'Max' else cast(c.length as varchar(10)) end + ')' when 61 then 'datetime' when 104 then 'bit' when 48 then 'TinyInt' when 189 then 'timestamp' else '???' + cast(c.xtype as varchar(10)) end ItemType, case when c.isnullable=1 then 'Yes' else '' end AllowNulls, case when c.colstat=1 then 'Identity' else dc.definition end DefaultValue from sysobjects o join syscolumns c on o.id=c.id left join sysconstraints cn on o.id=cn.id and c.colid=cn.colid left join sys.default_constraints dc on dc.object_id = cn.constid where o.xtype='U' order by o.name,c.colid end GO /****** Object: StoredProcedure [dbo].[vesp_ListTables2] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO create procedure [vesp_ListTables2] WITH EXECUTE AS OWNER AS begin select o.name TableName,c.name ColumnName, case c.xtype when 56 then 'int' when 231 then 'nvarchar' when 165 then 'varbinary' when 239 then 'nchar' when 175 then 'char' when 61 then 'datetime' when 104 then 'bit' when 48 then 'TinyInt' when 189 then 'timestamp' else '???' + cast(c.xtype as varchar(10)) end ItemType, case c.xtype when 56 then '0' when 231 then case c.length when -1 then 'Max' else cast(c.length/2 as varchar(10)) end when 165 then case c.length when -1 then 'Max' else cast(c.length/2 as varchar(10)) end when 239 then case c.length when -1 then 'Max' else cast(c.length/2 as varchar(10)) end when 175 then case c.length when -1 then 'Max' else cast(c.length/2 as varchar(10)) end when 61 then '0' when 104 then '0' when 48 then '0' when 189 then '0' else '0' end ItemSize, case when c.isnullable=1 then 'Yes' else '' end AllowNulls, case when c.colstat=1 then 'Identity' else dc.definition end DefaultValue from sysobjects o join syscolumns c on o.id=c.id left join sysconstraints cn on o.id=cn.id and c.colid=cn.colid left join sys.default_constraints dc on dc.object_id = cn.constid where o.xtype='U' order by o.name,c.colid end GO /****** Object: StoredProcedure [dbo].[vesp_ListTables3] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE procedure [vesp_ListTables3] WITH EXECUTE AS OWNER AS begin select o.name TableName,c.name ColumnName, case c.system_type_id when 56 then 'int' when 231 then 'nvarchar' when 165 then 'varbinary' when 167 then 'varchar' when 239 then 'nchar' when 175 then 'char' when 61 then 'datetime' when 104 then 'bit' when 48 then 'TinyInt' when 189 then 'timestamp' else '???' + cast(c.system_type_id as varchar(10)) end ItemType, case c.system_type_id when 56 then '0' when 231 then case c.max_length when -1 then 'Max' else cast(c.max_length/2 as varchar(10)) end when 165 then case c.max_length when -1 then 'Max' else cast(c.max_length as varchar(10)) end when 167 then case c.max_length when -1 then 'Max' else cast(c.max_length as varchar(10)) end when 239 then case c.max_length when -1 then 'Max' else cast(c.max_length/2 as varchar(10)) end when 175 then case c.max_length when -1 then 'Max' else cast(c.max_length as varchar(10)) end when 61 then '0' when 104 then '0' when 48 then '0' when 189 then '0' else '0' end ItemSize, case when c.is_nullable=1 then 'Yes' else '' end AllowNulls, case when c.is_identity=1 then 'Identity' else dc.definition end DefaultValue, x.value Description from sys.objects o join sys.columns c on o.object_id=c.object_id left join sysconstraints cn on o.object_id=cn.id and c.column_id=cn.colid left join sys.default_constraints dc on dc.object_id = cn.constid left join sys.extended_properties x on x.major_id = o.OBJECT_ID AND x.minor_id=c.column_id AND x.Name='MS_Description' where o.type='U' order by o.name,c.column_id end GO /****** Object: Table [dbo].[Groups] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Groups]( [GID] [int] IDENTITY(1,1) NOT NULL, [GroupName] [nvarchar](50) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [GroupType] [int] NULL, [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Groups_DTS] DEFAULT (getdate()), [UsrID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Groups_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Groups] PRIMARY KEY CLUSTERED ( [GID] 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 CREATE UNIQUE NONCLUSTERED INDEX [IX_Groups] ON [Groups] ( [GroupName] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Groups', @level2type=N'COLUMN',@level2name=N'GID' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Groups', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: StoredProcedure [dbo].[vlnErrorHandler] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [vlnErrorHandler] (@ExpectedCount int=-1 ,@MessageFormat nvarchar(512)=N'Expected RowCount (%d) not met (%d)') WITH EXECUTE AS OWNER AS BEGIN DECLARE @ErrorMessage NVARCHAR(4000), @ErrorNumber INT, @ErrorSeverity INT, @ErrorState INT, @ErrorProcedure NVARCHAR(126) , @ErrorLine INT, @RowCount INT; SELECT @ErrorMessage = ERROR_MESSAGE(), @ErrorSeverity = ERROR_SEVERITY(), @ErrorState = ERROR_STATE(),@ErrorNumber = ERROR_NUMBER() , @ErrorLine = ERROR_LINE(), @ErrorProcedure = ERROR_PROCEDURE(), @RowCount = @@RowCount; IF @ErrorNumber > 0 BEGIN IF @ErrorProcedure = OBJECT_NAME(@@PROCID) -- If the Procedure is the current procedure just pass the error message RAISERROR (@ErrorMessage, @ErrorSeverity, @ErrorState) ELSE -- Add in the procedure name and line as well as the error number RAISERROR (N'%s[%d] - (%d) %s', @ErrorSeverity, @ErrorState, @ErrorProcedure, @ErrorLine, @ErrorNumber, @ErrorMessage) END ELSE IF @ExpectedCount <> -1 AND @ExpectedCount <> @RowCount RAISERROR (@MessageFormat, 16, 1, @ExpectedCount, @RowCount) END GO /****** Object: Table [dbo].[Users] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Users]( [UID] [int] IDENTITY(1,1) NOT NULL, [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Users_UserID] DEFAULT (upper(suser_sname())), [FirstName] [nvarchar](50) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [MiddleName] [nvarchar](50) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [LastName] [nvarchar](50) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [Suffix] [nvarchar](10) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [CourtesyTitle] [nvarchar](10) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [PhoneNumber] [nvarchar](30) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [CFGName] [nvarchar](8) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [UserLogin] [nvarchar](10) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [UserName] [nvarchar](32) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Users_DTS] DEFAULT (getdate()), [UsrID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Users_UserID1] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Users] PRIMARY KEY CLUSTERED ( [UID] 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 EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Users', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[Formats] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Formats]( [FormatID] [int] IDENTITY(1,1) NOT NULL, [ParentID] [int] NOT NULL CONSTRAINT [DF_Formats_ParentID] DEFAULT ((1)), [Name] [nvarchar](20) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [Description] [nvarchar](250) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [Data] [xml] NOT NULL, [GenMac] [xml] NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Formats_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Formats_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Formats] PRIMARY KEY CLUSTERED ( [FormatID] 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 CREATE UNIQUE NONCLUSTERED INDEX [IX_Formats] ON [Formats] ( [ParentID] ASC, [Name] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO CREATE NONCLUSTERED INDEX [IX_FormatsParentID] ON [Formats] ( [ParentID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Formats', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[Sessions] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Sessions]( [SessionID] [int] IDENTITY(1,1) NOT NULL, [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Sessions_UserID] DEFAULT (upper(suser_sname())), [DTSDtart] [datetime] NOT NULL CONSTRAINT [DF_Sessions_DTSDtart] DEFAULT (getdate()), [DTSEnd] [datetime] NULL, [DTSActivity] [datetime] NULL, [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Sessions] PRIMARY KEY CLUSTERED ( [SessionID] 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 EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Sessions', @level2type=N'COLUMN',@level2name=N'DTSDtart' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Sessions', @level2type=N'COLUMN',@level2name=N'DTSEnd' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Sessions', @level2type=N'COLUMN',@level2name=N'DTSActivity' GO /****** Object: UserDefinedFunction [dbo].[ve_GetShortPart] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO Create FUNCTION [ve_GetShortPart] (@Number varchar(max),@Title varchar(max)) RETURNS varchar(max) WITH EXECUTE AS OWNER AS BEGIN if(isnull(@Number,'') = '') return @Title return @Number END GO /****** Object: Table [dbo].[Branches] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Branches]( [BranchID] [int] IDENTITY(1,1) NOT NULL, [VersionID] [int] NOT NULL CONSTRAINT [DF_Branches_VersionID] DEFAULT ((0)), [DateLimit] [datetime] NOT NULL CONSTRAINT [DF_Branches_DateLimit] DEFAULT (getdate()), [BeforeType] [tinyint] NOT NULL CONSTRAINT [DF_Branches_BeforeType] DEFAULT ((0)), [BeforeID] [int] NOT NULL CONSTRAINT [DF_Branches_BeforeID] DEFAULT ((0)), [AfterType] [tinyint] NOT NULL CONSTRAINT [DF_Branches_AfterType] DEFAULT ((0)), [AfterID] [int] NOT NULL CONSTRAINT [DF_Branches_AfterID] DEFAULT ((0)), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Branches] PRIMARY KEY CLUSTERED ( [BranchID] 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 EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Branches', @level2type=N'COLUMN',@level2name=N'DateLimit' GO /****** Object: Table [dbo].[AnnotationTypes] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [AnnotationTypes]( [TypeID] [int] IDENTITY(1,1) NOT NULL, [Name] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_AnnotationTypes_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_AnnotationTypes_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_AnnotationTypes] PRIMARY KEY CLUSTERED ( [TypeID] 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 CREATE UNIQUE NONCLUSTERED INDEX [IX_AnnotationTypes_Name] ON [AnnotationTypes] ( [Name] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'AnnotationTypes', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: UserDefinedFunction [dbo].[vefn_AllSections] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- Select .dbo.vefn_AllSections(10001) MyTypeSection, .dbo.vlnfn_AllSections(20001) MyTypeStep, .dbo.vlnfn_AllSections(5) MyTypeProc CREATE FUNCTION [vefn_AllSections](@type int) RETURNS int WITH EXECUTE AS OWNER AS BEGIN IF(@type < 20000 and @type >= 10000) RETURN 10000 RETURN @type END GO /****** Object: Table [dbo].[Owners] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Owners]( [OwnerID] [int] IDENTITY(1,1) NOT NULL, [SessionID] [int] NOT NULL CONSTRAINT [DF_Owners_SessionID] DEFAULT ((0)), [OwnerType] [tinyint] NOT NULL CONSTRAINT [DF_Owners_OwnerType] DEFAULT ((0)), [OwnerItemID] [int] NOT NULL CONSTRAINT [DF_Owners_OwnerItemID] DEFAULT ((0)), [DTSStart] [datetime] NOT NULL CONSTRAINT [DF_Owners_DTSStart] DEFAULT (getdate()), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Owners] PRIMARY KEY CLUSTERED ( [OwnerID] 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 EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Owners', @level2type=N'COLUMN',@level2name=N'DTSStart' GO /****** Object: UserDefinedFunction [dbo].[vefn_CompareTranFormat] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Determines if two transition formats are same string. returns 0 if identical, 1 if similar (range for range, item for item), 2 if totally different */ CREATE FUNCTION [vefn_CompareTranFormat] (@FormatID int, @NewFormatID int, @TranType int) RETURNS int WITH EXECUTE AS OWNER AS BEGIN -- IF @FormatID = @NewFormatID RETURN 0 -- Exactly the same format file DECLARE @TransFormat varchar(max) DECLARE @NewTransFormat varchar(max) SET @TransFormat = isnull(.dbo.vefn_GetTransFormat(@FormatID, @TranType),'') SET @NewTransFormat = isnull(.dbo.vefn_GetTransFormat(@NewFormatID, @TranType),'') RETURN CASE WHEN @TransFormat = @NewTransFormat THEN 0 -- transition formats are identical WHEN @TransFormat LIKE '%{Last Step}%' THEN CASE WHEN @NewTransFormat LIKE '%{Last Step}%' THEN 1 -- both ranges, but different format ELSE 2 -- totally different format, not even same type (was single, changed to range) END ELSE CASE WHEN @NewTransFormat LIKE '%{Last Step}%' THEN 2 -- totally different format, not even same type (was range, changed to single) ELSE 1 -- both single, but different format END END END GO /****** Object: Table [dbo].[Applicabilities] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Applicabilities]( [AppID] [int] IDENTITY(1,1) NOT NULL, [Name] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [Title] [nvarchar](510) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Applicabilities_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Applicabilities_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Applicabilities] PRIMARY KEY CLUSTERED ( [AppID] 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 EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Applicabilities', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: UserDefinedFunction [dbo].[vefn_FirstLink] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select .dbo.vefn_FirstLink('asdasdadsasd' + char(21) + 'asdasdasd\vasdasdasd', 2) select .dbo.vefn_FirstLink('asdasdadsasd' + char(21) + 'asdasdasd\vasdasdasd', 1) select .dbo.vefn_FirstLink('asdasdadsasd' + char(21) + 'asdasdasd\vasdasdasd', 0) */ -- This is only used for testing by vefn_RemoveExtraText CREATE FUNCTION [vefn_FirstLink](@text nvarchar(MAX),@includeLink int) RETURNS int WITH EXECUTE AS OWNER AS BEGIN DECLARE @index int SET @index = 0 if(@includeLink = 2) RETURN 0 if(@includeLink = 1) return CHARINDEX('\v' , @text) DECLARE @index2 int SET @index = PATINDEX('%[' + nchar(9574)+nchar(9516)+nchar(21) + ']%',@text) return @index END GO /****** Object: Table [dbo].[ApplicableStructures] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [ApplicableStructures]( [StructureID] [int] NOT NULL, [AppItems] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_ApplicableStructures_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_ApplicableStructures_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_ApplicableStructures] PRIMARY KEY CLUSTERED ( [StructureID] 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 EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'A series of characters - Y means Applicable, N means Not Applicable, Space means undecided' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'ApplicableStructures', @level2type=N'COLUMN',@level2name=N'AppItems' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'ApplicableStructures', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: UserDefinedFunction [dbo].[vefn_FixROData] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO Create FUNCTION [vefn_FixROData] (@data XML,@ROUsageID int,@NewROUsageID int) RETURNS XML WITH EXECUTE AS OWNER AS BEGIN -- Build Search String and Replace String DECLARE @lookFor varchar(MAX) DECLARE @replaceWith varchar(MAX) SET @lookFor = '#Link:ReferencedObject:' + ltrim(str(@ROUsageID)) + ' ' SET @replaceWith = '#Link:ReferencedObject:' + ltrim(str(@NewROUsageID)) + ' ' return CAST(replace(CAST(@data AS VarChar(max)),@lookFor,@replaceWith) AS XML) END GO /****** Object: UserDefinedFunction [dbo].[vefn_FixROText] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE FUNCTION [vefn_FixROText] (@Text varchar(MAX),@ROUsageID int,@NewROUsageID int) RETURNS varchar(MAX) WITH EXECUTE AS OWNER AS BEGIN -- Build Search String and Replace String DECLARE @lookFor varchar(MAX) DECLARE @replaceWith varchar(MAX) SET @lookFor = '#Link:ReferencedObject:' + ltrim(str(@ROUsageID)) + ' ' SET @replaceWith = '#Link:ReferencedObject:' + ltrim(str(@NewROUsageID)) + ' ' return replace(@text,@lookFor,@replaceWith) END GO /****** Object: UserDefinedFunction [dbo].[vefn_FixSearchString] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select ID,ss,.dbo.vefn_FixSearchString(ss) from ( select 1 ID,'*' ss union select 2 ID,'50%' ss union select 3 ID,'IF*' ss union select 4 ID,'*then:' ss union select 5 ID,'530`F' ss union select 6 ID,'check' ss union select 7 ID,'RCP*Cooling' ss union select 8 ID,'14%[34%]' ss union select 9 ID,'\*' ss union select 10 ID,'\?' ss union select 11 ID,'_' ss union select 12 ID,'[' ss union select 13 ID,']' ss union select 14 ID,'%' ss union select 15 ID,'_' ss union select 16 ID,'-' ss ) tt order by ID */ CREATE FUNCTION [vefn_FixSearchString](@SearchString nvarchar(MAX)) RETURNS nvarchar(MAX) WITH EXECUTE AS OWNER AS BEGIN -- This code adds % at the beginning and end if the beginning and end -- of the search string if it does not have % at the beginning or end Set @SearchString = replace(@SearchString,'[','[[]') Set @SearchString = replace(@SearchString,'_','[_]') Set @SearchString = replace(@SearchString,'%','[%]') Set @SearchString = replace(@SearchString,'*','%') Set @SearchString = replace(@SearchString,'?','_') Set @SearchString = replace(@SearchString,'\%','*') Set @SearchString = replace(@SearchString,'\_','?') --Set @SearchString = replace(@SearchString,'-','[-'+nchar(8209)+']') IF(@SearchString like '[%]%') RETURN @SearchString IF(@SearchString like '%[%]') RETURN @SearchString RETURN '%' + @SearchString + '%' END GO /****** Object: UserDefinedFunction [dbo].[vefn_FixTransitionDataForCopy] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE FUNCTION [vefn_FixTransitionDataForCopy] (@data XML,@TransitionID int,@TranType int,@OldToID int,@OldRangeID int, @NewID int, @NewToID int, @NewRangeID int, @NewTranType int) RETURNS XML WITH EXECUTE AS OWNER AS BEGIN -- Build Search String and Replace String DECLARE @offset int DECLARE @lookFor varchar(MAX) DECLARE @replaceWith varchar(MAX) DECLARE @text varchar(MAX) SET @text = Cast(@data as varchar(max)) SET @lookFor = '#Link:Transition:' + ltrim(str(@TranType)) + ' ' + ltrim(str(@TransitionID)) SET @offset = CHARINDEX(@lookFor,@text) if(@offset = 0) BEGIN SET @lookFor = '#Link:TransitionRange:' + ltrim(str(@TranType)) + ' ' + ltrim(str(@TransitionID)) SET @offset = CHARINDEX(@lookFor,@text) SET @replaceWith = '#Link:TransitionRange:' + ltrim(str(@NewTranType)) + ' ' + ltrim(str(@NewID)) + ' ' + ltrim(str(@NewToID)) + ' ' + ltrim(str(@NewRangeID)) SET @lookFor = @lookFor + ' ' + ltrim(str(@OldToID)) + ' ' + ltrim(str(@OldRangeID)) END ELSE BEGIN SET @replaceWith = '#Link:Transition:' + ltrim(str(@NewTranType)) + ' ' + ltrim(str(@NewID)) + ' ' + ltrim(str(@NewToID)) SET @lookFor = @lookFor + ' ' + ltrim(str(@OldToID)) END return Cast(replace(@text,@lookFor,@replaceWith) as XML) END GO /****** Object: UserDefinedFunction [dbo].[vefn_FixTransitionText] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select top 5 * from contents order by contentid desc DECLARE @Text1 varchar(MAX),@Text2 varchar(MAX),@Text3 varchar(MAX),@Text4 varchar(MAX) SET @Text1='\v \v0 PERFORM the following:' SET @Text2='\v \v0 PERFORM the following:' SET @Text3='\v \v0 PERFORM the following:' SET @Text4='\v \v0 IF reactor will NOT trip, THEN:' Select @Text1 Before, dbo.vefn_FixTransitionText(@Text1,58,4,270,285,270,999) [After] Union Select @Text2 Before, dbo.vefn_FixTransitionText(@Text2,58,2,265,270,270,999) [After] Union Select @Text3 Before, dbo.vefn_FixTransitionText(@Text3,58,2,270,270,270,999) [After] Union Select @Text4 Before, dbo.vefn_FixTransitionText(@Text4,8,1,270,270,270,999) [After] */ CREATE FUNCTION [vefn_FixTransitionText] (@Text varchar(MAX),@TransitionID int,@TranType int,@OldToID int,@OldRangeID int,@OldID int,@NewID int) RETURNS varchar(MAX) WITH EXECUTE AS OWNER AS BEGIN -- Build Search String and Replace String DECLARE @offset int DECLARE @lookFor varchar(MAX) DECLARE @replaceWith varchar(MAX) SET @lookFor = '#Link:Transition:' + ltrim(str(@TranType)) + ' ' + ltrim(str(@TransitionID)) SET @offset = CHARINDEX(@lookFor,@Text) if(@offset = 0) BEGIN SET @lookFor = '#Link:TransitionRange:' + ltrim(str(@TranType)) + ' ' + ltrim(str(@TransitionID)) SET @offset = CHARINDEX(@lookFor,@Text) SET @replaceWith = @lookFor + ' ' + ltrim(str(case @OldToID when @OldID then @NewID else @OldToID end)) + ' ' + ltrim(str(case @OldRangeID when @OldID then @NewID else @OldRangeID end)) SET @lookFor = @lookFor + ' ' + ltrim(str(@OldToID)) + ' ' + ltrim(str(@OldRangeID)) END ELSE BEGIN SET @replaceWith = @lookFor + ' ' + ltrim(str(case @OldToID when @OldID then @NewID else @OldToID end)) SET @lookFor = @lookFor + ' ' + ltrim(str(@OldToID)) END return replace(@text,@lookFor,@replaceWith) END GO /****** Object: UserDefinedFunction [dbo].[vefn_FixTransitionTextForCopy] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE FUNCTION [vefn_FixTransitionTextForCopy] (@Text varchar(MAX),@TransitionID int,@TranType int,@OldToID int,@OldRangeID int, @NewID int, @NewToID int, @NewRangeID int, @NewTranType int) RETURNS varchar(MAX) WITH EXECUTE AS OWNER AS BEGIN -- Build Search String and Replace String DECLARE @offset int DECLARE @lookFor varchar(MAX) DECLARE @replaceWith varchar(MAX) SET @lookFor = '#Link:Transition:' + ltrim(str(@TranType)) + ' ' + ltrim(str(@TransitionID)) SET @offset = CHARINDEX(@lookFor,@Text) if(@offset = 0) BEGIN SET @lookFor = '#Link:TransitionRange:' + ltrim(str(@TranType)) + ' ' + ltrim(str(@TransitionID)) SET @offset = CHARINDEX(@lookFor,@Text) SET @replaceWith = '#Link:TransitionRange:' + ltrim(str(@NewTranType)) + ' ' + ltrim(str(@NewID)) + ' ' + ltrim(str(@NewToID)) + ' ' + ltrim(str(@NewRangeID)) SET @lookFor = @lookFor + ' ' + ltrim(str(@OldToID)) + ' ' + ltrim(str(@OldRangeID)) END ELSE BEGIN SET @replaceWith = '#Link:Transition:' + ltrim(str(@NewTranType)) + ' ' + ltrim(str(@NewID)) + ' ' + ltrim(str(@NewToID)) SET @lookFor = @lookFor + ' ' + ltrim(str(@OldToID)) END return replace(@text,@lookFor,@replaceWith) END GO /****** Object: Table [dbo].[Roles] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Roles]( [RID] [int] IDENTITY(1,1) NOT NULL, [Name] [nvarchar](50) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [Title] [nvarchar](250) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Roles_DTS] DEFAULT (getdate()), [UsrID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Roles_UsrID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Roles] PRIMARY KEY CLUSTERED ( [RID] 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 CREATE UNIQUE NONCLUSTERED INDEX [IX_Roles] ON [Roles] ( [Name] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Roles', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[Associations] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Associations]( [AssociationID] [int] IDENTITY(1,1) NOT NULL, [VersionID] [int] NOT NULL, [ROFstID] [int] NOT NULL, [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Associations_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Associations_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Associations_1] PRIMARY KEY CLUSTERED ( [AssociationID] 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 CREATE UNIQUE NONCLUSTERED INDEX [IX_Associations_VersionID_ROFstID] ON [Associations] ( [VersionID] ASC, [ROFstID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Associations', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[Folders] Script Date: 01/06/2012 15:02:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Folders]( [FolderID] [int] IDENTITY(1,1) NOT NULL, [ParentID] [int] NOT NULL CONSTRAINT [DF_Folders_ParentID] DEFAULT ((1)), [DBID] [int] NOT NULL CONSTRAINT [DF_DataSets_DBID] DEFAULT ((1)), [Name] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [Title] [nvarchar](510) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [ShortName] [nvarchar](20) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [FormatID] [int] NULL, [ManualOrder] [float] NULL, [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_DataSets_DTS] DEFAULT (getdate()), [UsrID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_DataSets_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_DataSets] PRIMARY KEY CLUSTERED ( [FolderID] 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 CREATE NONCLUSTERED INDEX [IX_FoldersDBID] ON [Folders] ( [DBID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO CREATE NONCLUSTERED INDEX [IX_FoldersFormatID] ON [Folders] ( [FormatID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO CREATE NONCLUSTERED INDEX [IX_FoldersParentID] ON [Folders] ( [ParentID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO CREATE UNIQUE NONCLUSTERED INDEX [IX_UniqueChildFolders] ON [Folders] ( [ParentID] ASC, [Name] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Folders', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[DROUsages] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [DROUsages]( [DROUsageID] [int] IDENTITY(1,1) NOT NULL, [DocID] [int] NOT NULL CONSTRAINT [DF_Table_1_ContentID] DEFAULT ((0)), [ROID] [nvarchar](16) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_DROUsages_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_DROUsages_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, [RODbID] [int] NOT NULL, CONSTRAINT [PK_DROUsages] PRIMARY KEY CLUSTERED ( [DROUsageID] 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 EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'DROUsages', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[ROImages] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO SET ANSI_PADDING ON GO CREATE TABLE [ROImages]( [ImageID] [int] IDENTITY(1,1) NOT NULL, [RODbID] [int] NOT NULL, [FileName] [nvarchar](255) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [Content] [varbinary](max) NOT NULL, [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_ROImages_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_ROImages_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_ROImages] PRIMARY KEY CLUSTERED ( [ImageID] 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 SET ANSI_PADDING OFF GO CREATE UNIQUE NONCLUSTERED INDEX [IX_ROImages_RODbID_FileName_DTS] ON [ROImages] ( [RODbID] ASC, [FileName] ASC, [DTS] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'ROImages', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[ROFsts] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO SET ANSI_PADDING ON GO CREATE TABLE [ROFsts]( [ROFstID] [int] IDENTITY(1,1) NOT NULL, [RODbID] [int] NOT NULL, [ROLookup] [varbinary](max) NOT NULL, [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Table_1_DTS1] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_ROFsts_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_ROFsts] PRIMARY KEY CLUSTERED ( [ROFstID] 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 SET ANSI_PADDING OFF GO CREATE UNIQUE NONCLUSTERED INDEX [IX_ROFsts] ON [ROFsts] ( [RODbID] ASC, [DTS] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'ROFsts', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[RoUsages] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [RoUsages]( [ROUsageID] [int] IDENTITY(1,1) NOT NULL, [ContentID] [int] NOT NULL CONSTRAINT [DF_RoUsages_StructureID] DEFAULT ((0)), [ROID] [nvarchar](16) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_RoUsages_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_RoUsages_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, [RODbID] [int] NOT NULL, CONSTRAINT [PK_RoUsages] PRIMARY KEY CLUSTERED ( [ROUsageID] 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 CREATE NONCLUSTERED INDEX [IX_RoUsagesContentID] ON [RoUsages] ( [ContentID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'RoUsages', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[Figures] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Figures]( [FigureID] [int] IDENTITY(1,1) NOT NULL, [ROFstID] [int] NOT NULL, [ImageID] [int] NOT NULL, [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Figures_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Figures_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Figures_1] PRIMARY KEY CLUSTERED ( [FigureID] 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 CREATE UNIQUE NONCLUSTERED INDEX [IX_Figures_ROFstID_ImageID] ON [Figures] ( [ROFstID] ASC, [ImageID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Figures', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[Entries] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Entries]( [ContentID] [int] NOT NULL, [DocID] [int] NOT NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Entries_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Entries_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Entries] PRIMARY KEY CLUSTERED ( [ContentID] 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 CREATE NONCLUSTERED INDEX [IX_EntriesDocID] ON [Entries] ( [DocID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Entries', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[Pdfs] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO SET ANSI_PADDING ON GO CREATE TABLE [Pdfs]( [DocID] [int] NOT NULL, [DebugStatus] [int] NOT NULL, [TopRow] [int] NOT NULL, [PageLength] [int] NOT NULL, [LeftMargin] [int] NOT NULL, [PageWidth] [int] NOT NULL, [PageCount] [float] NOT NULL, [DocPdf] [varbinary](max) NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Pdfs_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Pdfs_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Pdfs] PRIMARY KEY CLUSTERED ( [DocID] ASC, [DebugStatus] ASC, [TopRow] ASC, [PageLength] ASC, [LeftMargin] ASC, [PageWidth] 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 SET ANSI_PADDING OFF GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'> 0 for Debug' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Pdfs', @level2type=N'COLUMN',@level2name=N'DebugStatus' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'Count of whole and partial pages' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Pdfs', @level2type=N'COLUMN',@level2name=N'PageCount' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Pdfs', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[Memberships] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Memberships]( [UGID] [int] IDENTITY(1,1) NOT NULL, [UID] [int] NOT NULL, [GID] [int] NOT NULL, [StartDate] [datetime] NOT NULL CONSTRAINT [DF_UserGroups_StartDate] DEFAULT (getdate()), [EndDate] [datetime] NULL, [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Memberships_DTS] DEFAULT (getdate()), [UsrID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Memberships_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_UserGroups] PRIMARY KEY CLUSTERED ( [UGID] 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 CREATE NONCLUSTERED INDEX [IX_MembershipsGID] ON [Memberships] ( [GID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO CREATE NONCLUSTERED INDEX [IX_MembershipsUID] ON [Memberships] ( [UID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Memberships', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[Assignments] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Assignments]( [AID] [int] IDENTITY(1,1) NOT NULL, [GID] [int] NOT NULL, [RID] [int] NOT NULL, [FolderID] [int] NOT NULL, [StartDate] [datetime] NOT NULL CONSTRAINT [DF_Assignments_StartDate] DEFAULT (getdate()), [EndDate] [datetime] NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Assignments_DTS] DEFAULT (getdate()), [UsrID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Assignments_UsrID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Assignments] PRIMARY KEY CLUSTERED ( [AID] 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 CREATE NONCLUSTERED INDEX [IX_AssignmentsFolderID] ON [Assignments] ( [FolderID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO CREATE NONCLUSTERED INDEX [IX_AssignmentsGID] ON [Assignments] ( [GID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO CREATE NONCLUSTERED INDEX [IX_AssignmentsRID] ON [Assignments] ( [RID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Assignments', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[Parts] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Parts]( [ContentID] [int] NOT NULL, [FromType] [int] NOT NULL, [ItemID] [int] NOT NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Parts_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Parts_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Parts] PRIMARY KEY CLUSTERED ( [ContentID] ASC, [FromType] 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 CREATE NONCLUSTERED INDEX [IX_PartsItemID] ON [Parts] ( [ItemID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Parts', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[DocVersions] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [DocVersions]( [VersionID] [int] IDENTITY(1,1) NOT NULL, [FolderID] [int] NOT NULL, [VersionType] [int] NOT NULL CONSTRAINT [DF_Versions_VersionType] DEFAULT ((0)), [Name] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [Title] [nvarchar](510) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [ItemID] [int] NULL, [FormatID] [int] NULL, [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Versions_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Versions_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Versions] PRIMARY KEY CLUSTERED ( [VersionID] 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 CREATE NONCLUSTERED INDEX [IX_DocVersionsFolderID] ON [DocVersions] ( [FolderID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO CREATE NONCLUSTERED INDEX [IX_DocVersionsFormatID] ON [DocVersions] ( [FormatID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO CREATE NONCLUSTERED INDEX [IX_DocVersionsItemID] ON [DocVersions] ( [ItemID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'0 Working Draft, 1 Temporary, 128 Revision, 129 Approved (Greater than 127 - non editable)' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'DocVersions', @level2type=N'COLUMN',@level2name=N'VersionType' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'DocVersions', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[Transitions] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Transitions]( [TransitionID] [int] IDENTITY(1,1) NOT NULL, [FromID] [int] NOT NULL, [ToID] [int] NOT NULL, [RangeID] [int] NOT NULL, [IsRange] [int] NOT NULL CONSTRAINT [DF_Transitions_IsRange] DEFAULT ((0)), [TranType] [int] NOT NULL CONSTRAINT [DF_Transitions_TranType] DEFAULT ((0)), [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Transitions_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Transitions_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_TranUsages] PRIMARY KEY CLUSTERED ( [TransitionID] 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 CREATE NONCLUSTERED INDEX [IX_TransitionsFromID] ON [Transitions] ( [FromID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO CREATE NONCLUSTERED INDEX [IX_TransitionsRangeID] ON [Transitions] ( [RangeID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO CREATE NONCLUSTERED INDEX [IX_TransitionsToID] ON [Transitions] ( [ToID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'StructureID' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Transitions', @level2type=N'COLUMN',@level2name=N'ToID' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'0 - Not a Range Transition, 1 - Range Transition, 2 - Range Transition - Extends to last Sibling' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Transitions', @level2type=N'COLUMN',@level2name=N'IsRange' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Transitions', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[Annotations] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Annotations]( [AnnotationID] [int] IDENTITY(1,1) NOT NULL, [ItemID] [int] NOT NULL, [TypeID] [int] NOT NULL, [RtfText] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [SearchText] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Annotations_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Annotations_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Annotations] PRIMARY KEY CLUSTERED ( [AnnotationID] 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 CREATE NONCLUSTERED INDEX [IX_AnnotationsItemID] ON [Annotations] ( [ItemID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO CREATE NONCLUSTERED INDEX [IX_AnnotationsTypeID] ON [Annotations] ( [TypeID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Annotations', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[Contents] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Contents]( [ContentID] [int] IDENTITY(1,1) NOT NULL, [Number] [nvarchar](256) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [Text] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [Type] [int] NULL, [FormatID] [int] NULL, [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Contents_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Contents_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Contents] PRIMARY KEY CLUSTERED ( [ContentID] 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 CREATE NONCLUSTERED INDEX [IX_ContentsFormatID] ON [Contents] ( [FormatID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'Increased from 30 to 256 to support RTF symbols' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Contents', @level2type=N'COLUMN',@level2name=N'Number' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'0 - Procedure, 10000 - Section, 20000 Step' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Contents', @level2type=N'COLUMN',@level2name=N'Type' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Contents', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[Items] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Items]( [ItemID] [int] IDENTITY(1,1) NOT NULL, [PreviousID] [int] NULL, [ContentID] [int] NOT NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Items_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Items_UsrID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Items] PRIMARY KEY CLUSTERED ( [ItemID] 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 CREATE NONCLUSTERED INDEX [IX_ItemsContentID] ON [Items] ( [ContentID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO CREATE NONCLUSTERED INDEX [IX_ItemsPreviousID] ON [Items] ( [PreviousID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Items', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[Details] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Details]( [DetailID] [int] IDENTITY(1,1) NOT NULL, [ContentID] [int] NOT NULL, [ItemType] [int] NOT NULL, [Text] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_StepTexts_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_StepTexts_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_StepTexts] PRIMARY KEY CLUSTERED ( [DetailID] 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 CREATE NONCLUSTERED INDEX [IX_DetailsContentID] ON [Details] ( [ContentID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Details', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[ZContents] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [ZContents]( [ContentID] [int] NOT NULL, [OldStepSequence] [nvarchar](32) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_ZContents] PRIMARY KEY CLUSTERED ( [ContentID] 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 /****** Object: Table [dbo].[Grids] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Grids]( [ContentID] [int] NOT NULL, [Data] [xml] NOT NULL, [Config] [xml] NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Grids_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Grids_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Grids] PRIMARY KEY CLUSTERED ( [ContentID] 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 EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Grids', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[Images] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO SET ANSI_PADDING ON GO CREATE TABLE [Images]( [ContentID] [int] NOT NULL, [ImageType] [int] NOT NULL CONSTRAINT [DF_Images_ImageType] DEFAULT ((1)), [FileName] [nvarchar](255) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [Data] [varbinary](max) NOT NULL, [Config] [xml] NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Images_DTS] DEFAULT (getdate()), [UserID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Images_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Images] PRIMARY KEY CLUSTERED ( [ContentID] 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 SET ANSI_PADDING OFF GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'1 - Figure, 2 - Video, 3 - Audio' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Images', @level2type=N'COLUMN',@level2name=N'ImageType' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Images', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: Table [dbo].[ZTransitions] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [ZTransitions]( [TransitionID] [int] NOT NULL, [oldto] [nvarchar](32) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_ZTransitions] PRIMARY KEY CLUSTERED ( [TransitionID] 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 /****** Object: Table [dbo].[Permissions] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [Permissions]( [PID] [int] IDENTITY(1,1) NOT NULL, [RID] [int] NOT NULL, [PermLevel] [int] NOT NULL, [VersionType] [int] NOT NULL, [PermValue] [int] NOT NULL, [PermAD] [int] NOT NULL CONSTRAINT [DF_Permissions_PermAD] DEFAULT ((0)), [StartDate] [datetime] NOT NULL CONSTRAINT [DF_Permissions_StartDate] DEFAULT (getdate()), [EndDate] [datetime] NULL, [Config] [nvarchar](max) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, [DTS] [datetime] NOT NULL CONSTRAINT [DF_Permissions_DTS] DEFAULT (getdate()), [UsrID] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL CONSTRAINT [DF_Permissions_UserID] DEFAULT (upper(suser_sname())), [LastChanged] [timestamp] NOT NULL, CONSTRAINT [PK_Permissions] PRIMARY KEY CLUSTERED ( [PID] 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 CREATE NONCLUSTERED INDEX [IX_PermissionsRID] ON [Permissions] ( [RID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'0 - None, 1 - Security, 2 - System, 3 - RO, 4 - Procdures, 5 - Sections, 6 - Steps, 7 - Comments' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Permissions', @level2type=N'COLUMN',@level2name=N'PermLevel' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'0 - None, 1 - Working Draft, 2 - Approved, (3 - All)' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Permissions', @level2type=N'COLUMN',@level2name=N'VersionType' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'1 - Read, 2 - Write, 4 - Create, 8 - Delete (15 - All)' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Permissions', @level2type=N'COLUMN',@level2name=N'PermValue' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'0 - Allow, 1 - Deny' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Permissions', @level2type=N'COLUMN',@level2name=N'PermAD' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'{datetime}' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Permissions', @level2type=N'COLUMN',@level2name=N'DTS' GO /****** Object: StoredProcedure [dbo].[getFoldersByFormatID] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getFoldersByFormatID] ( @FormatID int ) WITH EXECUTE AS OWNER AS SELECT [Folders].[FolderID], [Folders].[ParentID], [Folders].[DBID], [Folders].[Name], [Folders].[Title], [Folders].[ShortName], [Folders].[FormatID], [Folders].[ManualOrder], [Folders].[Config], [Folders].[DTS], [Folders].[UsrID], [Folders].[LastChanged], [Connections].[Name] [Connection_Name], [Connections].[Title] [Connection_Title], [Connections].[ConnectionString] [Connection_ConnectionString], [Connections].[ServerType] [Connection_ServerType], [Connections].[Config] [Connection_Config], [Connections].[DTS] [Connection_DTS], [Connections].[UsrID] [Connection_UsrID], (SELECT COUNT(*) FROM [Assignments] WHERE [Assignments].[FolderID]=[Folders].[FolderID]) [AssignmentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FolderID]=[Folders].[FolderID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] [Children] WHERE [Children].[ParentID]=[Folders].[FolderID]) [ChildCount] FROM [Folders] JOIN [Connections] ON [Connections].[DBID]=[Folders].[DBID] WHERE [Folders].[FormatID]=@FormatID RETURN GO /****** Object: StoredProcedure [dbo].[getFolders] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getFolders] WITH EXECUTE AS OWNER AS SELECT [FolderID], [ParentID], [DBID], [Name], [Title], [ShortName], [FormatID], [ManualOrder], [Config], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Assignments] WHERE [Assignments].[FolderID]=[Folders].[FolderID]) [AssignmentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FolderID]=[Folders].[FolderID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] [Children] WHERE [Children].[ParentID]=[Folders].[FolderID]) [ChildCount] FROM [Folders] RETURN GO /****** Object: StoredProcedure [dbo].[getFormats] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getFormats] WITH EXECUTE AS OWNER AS SELECT [FormatID], [ParentID], [Name], [Description], [Data], [GenMac], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Contents] WHERE [Contents].[FormatID]=[Formats].[FormatID]) [ContentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FormatID]=[Formats].[FormatID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[FormatID]=[Formats].[FormatID]) [FolderCount], (SELECT COUNT(*) FROM [Formats] [Children] WHERE [Children].[ParentID]=[Formats].[FormatID]) [ChildCount] FROM [Formats] RETURN GO /****** Object: StoredProcedure [dbo].[getFormatByParentID_Name] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getFormatByParentID_Name] ( @ParentID int, @Name nvarchar(20) ) WITH EXECUTE AS OWNER AS SELECT [FormatID], [ParentID], [Name], [Description], [Data], [GenMac], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Contents] WHERE [Contents].[FormatID]=[Formats].[FormatID]) [ContentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FormatID]=[Formats].[FormatID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[FormatID]=[Formats].[FormatID]) [FolderCount], (SELECT COUNT(*) FROM [Formats] [Children] WHERE [Children].[ParentID]=[Formats].[FormatID]) [ChildCount] FROM [Formats] WHERE [ParentID]=@ParentID AND [Name]=@Name RETURN GO /****** Object: StoredProcedure [dbo].[getFoldersByDBID] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getFoldersByDBID] ( @DBID int ) WITH EXECUTE AS OWNER AS SELECT [Folders].[FolderID], [Folders].[ParentID], [Folders].[DBID], [Folders].[Name], [Folders].[Title], [Folders].[ShortName], [Folders].[FormatID], [Folders].[ManualOrder], [Folders].[Config], [Folders].[DTS], [Folders].[UsrID], [Folders].[LastChanged], (SELECT COUNT(*) FROM [Assignments] WHERE [Assignments].[FolderID]=[Folders].[FolderID]) [AssignmentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FolderID]=[Folders].[FolderID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] [Children] WHERE [Children].[ParentID]=[Folders].[FolderID]) [ChildCount] FROM [Folders] WHERE [Folders].[DBID]=@DBID RETURN GO /****** Object: StoredProcedure [dbo].[getFormat] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getFormat] ( @FormatID int ) WITH EXECUTE AS OWNER AS SELECT [FormatID], [ParentID], [Name], [Description], [Data], [GenMac], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Contents] WHERE [Contents].[FormatID]=[Formats].[FormatID]) [ContentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FormatID]=[Formats].[FormatID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[FormatID]=[Formats].[FormatID]) [FolderCount], (SELECT COUNT(*) FROM [Formats] [Children] WHERE [Children].[ParentID]=[Formats].[FormatID]) [ChildCount] FROM [Formats] WHERE [FormatID]=@FormatID SELECT [Contents].[ContentID], [Contents].[Number], [Contents].[Text], [Contents].[Type], [Contents].[FormatID], [Contents].[Config], [Contents].[DTS], [Contents].[UserID], [Contents].[LastChanged] FROM [Contents] WHERE [Contents].[FormatID]=@FormatID SELECT [DocVersions].[VersionID], [DocVersions].[FolderID], [DocVersions].[VersionType], [DocVersions].[Name], [DocVersions].[Title], [DocVersions].[ItemID], [DocVersions].[FormatID], [DocVersions].[Config], [DocVersions].[DTS], [DocVersions].[UserID], [DocVersions].[LastChanged], [Folders].[ParentID] [Folder_ParentID], [Folders].[DBID] [Folder_DBID], [Folders].[Name] [Folder_Name], [Folders].[Title] [Folder_Title], [Folders].[ShortName] [Folder_ShortName], [Folders].[FormatID] [Folder_FormatID], [Folders].[ManualOrder] [Folder_ManualOrder], [Folders].[Config] [Folder_Config], [Folders].[DTS] [Folder_DTS], [Folders].[UsrID] [Folder_UsrID] FROM [DocVersions] JOIN [Folders] ON [Folders].[FolderID]=[DocVersions].[FolderID] WHERE [DocVersions].[FormatID]=@FormatID SELECT [Folders].[FolderID], [Folders].[ParentID], [Folders].[DBID], [Folders].[Name], [Folders].[Title], [Folders].[ShortName], [Folders].[FormatID], [Folders].[ManualOrder], [Folders].[Config], [Folders].[DTS], [Folders].[UsrID], [Folders].[LastChanged], [Connections].[Name] [Connection_Name], [Connections].[Title] [Connection_Title], [Connections].[ConnectionString] [Connection_ConnectionString], [Connections].[ServerType] [Connection_ServerType], [Connections].[Config] [Connection_Config], [Connections].[DTS] [Connection_DTS], [Connections].[UsrID] [Connection_UsrID] FROM [Folders] JOIN [Connections] ON [Connections].[DBID]=[Folders].[DBID] WHERE [Folders].[FormatID]=@FormatID RETURN GO /****** Object: StoredProcedure [dbo].[getFolderByParentID_Name] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getFolderByParentID_Name] ( @ParentID int, @Name nvarchar(100) ) WITH EXECUTE AS OWNER AS SELECT [FolderID], [ParentID], [DBID], [Name], [Title], [ShortName], [FormatID], [ManualOrder], [Config], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Assignments] WHERE [Assignments].[FolderID]=[Folders].[FolderID]) [AssignmentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FolderID]=[Folders].[FolderID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] [Children] WHERE [Children].[ParentID]=[Folders].[FolderID]) [ChildCount] FROM [Folders] WHERE [ParentID]=@ParentID AND [Name]=@Name RETURN GO /****** Object: StoredProcedure [dbo].[getFolder] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getFolder] ( @FolderID int ) WITH EXECUTE AS OWNER AS SELECT [FolderID], [ParentID], [DBID], [Name], [Title], [ShortName], [FormatID], [ManualOrder], [Config], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Assignments] WHERE [Assignments].[FolderID]=[Folders].[FolderID]) [AssignmentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FolderID]=[Folders].[FolderID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] [Children] WHERE [Children].[ParentID]=[Folders].[FolderID]) [ChildCount] FROM [Folders] WHERE [FolderID]=@FolderID SELECT [Assignments].[AID], [Assignments].[GID], [Assignments].[RID], [Assignments].[FolderID], [Assignments].[StartDate], [Assignments].[EndDate], [Assignments].[DTS], [Assignments].[UsrID], [Assignments].[LastChanged], [Groups].[GroupName] [Group_GroupName], [Groups].[GroupType] [Group_GroupType], [Groups].[Config] [Group_Config], [Groups].[DTS] [Group_DTS], [Groups].[UsrID] [Group_UsrID], [Roles].[Name] [Role_Name], [Roles].[Title] [Role_Title], [Roles].[DTS] [Role_DTS], [Roles].[UsrID] [Role_UsrID] FROM [Assignments] JOIN [Groups] ON [Groups].[GID]=[Assignments].[GID] JOIN [Roles] ON [Roles].[RID]=[Assignments].[RID] WHERE [Assignments].[FolderID]=@FolderID SELECT [DocVersions].[VersionID], [DocVersions].[FolderID], [DocVersions].[VersionType], [DocVersions].[Name], [DocVersions].[Title], [DocVersions].[ItemID], [DocVersions].[FormatID], [DocVersions].[Config], [DocVersions].[DTS], [DocVersions].[UserID], [DocVersions].[LastChanged] FROM [DocVersions] WHERE [DocVersions].[FolderID]=@FolderID RETURN GO /****** Object: StoredProcedure [dbo].[deleteDocVersion] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteDocVersion] ( @VersionID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Associations] WHERE [VersionID]=@VersionID DELETE [DocVersions] WHERE [VersionID] = @VersionID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getItemsByPartType] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* samples: getItemsByPartType 7 // tables getItemsByPartType 1 // procedure getItemsByPartType 2 // section getItemsByPartType 3 // Cautions getItemsByPartType 4 // Notes getItemsByPartType 5 // RNOs getItemsByPartType 6 // Steps */ CREATE PROCEDURE [getItemsByPartType](@FromType int) WITH EXECUTE AS OWNER AS SELECT ii.[ItemID], [PreviousID], ii.[ContentID], ii.[DTS], ii.[UserID], ii.[LastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=ii.[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=ii.[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=ii.[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=ii.[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=ii.[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=ii.[ItemID]) [Transition_ToIDCount] FROM [Items] ii JOIN [Parts] pp on pp.ItemID = ii.ItemID WHERE pp.Fromtype = @FromType RETURN GO /****** Object: StoredProcedure [dbo].[getItemsByPartTypeAndContent] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* samples: getItemsByPartTypeAndContent 7 // tables getItemsByPartTypeAndContent 1 // procedure getItemsByPartTypeAndContent 2 // section getItemsByPartTypeAndContent 3 // Cautions getItemsByPartTypeAndContent 4 // Notes getItemsByPartTypeAndContent 5 // RNOs getItemsByPartTypeAndContent 6 // Steps */ CREATE PROCEDURE [getItemsByPartTypeAndContent](@FromType int) WITH EXECUTE AS OWNER AS SELECT ii.[ItemID], [PreviousID], ii.[ContentID], ii.[DTS], ii.[UserID], ii.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=ii.[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=ii.[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=ii.[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=ii.[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=ii.[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=ii.[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount] FROM [Items] ii JOIN [Parts] pp on pp.ItemID = ii.ItemID JOIN [Contents] C on C.ContentID = ii.ContentID WHERE pp.Fromtype = @FromType RETURN GO /****** Object: StoredProcedure [dbo].[deleteFolder] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteFolder] ( @FolderID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Assignments] WHERE [FolderID]=@FolderID DELETE [DocVersions] WHERE [FolderID]=@FolderID DELETE [Folders] WHERE [FolderID] = @FolderID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getNextItems] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getNextItems] ( @PreviousID int ) WITH EXECUTE AS OWNER AS SELECT [ItemID], [PreviousID], [ContentID], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[Items].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[Items].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[Items].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[Items].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[Items].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[Items].[ItemID]) [Transition_ToIDCount] FROM [Items] WHERE [PreviousID]=@PreviousID AND [ItemID]<>@PreviousID RETURN GO /****** Object: StoredProcedure [dbo].[deleteItem] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteItem] ( @ItemID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Annotations] WHERE [ItemID]=@ItemID DELETE [DocVersions] WHERE [ItemID]=@ItemID DELETE [Parts] WHERE [ItemID]=@ItemID DELETE [Transitions] WHERE [RangeID]=@ItemID DELETE [Transitions] WHERE [ToID]=@ItemID DELETE [Items] WHERE [ItemID] = @ItemID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getParentFolder] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getParentFolder] ( @ParentID int ) WITH EXECUTE AS OWNER AS SELECT [FolderID], [ParentID], [DBID], [Name], [Title], [ShortName], [FormatID], [ManualOrder], [Config], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Assignments] WHERE [Assignments].[FolderID]=[Folders].[FolderID]) [AssignmentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FolderID]=[Folders].[FolderID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] [Children] WHERE [Children].[ParentID]=[Folders].[FolderID]) [ChildCount] FROM [Folders] WHERE [FolderID]=@ParentID RETURN GO /****** Object: StoredProcedure [dbo].[deleteFormat] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteFormat] ( @FormatID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Contents] WHERE [FormatID]=@FormatID DELETE [DocVersions] WHERE [FormatID]=@FormatID DELETE [Folders] WHERE [FormatID]=@FormatID DELETE [Formats] WHERE [FormatID] = @FormatID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getItemsByContentID] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getItemsByContentID] ( @ContentID int ) WITH EXECUTE AS OWNER AS SELECT [Items].[ItemID], [Items].[PreviousID], [Items].[ContentID], [Items].[DTS], [Items].[UserID], [Items].[LastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[Items].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[Items].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[Items].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[Items].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[Items].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[Items].[ItemID]) [Transition_ToIDCount] FROM [Items] WHERE [Items].[ContentID]=@ContentID RETURN GO /****** Object: StoredProcedure [dbo].[getItems] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getItems] WITH EXECUTE AS OWNER AS SELECT [ItemID], [PreviousID], [ContentID], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[Items].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[Items].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[Items].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[Items].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[Items].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[Items].[ItemID]) [Transition_ToIDCount] FROM [Items] RETURN GO /****** Object: StoredProcedure [dbo].[getItem] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getItem] ( @ItemID int ) WITH EXECUTE AS OWNER AS SELECT [ItemID], [PreviousID], [ContentID], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[Items].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[Items].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[Items].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[Items].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[Items].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[Items].[ItemID]) [Transition_ToIDCount] FROM [Items] WHERE [ItemID]=@ItemID SELECT [Annotations].[AnnotationID], [Annotations].[ItemID], [Annotations].[TypeID], [Annotations].[RtfText], [Annotations].[SearchText], [Annotations].[Config], [Annotations].[DTS], [Annotations].[UserID], [Annotations].[LastChanged], [AnnotationTypes].[Name] [AnnotationType_Name], [AnnotationTypes].[Config] [AnnotationType_Config], [AnnotationTypes].[DTS] [AnnotationType_DTS], [AnnotationTypes].[UserID] [AnnotationType_UserID] FROM [Annotations] JOIN [AnnotationTypes] ON [AnnotationTypes].[TypeID]=[Annotations].[TypeID] WHERE [Annotations].[ItemID]=@ItemID SELECT [DocVersions].[VersionID], [DocVersions].[FolderID], [DocVersions].[VersionType], [DocVersions].[Name], [DocVersions].[Title], [DocVersions].[ItemID], [DocVersions].[FormatID], [DocVersions].[Config], [DocVersions].[DTS], [DocVersions].[UserID], [DocVersions].[LastChanged], [Folders].[ParentID] [Folder_ParentID], [Folders].[DBID] [Folder_DBID], [Folders].[Name] [Folder_Name], [Folders].[Title] [Folder_Title], [Folders].[ShortName] [Folder_ShortName], [Folders].[FormatID] [Folder_FormatID], [Folders].[ManualOrder] [Folder_ManualOrder], [Folders].[Config] [Folder_Config], [Folders].[DTS] [Folder_DTS], [Folders].[UsrID] [Folder_UsrID] FROM [DocVersions] JOIN [Folders] ON [Folders].[FolderID]=[DocVersions].[FolderID] WHERE [DocVersions].[ItemID]=@ItemID SELECT [Parts].[ContentID], [Parts].[FromType], [Parts].[ItemID], [Parts].[DTS], [Parts].[UserID], [Parts].[LastChanged], [Contents].[Number] [Content_Number], [Contents].[Text] [Content_Text], [Contents].[Type] [Content_Type], [Contents].[FormatID] [Content_FormatID], [Contents].[Config] [Content_Config], [Contents].[DTS] [Content_DTS], [Contents].[UserID] [Content_UserID] FROM [Parts] JOIN [Contents] ON [Contents].[ContentID]=[Parts].[ContentID] WHERE [Parts].[ItemID]=@ItemID SELECT [Transitions].[TransitionID], [Transitions].[FromID], [Transitions].[ToID], [Transitions].[RangeID], [Transitions].[IsRange], [Transitions].[TranType], [Transitions].[Config], [Transitions].[DTS], [Transitions].[UserID], [Transitions].[LastChanged], [Contents].[Number] [Content_Number], [Contents].[Text] [Content_Text], [Contents].[Type] [Content_Type], [Contents].[FormatID] [Content_FormatID], [Contents].[Config] [Content_Config], [Contents].[DTS] [Content_DTS], [Contents].[UserID] [Content_UserID] FROM [Transitions] JOIN [Contents] ON [Contents].[ContentID]=[Transitions].[FromID] WHERE [Transitions].[RangeID]=@ItemID SELECT [Transitions].[TransitionID], [Transitions].[FromID], [Transitions].[ToID], [Transitions].[RangeID], [Transitions].[IsRange], [Transitions].[TranType], [Transitions].[Config], [Transitions].[DTS], [Transitions].[UserID], [Transitions].[LastChanged], [Contents].[Number] [Content_Number], [Contents].[Text] [Content_Text], [Contents].[Type] [Content_Type], [Contents].[FormatID] [Content_FormatID], [Contents].[Config] [Content_Config], [Contents].[DTS] [Content_DTS], [Contents].[UserID] [Content_UserID] FROM [Transitions] JOIN [Contents] ON [Contents].[ContentID]=[Transitions].[FromID] WHERE [Transitions].[ToID]=@ItemID RETURN GO /****** Object: StoredProcedure [dbo].[DeleteItemAndChildren] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [DeleteItemAndChildren] ( @ItemID int, @UserID AS VARCHAR(100) ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DECLARE @ContentID AS INT DECLARE @NextItemID AS INT DECLARE @PreviousItemID AS INT DECLARE @ExternalChildCount AS INT DECLARE @ExternalCount AS INT DECLARE @Path AS VARCHAR(MAX) DECLARE @Children AS TABLE ( ItemID INT PRIMARY KEY, ContentID INT ) DECLARE @ExternalTrans TABLE ( [FromItemID] int, [TransitionID] [int] NOT NULL, [FromID] [int] NOT NULL, [ToID] [int] NOT NULL, [RangeID] [int] NOT NULL, [Config] [nvarchar](max) NULL ) SET NOCOUNT ON SELECT @ContentID = ContentID, @PreviousItemID = PreviousID FROM Items WHERE ItemID = @ItemID SELECT @NextItemID = ItemID FROM Items WHERE PreviousID = @ItemID SELECT @ExternalCount = count(*) FROM vefn_FindExternalTransitions(@ItemID) SELECT @ExternalChildCount = count(*) FROM vefn_FindExternalChildTransitions(@ItemID) SET @Path = [dbo].[ve_GetShortPath](@ItemID) IF @ExternalCount > 0 AND @NextItemID is null BEGIN RAISERROR ('###Cannot Delete Item###Step %d has External Transitions and has no next step - (%s)',16,1,@ItemID,@Path) RETURN END IF @ExternalChildCount > 0 BEGIN RAISERROR ('###Cannot Delete Item###Step %d has External Transitions to it''s children - (%s)',16,1,@ItemID,@Path) RETURN END -- Get list of Children INSERT INTO @Children SELECT * FROM vefn_ChildItems(@ItemID) -- UPDATE PreviousID in Items WHERE ItemID = @NextItemID UPDATE Items SET PreviousID = @PreviousItemID WHERE ItemID=@NextItemID -- UPDATE DocVersion UPDATE DocVersions SET ItemID=@NextItemID where ItemID = @ItemID -- UPDATE Parts IF @NextItemID is not NULL -- Remove Part Record BEGIN UPDATE PARTS SET ItemID = @NextItemID where ItemID=@ItemID END ELSE BEGIN DELETE FROM Parts WHERE ItemID=@ItemID END -- Get external transitions that point to the specified Item -- These will need to be adjusted to point to the next Item. INSERT INTO @ExternalTrans SELECT * FROM vefn_FindExternalTransitions(@ItemID); DECLARE @typeID int -- AnnotationType SELECT @typeID = TypeID from AnnotationTypes where Name = 'Verification Required' IF(@typeID IS NULL) BEGIN INSERT INTO [AnnotationTypes] ([Name],[UserID]) VALUES ('Verification Required','Volian') SELECT @typeID = SCOPE_IDENTITY() END -- Add 'Verification Required' annotions for transtions that point to different step INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) SELECT ItemID, @typeID,'Verify Transition Destination',@UserID FROM Items where ItemID in (SELECT FromItemID FROM @ExternalTrans) -- Update content records for the transitions Update CC Set Text = DBO.vefn_FixTransitionText(Text,TT.TransitionID,TT.TranType,TT.ToID,TT.RangeID,@ItemID,@NextItemID) From CONTENTS CC JOIN Transitions TT ON TT.FromID = CC.ContentID WHERE TransitionID in(Select TransitionID from @ExternalTrans) -- Update transitions that point to @ItemID to Point to @NextItemID UPDATE TRANSITIONS SET ToID = case when ToID = @ItemID then @NextItemID else ToID END, RangeID = case when RangeID = @ItemID then @NextItemID else RangeID END WHERE TransitionID in(Select TransitionID from @ExternalTrans) -- Delete Annotations for @ItemID and children DELETE from Annotations where ItemID in(Select ItemID from @Children) -- Delete Details associated with @ContentID and children DELETE from Details where ContentID in(Select ContentID from @Children) -- Delete Grids associated with @ContentID and children DELETE from Grids where ContentID in(Select ContentID from @Children) -- Delete Images associated with @ContentID and children DELETE from Images where ContentID in(Select ContentID from @Children) -- Delete Entries associated with @ContentID and children DELETE from Entries where ContentID in(Select ContentID from @Children) -- Delete ROUsages associated with @ContentID and children DELETE from RoUsages where ContentID in(Select ContentID from @Children) -- Delete ZTransitions records associated with @ContentID and children DELETE FROM ZTransitions where TransitionID in(SELECT TransitionID from Transitions where FromID in(SELECT ContentID FROM @Children) or FromID = @ContentID) -- Delete Transitions associated with @ContentID and children DELETE FROM Transitions where FromID in(SELECT ContentID FROM @Children) or FromID = @ContentID -- Delete Parts associated with @ContentID and children DELETE from Parts where ContentID in(Select ContentID from @Children) -- Delete ZContents associated with @ContentID and children DELETE from ZContents where ContentID in(Select ContentID from @Children) -- Disconnect Items from Each Other DELETE from Items where ItemID in(Select ItemID from @Children) and PreviousID Is Not Null -- Disconnect Items to be deleted from each other Update Items set PreviousID = null where ItemID in (Select ItemID from @Children) and PreviousID Is Not Null -- Delete Item Records DELETE from Items where ItemID in(Select ItemID from @Children) -- DELETE Contents DELETE from Contents where ContentID in(Select ContentID from @Children) IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[DeleteItemAndChildrenTest] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [DeleteItemAndChildrenTest] ( @ItemID int, @UserID AS VARCHAR(100) ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DECLARE @ContentID AS INT DECLARE @NextItemID AS INT DECLARE @PreviousItemID AS INT DECLARE @ExternalChildCount AS INT DECLARE @ExternalCount AS INT DECLARE @Path AS VARCHAR(MAX) DECLARE @Children AS TABLE ( ItemID INT PRIMARY KEY, ContentID INT ) DECLARE @ExternalTrans TABLE ( [FromItemID] int, [TransitionID] [int] NOT NULL, [FromID] [int] NOT NULL, [ToID] [int] NOT NULL, [RangeID] [int] NOT NULL, [Config] [nvarchar](max) NULL ) SET NOCOUNT ON SELECT @ContentID = ContentID, @PreviousItemID = PreviousID FROM Items WHERE ItemID = @ItemID SELECT @NextItemID = ItemID FROM Items WHERE PreviousID = @ItemID SELECT @ExternalCount = count(*) FROM vefn_FindExternalTransitions(@ItemID) SELECT @ExternalChildCount = count(*) FROM vefn_FindExternalChildTransitions(@ItemID) SET @Path = [dbo].[ve_GetShortPath](@ItemID) IF @ExternalCount > 0 AND @NextItemID is null BEGIN PRINT '--->Cannot delete step ' + @Path + '.' + char(13) + '<===> It has External Transitions and has no next step' SELECT dbo.ve_GetShortPath(FromItemID) FromPath, dbo.ve_GetShortPath(ToID) ToPath FROM vefn_FindExternalTransitions(@ItemID) WHERE NOT EXISTS (SELECT * FROM Items WHERE PreviousID = @ItemID) RETURN END IF @ExternalChildCount > 0 BEGIN PRINT '---> Cannot delete step ' + @Path + '.' + char(13) + '<===> It has External Transitions to it''s children' SELECT dbo.ve_GetShortPath(FromItemID) FromPath, dbo.ve_GetShortPath(ToID) ToPath FROM vefn_FindExternalChildTransitions(@ItemID) RETURN END PRINT '@Path = ''' + @Path + '''' PRINT '@ItemID = ' + cast(@ItemID as varchar(10)) PRINT '@ContentID = ' + isnull(cast(@ContentID as varchar(10)),'{NULL}') PRINT '@NextItemID = ' + isnull(cast(@NextItemID as varchar(10)),'{NULL}') PRINT '@PreviousItemID = ' + isnull(cast(@PreviousItemID as varchar(10)),'{NULL}') PRINT '@ExternalCount = ' + isnull(cast(@ExternalCount as varchar(10)),'{NULL}') PRINT '@ExternalChildCount = ' + isnull(cast(@ExternalChildCount as varchar(10)),'{NULL}') PRINT '---' + char(13) +'Preparing to delete step ' + @Path+ char(13) + '---' -- Get list of Children INSERT INTO @Children SELECT * FROM vefn_ChildItems(@ItemID) PRINT 'Children' SELECT ItemID, [dbo].[ve_GetShortPath](ItemID) ItemPath, ContentID,[dbo].[ve_GetShortPathFromContentID](ContentID) ContentPath FROM @Children -- UPDATE PreviousID in Items WHERE ItemID = @NextItemID PRINT 'UPDATE Items Next' SELECT ItemID, [dbo].[ve_GetShortPath](@NextItemID) PathOfNextItem,[dbo].[ve_GetShortPath](PreviousID) PathOfDeletedItem, [dbo].[ve_GetShortPath](@PreviousItemID) NewPreviousPath FROM Items WHERE ItemID=@NextItemID -- UPDATE DocVersion PRINT 'UPDATE DocVersions ItemID' SELECT [dbo].[ve_GetShortPath](ItemID) MyPath, [dbo].[ve_GetShortPath](@NextItemID) NewPath FROM DocVersions WHERE ItemID=@ItemID SELECT VersionID, [dbo].[ve_GetShortPath](@NextItemID) NewPath FROM DocVersions WHERE ItemID=@ItemID -- UPDATE Parts IF @NextItemID is not NULL -- Remove Part Record BEGIN PRINT 'UPDATE Parts' SELECT ItemID,@NextItemID,[dbo].[ve_GetShortPath](ItemID) ItemPath, [dbo].[ve_GetShortPath](@NextItemID) NewItemPath FROM Parts WHERE ItemID=@ItemID END ELSE BEGIN PRINT 'DELETE Parts' SELECT ContentID,FromType,[dbo].[ve_GetShortPath](ItemID) ItemPath FROM Parts WHERE ItemID=@ItemID END -- Get external transitions that point to the specified Item -- These will need to be adjusted to point to the next Item. INSERT INTO @ExternalTrans SELECT * FROM vefn_FindExternalTransitions(@ItemID); DECLARE @typeID int -- AnnotationType SELECT @typeID = TypeID from AnnotationTypes where Name = 'Verification Required' IF(@typeID IS NULL) BEGIN PRINT 'ADD Verification Required' INSERT INTO [AnnotationTypes] ([Name],[UserID]) VALUES ('Verification Required','Volian') SELECT @typeID = SCOPE_IDENTITY() END -- Get list of External Transitions PRINT 'UPDATE Transitions - ADD Annotations' SELECT [dbo].[ve_GetShortPathFromContentID](FromID)FromPath ,[dbo].[ve_GetShortPath](ToID) ToPath ,case when ToID = @ItemID then [dbo].[ve_GetShortPath](@NextItemID) else [dbo].[ve_GetShortPath](ToID) END NewToPath ,[dbo].[ve_GetShortPath](RangeID) RangePath ,case when RangeID = @ItemID then [dbo].[ve_GetShortPath](@NextItemID) else [dbo].[ve_GetShortPath](RangeID) END NewRangePath FROM Transitions WHERE TransitionID IN(Select TransitionID from @ExternalTrans) -- Delete Annotations for @ItemID and children PRINT 'DELETE Annotations' SELECT AnnotationID, [dbo].[ve_GetShortPath](ItemID) ItemPath from Annotations where ItemID in(Select ItemID from @Children) -- Delete Details associated with @ContentID and children PRINT 'DELETE Details' SELECT [dbo].[ve_GetShortPathFromContentID](ContentID) ContentPath from Details where ContentID in(Select ContentID from @Children) -- Delete Entries associated with @ContentID and children PRINT 'DELETE Entries' SELECT ContentID, [dbo].[ve_GetShortPathFromContentID](ContentID) ContentPath from Entries where ContentID in(Select ContentID from @Children) -- Delete ROUsages associated with @ContentID and children PRINT 'DELETE ROUsages' SELECT ROUsageID, [dbo].[ve_GetShortPathFromContentID](ContentID) ContentPath from RoUsages where ContentID in(Select ContentID from @Children) -- Delete Transitions associated with @ContentID and children PRINT 'DELETE Transitions' SELECT TransitionID, [dbo].[ve_GetShortPathFromContentID](FromID)FromPath ,[dbo].[ve_GetShortPath](ToID) ToPath ,[dbo].[ve_GetShortPath](RangeID) RangePath FROM Transitions where FromID in(SELECT ContentID FROM @Children) or FromID = @ContentID -- Delete Parts associated with @ContentID and children PRINT 'DELETE Parts' SELECT ContentID, FromType,[dbo].[ve_GetShortPathFromContentID](ContentID) ContentPath from Parts where ContentID in(Select ContentID from @Children) -- Delete ZContents associated with @ContentID and children PRINT 'DELETE XContents' SELECT ContentID,[dbo].[ve_GetShortPathFromContentID](ContentID) ContentPath from ZContents where ContentID in(Select ContentID from @Children) -- Disconnect Items from Each Other PRINT 'DISCONNECT Items from each other' SELECT ItemID, [dbo].[ve_GetShortPath](ItemID) ItemPath, [dbo].[ve_GetShortPath](PreviousID) PreviousPath from Items where ItemID in(Select ItemID from @Children) and PreviousID Is Not Null -- Delete Item Records PRINT 'DELETE Items' SELECT ItemID, [dbo].[ve_GetShortPath](ItemID) ItemPath from Items where ItemID in(Select ItemID from @Children) -- DELETE Contents PRINT 'DELETE Contents' SELECT ContentID, [dbo].[ve_GetShortPathFromContentID](ContentID) ContentPath from Contents where ContentID in(Select ContentID from @Children) IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getParentFormat] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getParentFormat] ( @ParentID int ) WITH EXECUTE AS OWNER AS SELECT [FormatID], [ParentID], [Name], [Description], [Data], [GenMac], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Contents] WHERE [Contents].[FormatID]=[Formats].[FormatID]) [ContentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FormatID]=[Formats].[FormatID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[FormatID]=[Formats].[FormatID]) [FolderCount], (SELECT COUNT(*) FROM [Formats] [Children] WHERE [Children].[ParentID]=[Formats].[FormatID]) [ChildCount] FROM [Formats] WHERE [FormatID]=@ParentID RETURN GO /****** Object: StoredProcedure [dbo].[updateDocVersion] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateDocVersion] ( @VersionID int, @FolderID int, @VersionType int, @Name nvarchar(100), @Title nvarchar(510)=null, @ItemID int=null, @FormatID int=null, @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [DocVersions] SET [FolderID]=@FolderID, [VersionType]=@VersionType, [Name]=@Name, [Title]=@Title, [ItemID]=@ItemID, [FormatID]=@FormatID, [Config]=@Config, [DTS]=@DTS, [UserID]=@UserID WHERE [VersionID]=@VersionID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [DocVersions] WHERE [VersionID]=@VersionID) RAISERROR('DocVersion record has been deleted by another user', 16, 1) ELSE RAISERROR('DocVersion has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [DocVersions] WHERE [VersionID]=@VersionID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[purgeData] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [purgeData] WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION delete from [Annotations] dbcc checkident([Annotations],reseed,0) delete from [AnnotationTypes] dbcc checkident([AnnotationTypes],reseed,0) delete from [Assignments] dbcc checkident([Assignments],reseed,0) delete from [Associations] dbcc checkident([Associations],reseed,0) delete from [Details] dbcc checkident([Details],reseed,0) delete from [DocVersions] dbcc checkident([DocVersions],reseed,0) delete from [DROUsages] dbcc checkident([DROUsages],reseed,0) delete from [Entries] delete from [Figures] dbcc checkident([Figures],reseed,0) delete from [Folders] dbcc checkident([Folders],reseed,0) delete from [Grids] delete from [Images] delete from [Memberships] dbcc checkident([Memberships],reseed,0) delete from [Parts] delete from [Pdfs] delete from [Permissions] dbcc checkident([Permissions],reseed,0) delete from [ROFsts] dbcc checkident([ROFsts],reseed,0) delete from [ROImages] dbcc checkident([ROImages],reseed,0) delete from [Roles] dbcc checkident([Roles],reseed,0) delete from [RoUsages] dbcc checkident([RoUsages],reseed,0) delete from [Users] dbcc checkident([Users],reseed,0) delete from [ZContents] delete from [ZTransitions] delete from [Connections] dbcc checkident([Connections],reseed,0) delete from [Documents] dbcc checkident([Documents],reseed,0) delete from [Groups] dbcc checkident([Groups],reseed,0) delete from [RODbs] dbcc checkident([RODbs],reseed,0) delete from [Transitions] dbcc checkident([Transitions],reseed,0) delete from [Items] dbcc checkident([Items],reseed,0) delete from [Contents] dbcc checkident([Contents],reseed,0) delete from [Formats] dbcc checkident([Formats],reseed,0) IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getChildFormats] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getChildFormats] ( @ParentID int ) WITH EXECUTE AS OWNER AS SELECT [FormatID], [ParentID], [Name], [Description], [Data], [GenMac], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Contents] WHERE [Contents].[FormatID]=[Formats].[FormatID]) [ContentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FormatID]=[Formats].[FormatID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[FormatID]=[Formats].[FormatID]) [FolderCount], (SELECT COUNT(*) FROM [Formats] [Children] WHERE [Children].[ParentID]=[Formats].[FormatID]) [ChildCount] FROM [Formats] WHERE [ParentID]=@ParentID AND [FormatID]<>@ParentID RETURN GO /****** Object: StoredProcedure [dbo].[getAssociationsByROFstID] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getAssociationsByROFstID] ( @ROFstID int ) WITH EXECUTE AS OWNER AS SELECT [Associations].[AssociationID], [Associations].[VersionID], [Associations].[ROFstID], [Associations].[Config], [Associations].[DTS], [Associations].[UserID], [Associations].[LastChanged], [DocVersions].[FolderID] [DocVersion_FolderID], [DocVersions].[VersionType] [DocVersion_VersionType], [DocVersions].[Name] [DocVersion_Name], [DocVersions].[Title] [DocVersion_Title], [DocVersions].[ItemID] [DocVersion_ItemID], [DocVersions].[FormatID] [DocVersion_FormatID], [DocVersions].[Config] [DocVersion_Config], [DocVersions].[DTS] [DocVersion_DTS], [DocVersions].[UserID] [DocVersion_UserID] FROM [Associations] JOIN [DocVersions] ON [DocVersions].[VersionID]=[Associations].[VersionID] WHERE [Associations].[ROFstID]=@ROFstID RETURN GO /****** Object: StoredProcedure [dbo].[getChildFolders] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getChildFolders] ( @ParentID int ) WITH EXECUTE AS OWNER AS SELECT [FolderID], [ParentID], [DBID], [Name], [Title], [ShortName], [FormatID], [ManualOrder], [Config], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Assignments] WHERE [Assignments].[FolderID]=[Folders].[FolderID]) [AssignmentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FolderID]=[Folders].[FolderID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] [Children] WHERE [Children].[ParentID]=[Folders].[FolderID]) [ChildCount] FROM [Folders] WHERE [ParentID]=@ParentID AND [FolderID]<>@ParentID RETURN GO /****** Object: StoredProcedure [dbo].[getDocVersions] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getDocVersions] WITH EXECUTE AS OWNER AS SELECT [VersionID], [FolderID], [VersionType], [Name], [Title], [ItemID], [FormatID], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Associations] WHERE [Associations].[VersionID]=[DocVersions].[VersionID]) [AssociationCount] FROM [DocVersions] RETURN GO /****** Object: StoredProcedure [dbo].[getDocVersionsByFolderID] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getDocVersionsByFolderID] ( @FolderID int ) WITH EXECUTE AS OWNER AS SELECT [DocVersions].[VersionID], [DocVersions].[FolderID], [DocVersions].[VersionType], [DocVersions].[Name], [DocVersions].[Title], [DocVersions].[ItemID], [DocVersions].[FormatID], [DocVersions].[Config], [DocVersions].[DTS], [DocVersions].[UserID], [DocVersions].[LastChanged], (SELECT COUNT(*) FROM [Associations] WHERE [Associations].[VersionID]=[DocVersions].[VersionID]) [AssociationCount] FROM [DocVersions] WHERE [DocVersions].[FolderID]=@FolderID RETURN GO /****** Object: StoredProcedure [dbo].[getDocVersionsByFormatID] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getDocVersionsByFormatID] ( @FormatID int ) WITH EXECUTE AS OWNER AS SELECT [DocVersions].[VersionID], [DocVersions].[FolderID], [DocVersions].[VersionType], [DocVersions].[Name], [DocVersions].[Title], [DocVersions].[ItemID], [DocVersions].[FormatID], [DocVersions].[Config], [DocVersions].[DTS], [DocVersions].[UserID], [DocVersions].[LastChanged], [Folders].[ParentID] [Folder_ParentID], [Folders].[DBID] [Folder_DBID], [Folders].[Name] [Folder_Name], [Folders].[Title] [Folder_Title], [Folders].[ShortName] [Folder_ShortName], [Folders].[FormatID] [Folder_FormatID], [Folders].[ManualOrder] [Folder_ManualOrder], [Folders].[Config] [Folder_Config], [Folders].[DTS] [Folder_DTS], [Folders].[UsrID] [Folder_UsrID], (SELECT COUNT(*) FROM [Associations] WHERE [Associations].[VersionID]=[DocVersions].[VersionID]) [AssociationCount] FROM [DocVersions] JOIN [Folders] ON [Folders].[FolderID]=[DocVersions].[FolderID] WHERE [DocVersions].[FormatID]=@FormatID RETURN GO /****** Object: StoredProcedure [dbo].[getDocVersionsByItemID] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getDocVersionsByItemID] ( @ItemID int ) WITH EXECUTE AS OWNER AS SELECT [DocVersions].[VersionID], [DocVersions].[FolderID], [DocVersions].[VersionType], [DocVersions].[Name], [DocVersions].[Title], [DocVersions].[ItemID], [DocVersions].[FormatID], [DocVersions].[Config], [DocVersions].[DTS], [DocVersions].[UserID], [DocVersions].[LastChanged], [Folders].[ParentID] [Folder_ParentID], [Folders].[DBID] [Folder_DBID], [Folders].[Name] [Folder_Name], [Folders].[Title] [Folder_Title], [Folders].[ShortName] [Folder_ShortName], [Folders].[FormatID] [Folder_FormatID], [Folders].[ManualOrder] [Folder_ManualOrder], [Folders].[Config] [Folder_Config], [Folders].[DTS] [Folder_DTS], [Folders].[UsrID] [Folder_UsrID], (SELECT COUNT(*) FROM [Associations] WHERE [Associations].[VersionID]=[DocVersions].[VersionID]) [AssociationCount] FROM [DocVersions] JOIN [Folders] ON [Folders].[FolderID]=[DocVersions].[FolderID] WHERE [DocVersions].[ItemID]=@ItemID RETURN GO /****** Object: StoredProcedure [dbo].[getDocVersion] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getDocVersion] ( @VersionID int ) WITH EXECUTE AS OWNER AS SELECT [VersionID], [FolderID], [VersionType], [Name], [Title], [ItemID], [FormatID], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Associations] WHERE [Associations].[VersionID]=[DocVersions].[VersionID]) [AssociationCount] FROM [DocVersions] WHERE [VersionID]=@VersionID SELECT [Associations].[AssociationID], [Associations].[VersionID], [Associations].[ROFstID], [Associations].[Config], [Associations].[DTS], [Associations].[UserID], [Associations].[LastChanged], [ROFsts].[RODbID] [ROFst_RODbID], [ROFsts].[ROLookup] [ROFst_ROLookup], [ROFsts].[Config] [ROFst_Config], [ROFsts].[DTS] [ROFst_DTS], [ROFsts].[UserID] [ROFst_UserID] FROM [Associations] JOIN [ROFsts] ON [ROFsts].[ROFstID]=[Associations].[ROFstID] WHERE [Associations].[VersionID]=@VersionID RETURN GO /****** Object: UserDefinedFunction [dbo].[ve_GetFolderPath] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Select VersionID,Name,dbo.ve_GetFolderPath(VersionID) from DocVersions order by VersionID */ CREATE FUNCTION [ve_GetFolderPath] (@VersionID int) RETURNS varchar(MAX) WITH EXECUTE AS OWNER AS BEGIN declare @Path varchar(MAX); with Folderz(Level, FolderID, Path) as ( Select 1 Level, FolderID,CAST(Name as varchar(MAX)) from DocVersions I where VersionID = @VersionID Union All -- Select FS.ParentID - (Select ParentID from Folders where FolderID = FS.ParentID), ParentID, CAST(Name + char(7) + Path as varchar(MAX)) from Folders FS join Folderz FZ on FS.FolderID = FZ.FolderID where FS.FolderID <> FS.ParentID ) select @Path = path From Folderz where Level = 0 return @Path END; GO /****** Object: StoredProcedure [dbo].[addDocVersion] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addDocVersion] ( @FolderID int, @VersionType int, @Name nvarchar(100), @Title nvarchar(510)=null, @ItemID int=null, @FormatID int=null, @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @newVersionID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [DocVersions] ( [FolderID], [VersionType], [Name], [Title], [ItemID], [FormatID], [Config], [DTS], [UserID] ) VALUES ( @FolderID, @VersionType, @Name, @Title, @ItemID, @FormatID, @Config, @DTS, @UserID ) SELECT @newVersionID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [DocVersions] WHERE [VersionID]=@newVersionID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: UserDefinedFunction [dbo].[vefn_GetInheritedFormat] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Samples Select TranType, .dbo.vefn_GetInheritedFormat(355) TransFormat from(Select 1 TranType UNION Select 2 TranType UNION Select 3 TranType UNION Select 4 TranType UNION Select 5 TranType UNION Select 6 TranType UNION Select 7 TranType UNION Select 8 TranType UNION Select 9 TranType UNION Select 10 TranType) TT Select top 25 ItemID, TranType, .dbo.vefn_GetInheritedFormat(ItemID) TransFormat From Transitions TR Join Items II on II.ContentID = TR.FromID */ /* local is a 'boolean' (0=false, 1=true) to state whether to look at the item itself or only its parent */ CREATE FUNCTION [vefn_GetInheritedFormat] (@ItemID int, @local int) RETURNS int WITH EXECUTE AS OWNER AS BEGIN DECLARE @FormatID as int -- First get the Active Format begin with Itemz([Level], [PreviousID], [ItemID], [ParentID], [FolderID], [FormatID]) as ( Select 0 [Level], [PreviousID], [ItemID], null, null, case when @local = 1 then (Select FormatID from Contents CC where [CC].[ContentID] = [II].[ContentID]) else null end FormatID FROM [Items] II where [ItemID]=@ItemID Union All -- Parent Item select [Level] + 1, I.[PreviousID], I.[ItemID], null, null, C.FormatID from Itemz Z join Parts P on P.ItemID = Z.ItemID join Items I on I.ContentID = P.ContentID join Contents C on C.ContentID = P.ContentID where Z.FormatID is null -- Siblings Item Union All select [Level] , I.[PreviousID] , I.[ItemID], null, null, Z.FormatID from Itemz Z join Items I on Z.PreviousID = I.ItemID where Z.FormatID is null Union All -- DocVersion From Item select [Level] + 1, null, null, DV.FolderID, null, DV.FormatID from Itemz Z join DocVersions DV on DV.ItemID = Z.ItemID where Z.FormatID is null Union All -- Folders select [Level] + 1, null, null, FF.ParentID, FF.FolderID, FF.FormatID from Itemz Z join Folders FF on FF.FolderID = Z.ParentID and FF.ParentID <> FF.FolderID where Z.FormatID is null ) Select @FormatID = FormatID from Itemz ZZ Where FormatID is not null RETURN @FormatID END END GO /****** Object: StoredProcedure [dbo].[getPreviousItem] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getPreviousItem] ( @PreviousID int ) WITH EXECUTE AS OWNER AS SELECT [ItemID], [PreviousID], [ContentID], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[Items].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[Items].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[Items].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[Items].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[Items].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[Items].[ItemID]) [Transition_ToIDCount] FROM [Items] WHERE [ItemID]=@PreviousID RETURN GO /****** Object: StoredProcedure [dbo].[existsDocVersion] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsDocVersion] ( @VersionID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [DocVersions] WHERE [VersionID]=@VersionID RETURN GO /****** Object: StoredProcedure [dbo].[getROFst] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getROFst] ( @ROFstID int ) WITH EXECUTE AS OWNER AS SELECT [ROFstID], [RODbID], [ROLookup], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Associations] WHERE [Associations].[ROFstID]=[ROFsts].[ROFstID]) [AssociationCount], (SELECT COUNT(*) FROM [Figures] WHERE [Figures].[ROFstID]=[ROFsts].[ROFstID]) [FigureCount] FROM [ROFsts] WHERE [ROFstID]=@ROFstID SELECT [Associations].[AssociationID], [Associations].[VersionID], [Associations].[ROFstID], [Associations].[Config], [Associations].[DTS], [Associations].[UserID], [Associations].[LastChanged], [DocVersions].[FolderID] [DocVersion_FolderID], [DocVersions].[VersionType] [DocVersion_VersionType], [DocVersions].[Name] [DocVersion_Name], [DocVersions].[Title] [DocVersion_Title], [DocVersions].[ItemID] [DocVersion_ItemID], [DocVersions].[FormatID] [DocVersion_FormatID], [DocVersions].[Config] [DocVersion_Config], [DocVersions].[DTS] [DocVersion_DTS], [DocVersions].[UserID] [DocVersion_UserID] FROM [Associations] JOIN [DocVersions] ON [DocVersions].[VersionID]=[Associations].[VersionID] WHERE [Associations].[ROFstID]=@ROFstID SELECT [Figures].[FigureID], [Figures].[ROFstID], [Figures].[ImageID], [Figures].[Config], [Figures].[DTS], [Figures].[UserID], [Figures].[LastChanged], [ROImages].[RODbID] [ROImage_RODbID], [ROImages].[FileName] [ROImage_FileName], [ROImages].[Content] [ROImage_Content], [ROImages].[Config] [ROImage_Config], [ROImages].[DTS] [ROImage_DTS], [ROImages].[UserID] [ROImage_UserID] FROM [Figures] JOIN [ROImages] ON [ROImages].[ImageID]=[Figures].[ImageID] WHERE [Figures].[ROFstID]=@ROFstID RETURN GO /****** Object: StoredProcedure [dbo].[vesp_ListChildren] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- vesp_ListChildren 17 -- drop procedure [getItemAndChildren] CREATE PROCEDURE [vesp_ListChildren] (@ItemID int) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged]) as ( Select 0 [Level], 0 [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID -- Siblings Union All select [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.[Level] > 0 ) select I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Children] WHERE [Children].[PreviousID]=[I].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount] from ItemZ I join Contents C on C.ContentID = I.ContentID order by I.[Level] , I.[FromType], I.[Ordinal] END GO /****** Object: StoredProcedure [dbo].[getTopFolder] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getTopFolder] WITH EXECUTE AS OWNER AS SELECT [FolderID], [ParentID], [DBID], [Name], [Title], [ShortName], [FormatID], [ManualOrder], [Config], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Assignments] WHERE [Assignments].[FolderID]=[Folders].[FolderID]) [AssignmentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FolderID]=[Folders].[FolderID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] [Children] WHERE [Children].[ParentID]=[Folders].[FolderID]) [ChildCount] FROM [Folders] WHERE [FolderID]=[ParentID] SELECT [Assignments].[AID], [Assignments].[GID], [Assignments].[RID], [Assignments].[FolderID], [Assignments].[StartDate], [Assignments].[EndDate], [Assignments].[DTS], [Assignments].[UsrID], [Assignments].[LastChanged], [Groups].[GroupName] [Group_GroupName], [Groups].[GroupType] [Group_GroupType], [Groups].[Config] [Group_Config], [Groups].[DTS] [Group_DTS], [Groups].[UsrID] [Group_UsrID], [Roles].[Name] [Role_Name], [Roles].[Title] [Role_Title], [Roles].[DTS] [Role_DTS], [Roles].[UsrID] [Role_UsrID] FROM [Assignments] JOIN [Groups] ON [Groups].[GID]=[Assignments].[GID] JOIN [Roles] ON [Roles].[RID]=[Assignments].[RID] WHERE [Assignments].[FolderID]=(Select [FolderID] from [Folders] where [FolderID]=[ParentID]) SELECT [DocVersions].[VersionID], [DocVersions].[FolderID], [DocVersions].[VersionType], [DocVersions].[Name], [DocVersions].[Title], [DocVersions].[ItemID], [DocVersions].[FormatID], [DocVersions].[Config], [DocVersions].[DTS], [DocVersions].[UserID], [DocVersions].[LastChanged] FROM [DocVersions] WHERE [DocVersions].[FolderID]=(Select [FolderID] from [Folders] where [FolderID]=[ParentID]) RETURN GO /****** Object: StoredProcedure [dbo].[vesp_ListItemAndChildren] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- vesp_ListItemAndChildren 1,0 -- drop procedure [vesp_ListItemAndChildren] CREATE PROCEDURE [vesp_ListItemAndChildren] (@ItemID int, @ParentID int) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], @ParentID [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 [pContentID],[DTS] [pDTS], [UserID] [pUserID], [LastChanged] [pLastChanged] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID],P.[LastChanged] [pLastChanged] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID -- Siblings Union All select [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.[Level] > 0 ) select I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], [pContentID],[pDTS],[pUserID],[pLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[I].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount] from ItemZ I join Contents C on C.ContentID = I.ContentID order by I.[Level] , I.[FromType], I.[Ordinal] END GO /****** Object: StoredProcedure [dbo].[vesp_ListItems] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO --vesp_ListItems 1 CREATE PROCEDURE [vesp_ListItems] ( @ItemID int = 0 ) WITH EXECUTE AS OWNER AS BEGIN with Itemz(ItemID,PreviousID,ContentID,[DTS],[UserID],[LastChanged]) as ( Select ItemID,PreviousID,ContentID,[DTS],[UserID],[LastChanged] from Items where ItemID=@ItemID Union All -- Select C.ItemID,C.PreviousID,C.ContentID,C.[DTS],C.[UserID],C.[LastChanged] from Items C Join Itemz Z on C.PreviousID=Z.ItemID ) Select ItemID,PreviousID,ContentID,[DTS],[UserID],[LastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[Itemz].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[Itemz].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Children] WHERE [Children].[PreviousID]=[Itemz].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[Itemz].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[Itemz].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[Itemz].[ItemID]) [Transition_ToIDCount] from Itemz OPTION (MAXRECURSION 1000) END GO /****** Object: StoredProcedure [dbo].[vesp_ListItemsAndContent] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO --vesp_ListItemsAndContent 1 CREATE PROCEDURE [vesp_ListItemsAndContent] ( @ItemID int = 0 ) WITH EXECUTE AS OWNER AS BEGIN with Itemz(ItemID,PreviousID,ContentID,[DTS],[UserID],[LastChanged]) as ( Select ItemID,PreviousID,ContentID,[DTS],[UserID],[LastChanged] from Items where ItemID=@ItemID Union All -- Select I.ItemID,I.PreviousID,I.ContentID,I.[DTS],I.[UserID],I.[LastChanged] from Items I Join Itemz Z on I.PreviousID=Z.ItemID ) Select I.ItemID,I.PreviousID,I.ContentID,I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Children] WHERE [Children].[PreviousID]=[I].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount] from Itemz I Join Contents C on I.ContentID = C.ContentID OPTION (MAXRECURSION 1000) END GO /****** Object: StoredProcedure [dbo].[existsPdf] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsPdf] ( @DocID int, @DebugStatus int, @TopRow int, @PageLength int, @LeftMargin int, @PageWidth int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Pdfs] WHERE [DocID]=@DocID AND [DebugStatus]=@DebugStatus AND [TopRow]=@TopRow AND [PageLength]=@PageLength AND [LeftMargin]=@LeftMargin AND [PageWidth]=@PageWidth RETURN GO /****** Object: StoredProcedure [dbo].[getPdfs] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getPdfs] WITH EXECUTE AS OWNER AS SELECT [DocID], [DebugStatus], [TopRow], [PageLength], [LeftMargin], [PageWidth], [PageCount], [DocPdf], [DTS], [UserID], [LastChanged] FROM [Pdfs] RETURN GO /****** Object: StoredProcedure [dbo].[getPdfsByDocID] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getPdfsByDocID] ( @DocID int ) WITH EXECUTE AS OWNER AS SELECT [Pdfs].[DocID], [Pdfs].[DebugStatus], [Pdfs].[TopRow], [Pdfs].[PageLength], [Pdfs].[LeftMargin], [Pdfs].[PageWidth], [Pdfs].[PageCount], [Pdfs].[DocPdf], [Pdfs].[DTS], [Pdfs].[UserID], [Pdfs].[LastChanged] FROM [Pdfs] WHERE [Pdfs].[DocID]=@DocID RETURN GO /****** Object: StoredProcedure [dbo].[deletePdf] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deletePdf] ( @DocID int, @DebugStatus int, @TopRow int, @PageLength int, @LeftMargin int, @PageWidth int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Pdfs] WHERE [DocID] = @DocID AND [DebugStatus] = @DebugStatus AND [TopRow] = @TopRow AND [PageLength] = @PageLength AND [LeftMargin] = @LeftMargin AND [PageWidth] = @PageWidth IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getPdf] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getPdf] ( @DocID int, @DebugStatus int, @TopRow int, @PageLength int, @LeftMargin int, @PageWidth int ) WITH EXECUTE AS OWNER AS SELECT [DocID], [DebugStatus], [TopRow], [PageLength], [LeftMargin], [PageWidth], [PageCount], [DocPdf], [DTS], [UserID], [LastChanged] FROM [Pdfs] WHERE [DocID]=@DocID AND [DebugStatus]=@DebugStatus AND [TopRow]=@TopRow AND [PageLength]=@PageLength AND [LeftMargin]=@LeftMargin AND [PageWidth]=@PageWidth RETURN GO /****** Object: StoredProcedure [dbo].[getDocument] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getDocument] ( @DocID int ) WITH EXECUTE AS OWNER AS SELECT [DocID], [LibTitle], [DocContent], [DocAscii], [Config], [DTS], [UserID], [LastChanged], [FileExtension], (SELECT COUNT(*) FROM [DROUsages] WHERE [DROUsages].[DocID]=[Documents].[DocID]) [DROUsageCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[DocID]=[Documents].[DocID]) [EntryCount], (SELECT COUNT(*) FROM [Pdfs] WHERE [Pdfs].[DocID]=[Documents].[DocID]) [PdfCount] FROM [Documents] WHERE [DocID]=@DocID SELECT [DROUsages].[DROUsageID], [DROUsages].[DocID], [DROUsages].[ROID], [DROUsages].[Config], [DROUsages].[DTS], [DROUsages].[UserID], [DROUsages].[LastChanged], [DROUsages].[RODbID], [RODbs].[ROName] [RODb_ROName], [RODbs].[FolderPath] [RODb_FolderPath], [RODbs].[DBConnectionString] [RODb_DBConnectionString], [RODbs].[Config] [RODb_Config], [RODbs].[DTS] [RODb_DTS], [RODbs].[UserID] [RODb_UserID] FROM [DROUsages] JOIN [RODbs] ON [RODbs].[RODbID]=[DROUsages].[RODbID] WHERE [DROUsages].[DocID]=@DocID SELECT [Entries].[ContentID], [Entries].[DocID], [Entries].[DTS], [Entries].[UserID], [Entries].[LastChanged], [Contents].[Number] [Content_Number], [Contents].[Text] [Content_Text], [Contents].[Type] [Content_Type], [Contents].[FormatID] [Content_FormatID], [Contents].[Config] [Content_Config], [Contents].[DTS] [Content_DTS], [Contents].[UserID] [Content_UserID] FROM [Entries] JOIN [Contents] ON [Contents].[ContentID]=[Entries].[ContentID] WHERE [Entries].[DocID]=@DocID SELECT [Pdfs].[DocID], [Pdfs].[DebugStatus], [Pdfs].[TopRow], [Pdfs].[PageLength], [Pdfs].[LeftMargin], [Pdfs].[PageWidth], [Pdfs].[PageCount], [Pdfs].[DocPdf], [Pdfs].[DTS], [Pdfs].[UserID], [Pdfs].[LastChanged] FROM [Pdfs] WHERE [Pdfs].[DocID]=@DocID RETURN GO /****** Object: StoredProcedure [dbo].[getDocuments] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getDocuments] WITH EXECUTE AS OWNER AS SELECT [DocID], [LibTitle], [DocContent], [DocAscii], [Config], [DTS], [UserID], [LastChanged], [FileExtension], (SELECT COUNT(*) FROM [DROUsages] WHERE [DROUsages].[DocID]=[Documents].[DocID]) [DROUsageCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[DocID]=[Documents].[DocID]) [EntryCount], (SELECT COUNT(*) FROM [Pdfs] WHERE [Pdfs].[DocID]=[Documents].[DocID]) [PdfCount] FROM [Documents] RETURN GO /****** Object: StoredProcedure [dbo].[updatePdf] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updatePdf] ( @DocID int, @DebugStatus int, @TopRow int, @PageLength int, @LeftMargin int, @PageWidth int, @PageCount float, @DocPdf varbinary(MAX)=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Pdfs] SET [PageCount]=@PageCount, [DocPdf]=@DocPdf, [DTS]=@DTS, [UserID]=@UserID WHERE [DocID]=@DocID AND [DebugStatus]=@DebugStatus AND [TopRow]=@TopRow AND [PageLength]=@PageLength AND [LeftMargin]=@LeftMargin AND [PageWidth]=@PageWidth AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Pdfs] WHERE [DocID]=@DocID AND [DebugStatus]=@DebugStatus AND [TopRow]=@TopRow AND [PageLength]=@PageLength AND [LeftMargin]=@LeftMargin AND [PageWidth]=@PageWidth) RAISERROR('Pdf record has been deleted by another user', 16, 1) ELSE RAISERROR('Pdf has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Pdfs] WHERE [DocID]=@DocID AND [DebugStatus]=@DebugStatus AND [TopRow]=@TopRow AND [PageLength]=@PageLength AND [LeftMargin]=@LeftMargin AND [PageWidth]=@PageWidth IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[deleteAllPdfs] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteAllPdfs] ( @DocID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Pdfs] WHERE [DocID] = @DocID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[deleteDocument] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteDocument] ( @DocID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [DROUsages] WHERE [DocID]=@DocID DELETE [Entries] WHERE [DocID]=@DocID DELETE [Pdfs] WHERE [DocID]=@DocID DELETE [Documents] WHERE [DocID] = @DocID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getLibraryDocuments] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO --getLibraryDocuments CREATE PROCEDURE [getLibraryDocuments] WITH EXECUTE AS OWNER AS SELECT [DocID], [LibTitle], [DocContent], [DocAscii], [FileExtension], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [DROUsages] WHERE [DROUsages].[DocID]=[Documents].[DocID]) [DROUsageCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[DocID]=[Documents].[DocID]) [EntryCount], (SELECT COUNT(*) FROM [Pdfs] WHERE [Pdfs].[DocID]=[Documents].[DocID]) [PdfCount] FROM [Documents] where [LibTitle] <> '' order by [LibTitle] RETURN GO /****** Object: StoredProcedure [dbo].[addPdf] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addPdf] ( @DocID int, @DebugStatus int, @TopRow int, @PageLength int, @LeftMargin int, @PageWidth int, @PageCount float, @DocPdf varbinary(MAX)=null, @DTS datetime, @UserID nvarchar(100), @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Pdfs] ( [DocID], [DebugStatus], [TopRow], [PageLength], [LeftMargin], [PageWidth], [PageCount], [DocPdf], [DTS], [UserID] ) VALUES ( @DocID, @DebugStatus, @TopRow, @PageLength, @LeftMargin, @PageWidth, @PageCount, @DocPdf, @DTS, @UserID ) SELECT @newLastChanged=[LastChanged] FROM [Pdfs] WHERE [DocID]=@DocID AND [DebugStatus]=@DebugStatus AND [TopRow]=@TopRow AND [PageLength]=@PageLength AND [LeftMargin]=@LeftMargin AND [PageWidth]=@PageWidth IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[sp_creatediagram] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [sp_creatediagram] ( @diagramname sysname, @owner_id int = null, @version int, @definition varbinary(max) ) WITH EXECUTE AS 'dbo' AS BEGIN set nocount on declare @theId int declare @retval int declare @IsDbo int declare @userName sysname if(@version is null or @diagramname is null) begin RAISERROR (N'E_INVALIDARG', 16, 1); return -1 end execute as caller; select @theId = DATABASE_PRINCIPAL_ID(); select @IsDbo = IS_MEMBER(N'db_owner'); revert; if @owner_id is null begin select @owner_id = @theId; end else begin if @theId <> @owner_id begin if @IsDbo = 0 begin RAISERROR (N'E_INVALIDARG', 16, 1); return -1 end select @theId = @owner_id end end -- next 2 line only for test, will be removed after define name unique if EXISTS(select diagram_id from dbo.sysdiagrams where principal_id = @theId and name = @diagramname) begin RAISERROR ('The name is already used.', 16, 1); return -2 end insert into dbo.sysdiagrams(name, principal_id , version, definition) VALUES(@diagramname, @theId, @version, @definition) ; select @retval = @@IDENTITY return @retval END GO /****** Object: StoredProcedure [dbo].[sp_alterdiagram] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [sp_alterdiagram] ( @diagramname sysname, @owner_id int = null, @version int, @definition varbinary(max) ) WITH EXECUTE AS 'dbo' AS BEGIN set nocount on declare @theId int declare @retval int declare @IsDbo int declare @UIDFound int declare @DiagId int declare @ShouldChangeUID int if(@diagramname is null) begin RAISERROR ('Invalid ARG', 16, 1) return -1 end execute as caller; select @theId = DATABASE_PRINCIPAL_ID(); select @IsDbo = IS_MEMBER(N'db_owner'); if(@owner_id is null) select @owner_id = @theId; revert; select @ShouldChangeUID = 0 select @DiagId = diagram_id, @UIDFound = principal_id from dbo.sysdiagrams where principal_id = @owner_id and name = @diagramname if(@DiagId IS NULL or (@IsDbo = 0 and @theId <> @UIDFound)) begin RAISERROR ('Diagram does not exist or you do not have permission.', 16, 1); return -3 end if(@IsDbo <> 0) begin if(@UIDFound is null or USER_NAME(@UIDFound) is null) -- invalid principal_id begin select @ShouldChangeUID = 1 ; end end -- update dds data update dbo.sysdiagrams set definition = @definition where diagram_id = @DiagId ; -- change owner if(@ShouldChangeUID = 1) update dbo.sysdiagrams set principal_id = @theId where diagram_id = @DiagId ; -- update dds version if(@version is not null) update dbo.sysdiagrams set version = @version where diagram_id = @DiagId ; return 0 END GO /****** Object: StoredProcedure [dbo].[sp_dropdiagram] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [sp_dropdiagram] ( @diagramname sysname, @owner_id int = null ) WITH EXECUTE AS 'dbo' AS BEGIN set nocount on declare @theId int declare @IsDbo int declare @UIDFound int declare @DiagId int if(@diagramname is null) begin RAISERROR ('Invalid value', 16, 1); return -1 end EXECUTE AS CALLER; select @theId = DATABASE_PRINCIPAL_ID(); select @IsDbo = IS_MEMBER(N'db_owner'); if(@owner_id is null) select @owner_id = @theId; REVERT; select @DiagId = diagram_id, @UIDFound = principal_id from dbo.sysdiagrams where principal_id = @owner_id and name = @diagramname if(@DiagId IS NULL or (@IsDbo = 0 and @UIDFound <> @theId)) begin RAISERROR ('Diagram does not exist or you do not have permission.', 16, 1) return -3 end delete from dbo.sysdiagrams where diagram_id = @DiagId; return 0; END GO /****** Object: StoredProcedure [dbo].[sp_renamediagram] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [sp_renamediagram] ( @diagramname sysname, @owner_id int = null, @new_diagramname sysname ) WITH EXECUTE AS 'dbo' AS BEGIN set nocount on declare @theId int declare @IsDbo int declare @UIDFound int declare @DiagId int declare @DiagIdTarg int declare @u_name sysname if((@diagramname is null) or (@new_diagramname is null)) begin RAISERROR ('Invalid value', 16, 1); return -1 end EXECUTE AS CALLER; select @theId = DATABASE_PRINCIPAL_ID(); select @IsDbo = IS_MEMBER(N'db_owner'); if(@owner_id is null) select @owner_id = @theId; REVERT; select @u_name = USER_NAME(@owner_id) select @DiagId = diagram_id, @UIDFound = principal_id from dbo.sysdiagrams where principal_id = @owner_id and name = @diagramname if(@DiagId IS NULL or (@IsDbo = 0 and @UIDFound <> @theId)) begin RAISERROR ('Diagram does not exist or you do not have permission.', 16, 1) return -3 end -- if((@u_name is not null) and (@new_diagramname = @diagramname)) -- nothing will change -- return 0; if(@u_name is null) select @DiagIdTarg = diagram_id from dbo.sysdiagrams where principal_id = @theId and name = @new_diagramname else select @DiagIdTarg = diagram_id from dbo.sysdiagrams where principal_id = @owner_id and name = @new_diagramname if((@DiagIdTarg is not null) and @DiagId <> @DiagIdTarg) begin RAISERROR ('The name is already used.', 16, 1); return -2 end if(@u_name is null) update dbo.sysdiagrams set [name] = @new_diagramname, principal_id = @theId where diagram_id = @DiagId else update dbo.sysdiagrams set [name] = @new_diagramname where diagram_id = @DiagId return 0 END GO /****** Object: StoredProcedure [dbo].[sp_helpdiagramdefinition] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [sp_helpdiagramdefinition] ( @diagramname sysname, @owner_id int = null ) WITH EXECUTE AS N'dbo' AS BEGIN set nocount on declare @theId int declare @IsDbo int declare @DiagId int declare @UIDFound int if(@diagramname is null) begin RAISERROR (N'E_INVALIDARG', 16, 1); return -1 end execute as caller; select @theId = DATABASE_PRINCIPAL_ID(); select @IsDbo = IS_MEMBER(N'db_owner'); if(@owner_id is null) select @owner_id = @theId; revert; select @DiagId = diagram_id, @UIDFound = principal_id from dbo.sysdiagrams where principal_id = @owner_id and name = @diagramname; if(@DiagId IS NULL or (@IsDbo = 0 and @UIDFound <> @theId )) begin RAISERROR ('Diagram does not exist or you do not have permission.', 16, 1); return -3 end select version, definition FROM dbo.sysdiagrams where diagram_id = @DiagId ; return 0 END GO /****** Object: StoredProcedure [dbo].[sp_helpdiagrams] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [sp_helpdiagrams] ( @diagramname sysname = NULL, @owner_id int = NULL ) WITH EXECUTE AS N'dbo' AS BEGIN DECLARE @user sysname DECLARE @dboLogin bit EXECUTE AS CALLER; SET @user = USER_NAME(); SET @dboLogin = CONVERT(bit,IS_MEMBER('db_owner')); REVERT; SELECT [Database] = DB_NAME(), [Name] = name, [ID] = diagram_id, [Owner] = USER_NAME(principal_id), [OwnerID] = principal_id FROM sysdiagrams WHERE (@dboLogin = 1 OR USER_NAME(principal_id) = @user) AND (@diagramname IS NULL OR name = @diagramname) AND (@owner_id IS NULL OR principal_id = @owner_id) ORDER BY 4, 5, 1 END GO /****** Object: StoredProcedure [dbo].[existsConnection] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsConnection] ( @DBID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Connections] WHERE [DBID]=@DBID RETURN GO /****** Object: StoredProcedure [dbo].[updateConnection] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateConnection] ( @DBID int, @Name nvarchar(100)=null, @Title nvarchar(510)=null, @ConnectionString nvarchar(510)=null, @ServerType int, @Config nvarchar(MAX)=null, @DTS datetime, @UsrID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Connections] SET [Name]=@Name, [Title]=@Title, [ConnectionString]=@ConnectionString, [ServerType]=@ServerType, [Config]=@Config, [DTS]=@DTS, [UsrID]=@UsrID WHERE [DBID]=@DBID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Connections] WHERE [DBID]=@DBID) RAISERROR('Connection record has been deleted by another user', 16, 1) ELSE RAISERROR('Connection has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Connections] WHERE [DBID]=@DBID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getConnection] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getConnection] ( @DBID int ) WITH EXECUTE AS OWNER AS SELECT [DBID], [Name], [Title], [ConnectionString], [ServerType], [Config], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[DBID]=[Connections].[DBID]) [FolderCount] FROM [Connections] WHERE [DBID]=@DBID SELECT [Folders].[FolderID], [Folders].[ParentID], [Folders].[DBID], [Folders].[Name], [Folders].[Title], [Folders].[ShortName], [Folders].[FormatID], [Folders].[ManualOrder], [Folders].[Config], [Folders].[DTS], [Folders].[UsrID], [Folders].[LastChanged] FROM [Folders] WHERE [Folders].[DBID]=@DBID RETURN GO /****** Object: StoredProcedure [dbo].[getConnectionByName] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getConnectionByName] ( @Name nvarchar(100) ) WITH EXECUTE AS OWNER AS SELECT [DBID], [Name], [Title], [ConnectionString], [ServerType], [Config], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[DBID]=[Connections].[DBID]) [FolderCount] FROM [Connections] WHERE [Name]=@Name RETURN GO /****** Object: StoredProcedure [dbo].[getConnections] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getConnections] WITH EXECUTE AS OWNER AS SELECT [DBID], [Name], [Title], [ConnectionString], [ServerType], [Config], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[DBID]=[Connections].[DBID]) [FolderCount] FROM [Connections] RETURN GO /****** Object: StoredProcedure [dbo].[addConnection] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addConnection] ( @Name nvarchar(100)=null, @Title nvarchar(510)=null, @ConnectionString nvarchar(510)=null, @ServerType int, @Config nvarchar(MAX)=null, @DTS datetime, @UsrID nvarchar(100), @newDBID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Connections] ( [Name], [Title], [ConnectionString], [ServerType], [Config], [DTS], [UsrID] ) VALUES ( @Name, @Title, @ConnectionString, @ServerType, @Config, @DTS, @UsrID ) SELECT @newDBID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Connections] WHERE [DBID]=@newDBID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[deleteConnection] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteConnection] ( @DBID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Folders] WHERE [DBID]=@DBID DELETE [Connections] WHERE [DBID] = @DBID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[addRODb] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addRODb] ( @ROName nvarchar(255), @FolderPath nvarchar(255), @DBConnectionString nvarchar(MAX), @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @newRODbID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [RODbs] ( [ROName], [FolderPath], [DBConnectionString], [Config], [DTS], [UserID] ) VALUES ( @ROName, @FolderPath, @DBConnectionString, @Config, @DTS, @UserID ) SELECT @newRODbID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [RODbs] WHERE [RODbID]=@newRODbID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getJustRODb] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getJustRODb] ( @RODbID int ) WITH EXECUTE AS OWNER AS SELECT [RODbID], [ROName], [FolderPath], [DBConnectionString], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [DROUsages] WHERE [DROUsages].[RODbID]=[RODbs].[RODbID]) [DROUsageCount], (SELECT COUNT(*) FROM [ROFsts] WHERE [ROFsts].[RODbID]=[RODbs].[RODbID]) [ROFstCount], (SELECT COUNT(*) FROM [ROImages] WHERE [ROImages].[RODbID]=[RODbs].[RODbID]) [ROImageCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[RODbID]=[RODbs].[RODbID]) [RoUsageCount] FROM [RODbs] WHERE [RODbID]=@RODbID RETURN GO /****** Object: StoredProcedure [dbo].[getDROUsagesByDocID] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getDROUsagesByDocID] ( @DocID int ) WITH EXECUTE AS OWNER AS SELECT [DROUsages].[DROUsageID], [DROUsages].[DocID], [DROUsages].[ROID], [DROUsages].[Config], [DROUsages].[DTS], [DROUsages].[UserID], [DROUsages].[LastChanged], [DROUsages].[RODbID], [RODbs].[ROName] [RODb_ROName], [RODbs].[FolderPath] [RODb_FolderPath], [RODbs].[DBConnectionString] [RODb_DBConnectionString], [RODbs].[Config] [RODb_Config], [RODbs].[DTS] [RODb_DTS], [RODbs].[UserID] [RODb_UserID] FROM [DROUsages] JOIN [RODbs] ON [RODbs].[RODbID]=[DROUsages].[RODbID] WHERE [DROUsages].[DocID]=@DocID RETURN GO /****** Object: StoredProcedure [dbo].[updateRODb] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateRODb] ( @RODbID int, @ROName nvarchar(255), @FolderPath nvarchar(255), @DBConnectionString nvarchar(MAX), @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [RODbs] SET [ROName]=@ROName, [FolderPath]=@FolderPath, [DBConnectionString]=@DBConnectionString, [Config]=@Config, [DTS]=@DTS, [UserID]=@UserID WHERE [RODbID]=@RODbID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [RODbs] WHERE [RODbID]=@RODbID) RAISERROR('RODb record has been deleted by another user', 16, 1) ELSE RAISERROR('RODb has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [RODbs] WHERE [RODbID]=@RODbID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getContent] Script Date: 01/06/2012 15:02:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getContent] ( @ContentID int ) WITH EXECUTE AS OWNER AS SELECT [ContentID], [Number], [Text], [Type], [FormatID], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[Contents].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[Contents].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[Contents].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[Contents].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[Contents].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[Contents].[ContentID]) [PartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[Contents].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[Contents].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[Contents].[ContentID]) [ZContentCount] FROM [Contents] WHERE [ContentID]=@ContentID SELECT [Details].[DetailID], [Details].[ContentID], [Details].[ItemType], [Details].[Text], [Details].[Config], [Details].[DTS], [Details].[UserID], [Details].[LastChanged] FROM [Details] WHERE [Details].[ContentID]=@ContentID SELECT [Entries].[ContentID], [Entries].[DocID], [Entries].[DTS], [Entries].[UserID], [Entries].[LastChanged], [Documents].[LibTitle] [Document_LibTitle], [Documents].[DocContent] [Document_DocContent], [Documents].[DocAscii] [Document_DocAscii], [Documents].[Config] [Document_Config], [Documents].[DTS] [Document_DTS], [Documents].[UserID] [Document_UserID], [Documents].[FileExtension] [Document_FileExtension] FROM [Entries] JOIN [Documents] ON [Documents].[DocID]=[Entries].[DocID] WHERE [Entries].[ContentID]=@ContentID SELECT [Grids].[ContentID], [Grids].[Data], [Grids].[Config], [Grids].[DTS], [Grids].[UserID], [Grids].[LastChanged] FROM [Grids] WHERE [Grids].[ContentID]=@ContentID SELECT [Images].[ContentID], [Images].[ImageType], [Images].[FileName], [Images].[Data], [Images].[Config], [Images].[DTS], [Images].[UserID], [Images].[LastChanged] FROM [Images] WHERE [Images].[ContentID]=@ContentID SELECT [Items].[ItemID], [Items].[PreviousID], [Items].[ContentID], [Items].[DTS], [Items].[UserID], [Items].[LastChanged] FROM [Items] WHERE [Items].[ContentID]=@ContentID SELECT [Parts].[ContentID], [Parts].[FromType], [Parts].[ItemID], [Parts].[DTS], [Parts].[UserID], [Parts].[LastChanged], [Items].[PreviousID] [Item_PreviousID], [Items].[ContentID] [Item_ContentID], [Items].[DTS] [Item_DTS], [Items].[UserID] [Item_UserID] FROM [Parts] JOIN [Items] ON [Items].[ItemID]=[Parts].[ItemID] WHERE [Parts].[ContentID]=@ContentID SELECT [RoUsages].[ROUsageID], [RoUsages].[ContentID], [RoUsages].[ROID], [RoUsages].[Config], [RoUsages].[DTS], [RoUsages].[UserID], [RoUsages].[LastChanged], [RoUsages].[RODbID], [RODbs].[ROName] [RODb_ROName], [RODbs].[FolderPath] [RODb_FolderPath], [RODbs].[DBConnectionString] [RODb_DBConnectionString], [RODbs].[Config] [RODb_Config], [RODbs].[DTS] [RODb_DTS], [RODbs].[UserID] [RODb_UserID] FROM [RoUsages] JOIN [RODbs] ON [RODbs].[RODbID]=[RoUsages].[RODbID] WHERE [RoUsages].[ContentID]=@ContentID SELECT [Transitions].[TransitionID], [Transitions].[FromID], [Transitions].[ToID], [Transitions].[RangeID], [Transitions].[IsRange], [Transitions].[TranType], [Transitions].[Config], [Transitions].[DTS], [Transitions].[UserID], [Transitions].[LastChanged], [Items_RangeID].[PreviousID] [Item_RangeID_PreviousID], [Items_RangeID].[ContentID] [Item_RangeID_ContentID], [Items_RangeID].[DTS] [Item_RangeID_DTS], [Items_RangeID].[UserID] [Item_RangeID_UserID], [Items_ToID].[PreviousID] [Item_ToID_PreviousID], [Items_ToID].[ContentID] [Item_ToID_ContentID], [Items_ToID].[DTS] [Item_ToID_DTS], [Items_ToID].[UserID] [Item_ToID_UserID] FROM [Transitions] JOIN [Items] [Items_RangeID] ON [Items_RangeID].[ItemID]=[Transitions].[RangeID] JOIN [Items] [Items_ToID] ON [Items_ToID].[ItemID]=[Transitions].[ToID] WHERE [Transitions].[FromID]=@ContentID SELECT [ZContents].[ContentID], [ZContents].[OldStepSequence], [ZContents].[LastChanged] FROM [ZContents] WHERE [ZContents].[ContentID]=@ContentID RETURN GO /****** Object: UserDefinedFunction [dbo].[vefn_SplitROSearch] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select * from vefn_SplitROSearch(null) select * from vefn_SplitROSearch('') select * from vefn_SplitROSearch('1') select * from vefn_SplitROSearch('1:0001') select * from vefn_SplitROSearch('1:0001000019C') select * from vefn_SplitROSearch('1:0001000019C,0001000019D') */ CREATE FUNCTION [vefn_SplitROSearch](@text varchar(MAX)='') RETURNS @ROIDSearch TABLE ( RODBID int, ROID varchar(16) --,CONSTRAINT ROIDSearchPK PRIMARY KEY(RODBID, ROID) ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @index int IF(isnull(@text,'') = '') BEGIN Insert into @ROIDSearch Select RODBID, '' from RODbs RETURN END SET @index = CHARINDEX(':' , @text) DECLARE @RODBID int IF (@index = 0) AND (LEN(@text) > 0) BEGIN SET @RODBID = CAST(@text AS INT) INSERT INTO @ROIDSearch VALUES (@RODBID,'') SET @Text='' END ELSE BEGIN SET @RODBID = CAST(LEFT(@text, @index - 1) AS INT) SET @text = RIGHT(@text, (LEN(@text) - @index)) SET @index = -1 END SET @text = RIGHT(@text, (LEN(@text) - @index)) WHILE (LEN(@text) > 0) BEGIN SET @index = CHARINDEX(',' , @text) IF (@index = 0) AND (LEN(@text) > 0) BEGIN INSERT INTO @ROIDSearch VALUES (@RODBID,@text) BREAK END IF (@index > 1) BEGIN INSERT INTO @ROIDSearch VALUES (@RODBID,LEFT(@text, @index - 1)) SET @text = RIGHT(@text, (LEN(@text) - @index)) END ELSE SET @text = RIGHT(@text, (LEN(@text) - @index)) END RETURN END GO /****** Object: StoredProcedure [dbo].[getRODbByFolderPath] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getRODbByFolderPath] ( @FolderPath nvarchar(255) ) WITH EXECUTE AS OWNER AS SELECT [RODbID], [ROName], [FolderPath], [DBConnectionString], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [DROUsages] WHERE [DROUsages].[RODbID]=[RODbs].[RODbID]) [DROUsageCount], (SELECT COUNT(*) FROM [ROFsts] WHERE [ROFsts].[RODbID]=[RODbs].[RODbID]) [ROFstCount], (SELECT COUNT(*) FROM [ROImages] WHERE [ROImages].[RODbID]=[RODbs].[RODbID]) [ROImageCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[RODbID]=[RODbs].[RODbID]) [RoUsageCount] FROM [RODbs] WHERE [FolderPath]=@FolderPath RETURN GO /****** Object: StoredProcedure [dbo].[getRODbs] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getRODbs] WITH EXECUTE AS OWNER AS SELECT [RODbID], [ROName], [FolderPath], [DBConnectionString], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [DROUsages] WHERE [DROUsages].[RODbID]=[RODbs].[RODbID]) [DROUsageCount], (SELECT COUNT(*) FROM [ROFsts] WHERE [ROFsts].[RODbID]=[RODbs].[RODbID]) [ROFstCount], (SELECT COUNT(*) FROM [ROImages] WHERE [ROImages].[RODbID]=[RODbs].[RODbID]) [ROImageCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[RODbID]=[RODbs].[RODbID]) [RoUsageCount] FROM [RODbs] RETURN GO /****** Object: StoredProcedure [dbo].[deleteRODb] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteRODb] ( @RODbID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [DROUsages] WHERE [RODbID]=@RODbID DELETE [ROFsts] WHERE [RODbID]=@RODbID DELETE [ROImages] WHERE [RODbID]=@RODbID DELETE [RoUsages] WHERE [RODbID]=@RODbID DELETE [RODbs] WHERE [RODbID] = @RODbID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getRODb] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getRODb] ( @RODbID int ) WITH EXECUTE AS OWNER AS SELECT [RODbID], [ROName], [FolderPath], [DBConnectionString], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [DROUsages] WHERE [DROUsages].[RODbID]=[RODbs].[RODbID]) [DROUsageCount], (SELECT COUNT(*) FROM [ROFsts] WHERE [ROFsts].[RODbID]=[RODbs].[RODbID]) [ROFstCount], (SELECT COUNT(*) FROM [ROImages] WHERE [ROImages].[RODbID]=[RODbs].[RODbID]) [ROImageCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[RODbID]=[RODbs].[RODbID]) [RoUsageCount] FROM [RODbs] WHERE [RODbID]=@RODbID SELECT [DROUsages].[DROUsageID], [DROUsages].[DocID], [DROUsages].[ROID], [DROUsages].[Config], [DROUsages].[DTS], [DROUsages].[UserID], [DROUsages].[LastChanged], [DROUsages].[RODbID], [Documents].[LibTitle] [Document_LibTitle], [Documents].[DocContent] [Document_DocContent], [Documents].[DocAscii] [Document_DocAscii], [Documents].[Config] [Document_Config], [Documents].[DTS] [Document_DTS], [Documents].[UserID] [Document_UserID], [Documents].[FileExtension] [Document_FileExtension] FROM [DROUsages] JOIN [Documents] ON [Documents].[DocID]=[DROUsages].[DocID] WHERE [DROUsages].[RODbID]=@RODbID SELECT [ROFsts].[ROFstID], [ROFsts].[RODbID], [ROFsts].[ROLookup], [ROFsts].[Config], [ROFsts].[DTS], [ROFsts].[UserID], [ROFsts].[LastChanged] FROM [ROFsts] WHERE [ROFsts].[RODbID]=@RODbID SELECT [ROImages].[ImageID], [ROImages].[RODbID], [ROImages].[FileName], [ROImages].[Content], [ROImages].[Config], [ROImages].[DTS], [ROImages].[UserID], [ROImages].[LastChanged] FROM [ROImages] WHERE [ROImages].[RODbID]=@RODbID SELECT [RoUsages].[ROUsageID], [RoUsages].[ContentID], [RoUsages].[ROID], [RoUsages].[Config], [RoUsages].[DTS], [RoUsages].[UserID], [RoUsages].[LastChanged], [RoUsages].[RODbID], [Contents].[Number] [Content_Number], [Contents].[Text] [Content_Text], [Contents].[Type] [Content_Type], [Contents].[FormatID] [Content_FormatID], [Contents].[Config] [Content_Config], [Contents].[DTS] [Content_DTS], [Contents].[UserID] [Content_UserID] FROM [RoUsages] JOIN [Contents] ON [Contents].[ContentID]=[RoUsages].[ContentID] WHERE [RoUsages].[RODbID]=@RODbID RETURN GO /****** Object: StoredProcedure [dbo].[getRoUsagesByContentID] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getRoUsagesByContentID] ( @ContentID int ) WITH EXECUTE AS OWNER AS SELECT [RoUsages].[ROUsageID], [RoUsages].[ContentID], [RoUsages].[ROID], [RoUsages].[Config], [RoUsages].[DTS], [RoUsages].[UserID], [RoUsages].[LastChanged], [RoUsages].[RODbID], [RODbs].[ROName] [RODb_ROName], [RODbs].[FolderPath] [RODb_FolderPath], [RODbs].[DBConnectionString] [RODb_DBConnectionString], [RODbs].[Config] [RODb_Config], [RODbs].[DTS] [RODb_DTS], [RODbs].[UserID] [RODb_UserID] FROM [RoUsages] JOIN [RODbs] ON [RODbs].[RODbID]=[RoUsages].[RODbID] WHERE [RoUsages].[ContentID]=@ContentID RETURN GO /****** Object: StoredProcedure [dbo].[existsRODb] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsRODb] ( @RODbID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [RODbs] WHERE [RODbID]=@RODbID RETURN GO /****** Object: StoredProcedure [dbo].[deleteROFst] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteROFst] ( @ROFstID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Associations] WHERE [ROFstID]=@ROFstID DELETE [Figures] WHERE [ROFstID]=@ROFstID DELETE [ROFsts] WHERE [ROFstID] = @ROFstID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getROFstByRODbID_DTS] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getROFstByRODbID_DTS] ( @RODbID int, @DTS datetime ) WITH EXECUTE AS OWNER AS SELECT [ROFstID], [RODbID], [ROLookup], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Associations] WHERE [Associations].[ROFstID]=[ROFsts].[ROFstID]) [AssociationCount], (SELECT COUNT(*) FROM [Figures] WHERE [Figures].[ROFstID]=[ROFsts].[ROFstID]) [FigureCount] FROM [ROFsts] WHERE [RODbID]=@RODbID AND [DTS]=@DTS RETURN GO /****** Object: StoredProcedure [dbo].[existsAssociation] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsAssociation] ( @AssociationID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Associations] WHERE [AssociationID]=@AssociationID RETURN GO /****** Object: StoredProcedure [dbo].[getROFstsByRODbID] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getROFstsByRODbID] ( @RODbID int ) WITH EXECUTE AS OWNER AS SELECT [ROFsts].[ROFstID], [ROFsts].[RODbID], [ROFsts].[ROLookup], [ROFsts].[Config], [ROFsts].[DTS], [ROFsts].[UserID], [ROFsts].[LastChanged], (SELECT COUNT(*) FROM [Associations] WHERE [Associations].[ROFstID]=[ROFsts].[ROFstID]) [AssociationCount], (SELECT COUNT(*) FROM [Figures] WHERE [Figures].[ROFstID]=[ROFsts].[ROFstID]) [FigureCount] FROM [ROFsts] WHERE [ROFsts].[RODbID]=@RODbID RETURN GO /****** Object: StoredProcedure [dbo].[getROFsts] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getROFsts] WITH EXECUTE AS OWNER AS SELECT [ROFstID], [RODbID], [ROLookup], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Associations] WHERE [Associations].[ROFstID]=[ROFsts].[ROFstID]) [AssociationCount], (SELECT COUNT(*) FROM [Figures] WHERE [Figures].[ROFstID]=[ROFsts].[ROFstID]) [FigureCount] FROM [ROFsts] RETURN GO /****** Object: StoredProcedure [dbo].[getRoFstBySize] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* getRoFstBySize 1,74928 */ create PROCEDURE [getRoFstBySize] ( @RODbID int, @Len int ) WITH EXECUTE AS OWNER AS select [ROFstID], [RODbID], [ROLookup], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Associations] WHERE [Associations].[ROFstID]=[ROFsts].[ROFstID]) [AssociationCount], (SELECT COUNT(*) FROM [Figures] WHERE [Figures].[ROFstID]=[ROFsts].[ROFstID]) [FigureCount] from [ROFsts] where len(rolookup) = @len and [RODbID] = @RODbID RETURN GO /****** Object: StoredProcedure [dbo].[getAssociation] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getAssociation] ( @AssociationID int ) WITH EXECUTE AS OWNER AS SELECT [AssociationID], [VersionID], [ROFstID], [Config], [DTS], [UserID], [LastChanged] FROM [Associations] WHERE [AssociationID]=@AssociationID RETURN GO /****** Object: StoredProcedure [dbo].[updateAssociation] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateAssociation] ( @AssociationID int, @VersionID int, @ROFstID int, @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Associations] SET [VersionID]=@VersionID, [ROFstID]=@ROFstID, [Config]=@Config, [DTS]=@DTS, [UserID]=@UserID WHERE [AssociationID]=@AssociationID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Associations] WHERE [AssociationID]=@AssociationID) RAISERROR('Association record has been deleted by another user', 16, 1) ELSE RAISERROR('Association has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Associations] WHERE [AssociationID]=@AssociationID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getAssociationsByVersionID] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getAssociationsByVersionID] ( @VersionID int ) WITH EXECUTE AS OWNER AS SELECT [Associations].[AssociationID], [Associations].[VersionID], [Associations].[ROFstID], [Associations].[Config], [Associations].[DTS], [Associations].[UserID], [Associations].[LastChanged], [ROFsts].[RODbID] [ROFst_RODbID], [ROFsts].[ROLookup] [ROFst_ROLookup], [ROFsts].[Config] [ROFst_Config], [ROFsts].[DTS] [ROFst_DTS], [ROFsts].[UserID] [ROFst_UserID] FROM [Associations] JOIN [ROFsts] ON [ROFsts].[ROFstID]=[Associations].[ROFstID] WHERE [Associations].[VersionID]=@VersionID RETURN GO /****** Object: StoredProcedure [dbo].[getAssociations] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getAssociations] WITH EXECUTE AS OWNER AS SELECT [AssociationID], [VersionID], [ROFstID], [Config], [DTS], [UserID], [LastChanged] FROM [Associations] RETURN GO /****** Object: StoredProcedure [dbo].[getAssociationByVersionID_ROFstID] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getAssociationByVersionID_ROFstID] ( @VersionID int, @ROFstID int ) WITH EXECUTE AS OWNER AS SELECT [AssociationID], [VersionID], [ROFstID], [Config], [DTS], [UserID], [LastChanged] FROM [Associations] WHERE [VersionID]=@VersionID AND [ROFstID]=@ROFstID RETURN GO /****** Object: StoredProcedure [dbo].[addAssociation] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addAssociation] ( @VersionID int, @ROFstID int, @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @newAssociationID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Associations] ( [VersionID], [ROFstID], [Config], [DTS], [UserID] ) VALUES ( @VersionID, @ROFstID, @Config, @DTS, @UserID ) SELECT @newAssociationID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Associations] WHERE [AssociationID]=@newAssociationID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getJustROFst] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getJustROFst] ( @ROFstID int ) WITH EXECUTE AS OWNER AS SELECT [ROFstID], [RODbID], [ROLookup], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Associations] WHERE [Associations].[ROFstID]=[ROFsts].[ROFstID]) [AssociationCount], (SELECT COUNT(*) FROM [Figures] WHERE [Figures].[ROFstID]=[ROFsts].[ROFstID]) [FigureCount] FROM [ROFsts] WHERE [ROFstID]=@ROFstID RETURN GO /****** Object: StoredProcedure [dbo].[deleteAssociation] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteAssociation] ( @AssociationID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Associations] WHERE [AssociationID] = @AssociationID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[deleteContent] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteContent] ( @ContentID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Details] WHERE [ContentID]=@ContentID DELETE [Entries] WHERE [ContentID]=@ContentID DELETE [Grids] WHERE [ContentID]=@ContentID DELETE [Images] WHERE [ContentID]=@ContentID DELETE [Items] WHERE [ContentID]=@ContentID DELETE [Parts] WHERE [ContentID]=@ContentID DELETE [RoUsages] WHERE [ContentID]=@ContentID DELETE [Transitions] WHERE [FromID]=@ContentID DELETE [ZContents] WHERE [ContentID]=@ContentID DELETE [Contents] WHERE [ContentID] = @ContentID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[deleteEntry] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteEntry] ( @ContentID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Entries] WHERE [ContentID] = @ContentID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[CopyItemAndChildren] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [CopyItemAndChildren] ( @StartItemID INT, @DestFormatID INT, @UserID NVARCHAR(100), @NewStartItemID int output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block --+-----------------------------------------------------------------+ --¦ BEGIN TRANSACTION to make these changes temporary ¦ --+-----------------------------------------------------------------+ BEGIN TRANSACTION DECLARE @Children AS TABLE ( ItemID INT PRIMARY KEY, NewItemID INT, ContentID INT, NewContentID INT, FormatID INT, NewFormatID INT ) DECLARE @NewDocuments AS TABLE ( DocID INT PRIMARY KEY, NewDocID INT ) -- Locals DECLARE @DTS DATETIME -- DTS of all New Items SET @DTS = GETDATE() -- Get the current Date and Time -- Get a list of all of the Items to be copied based upon StartItemID and EndItemID -- If the StartItemID = EndItemID then it is a single item and it's children INSERT INTO @Children SELECT ItemID,ItemID,ContentID,ContentID,FormatID,FormatID FROM vefn_ChildItemsRange(@StartItemID,@StartItemID,null) -- <<< Copy Contents >>> -- Create new content rows to match the existing rows. Set the type to the Current ContentID temporarily -- so that the new content rows can be associated with the existing content rows. INSERT INTO Contents ([Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID]) select [Number],[Text],[ContentID],[FormatID],[Config],@DTS,@UserID from Contents where ContentID in(Select ContentID from @Children) -- Update the @Children with the NewConentIDs UPDATE NN set NN.NewContentID = CC.ContentID From Contents CC Join @Children NN on NN.ContentID = CC.Type AND CC.DTS = @DTS and CC.UserID = @UserID -- Reset the Type column in the Contents table with the Type column from the original Records. UPDATE CC set CC.Type = CC2.Type From Contents CC Join @Children NN on NN.NewContentID = CC.ContentID Join Contents CC2 on NN.ContentID = CC2.ContentID -- Contents are done -- SELECT * From Contents where DTS = @DTS and UserID = @UserID -- <<< Copy Grids >>> INSERT INTO [Grids]([ContentID],[Data],[Config],[DTS],[UserID]) SELECT NN.[NewContentID],[Data],[Config],@DTS,@UserID FROM [Grids] GG Join @Children NN on GG.ContentID = NN.ContentID -- <<< Copy Images >>> INSERT INTO [Images]([ContentID],[ImageType],[FileName],[Data],[Config],[DTS],[UserID]) SELECT NN.[NewContentID],[ImageType],[FileName],[Data],[Config],@DTS,@UserID FROM [Images] II Join @Children NN on II.ContentID = NN.ContentID -- Create new item rows based upon the current item rows and the @Children table, with the NewContentIDs INSERT INTO [Items] ([PreviousID],[ContentID],[DTS],[UserID]) SELECT II.[PreviousID], -- Leave the PreviousID as is for now NN.NewContentID, @DTS, @UserID from @Children NN join Items II on II.ContentID = NN.ContentID -- Update the @Children with the NewItemIDs UPDATE NN set NN.NewItemID = II.ItemID From Items II Join @Children NN on NN.NewContentID = II.ContentID AND II.DTS = @DTS and II.UserID = @UserID DECLARE @NewItemID int SELECT @NewItemID = NewItemID FROM @Children WHERE ItemID = @StartItemID UPDATE NN SET NN.[NewFormatID] = CC.[FormatID] FROM @Children NN Join vefn_ChildItemsRange(@NewItemID,@NewItemID,@DestFormatID) CC ON NN.NewItemID = CC.ItemID -- The @Children table is now complete --SELECT * From @Children -- Update the PreviousID in the new Item rows, to the new ItemIDs based upon the old ItemIDs Update II Set II.[PreviousID] = NN.NewItemID from Items II Join @Children NN on NN.ItemID = II.PreviousID AND II.DTS = @DTS and II.UserID = @UserID -- Get the new ItemIDs based upon the old ItemIDs SELECT @NewStartItemID = NewItemID from @Children where ItemID = @StartItemID --SELECT @NewEndItemID = NewItemID from @Children where ItemID = @EndItemID -- Set the PreviousID for the starting Item to null temporarily. -- This will be adjusted based upon where the step is inserted. Update Items Set PreviousID = null where ItemID = @NewStartItemID -- Items are done --SELECT * From Items where DTS = @DTS and UserID = @UserID -- <<< Copy Parts >>> INSERT INTO [Parts] ([ContentID],[FromType],[ItemID],[DTS],[UserID]) Select NNF.NewContentID,[FromType],NNT.NewItemID, @DTS, @UserID from Parts PP JOIN @Children NNF on PP.ContentID = NNF.ContentID JOIN @Children NNT on PP.ItemID = NNT.ItemID -- Parts are done -- SELECT * From Parts where DTS = @DTS and UserID = @UserID -- <<< Copy Annotations >>> INSERT INTO [Annotations] ([ItemID],[TypeID],[RtfText],[SearchText],[Config],[DTS],[UserID]) Select NewItemID, TypeID, RtfText, SearchText, Config, @DTS, @UserID from Annotations AA Join @Children NN on AA.ItemID = NN.ItemID -- Annotations are done -- SELECT * From Annotations where DTS = @DTS and UserID = @UserID -- <<< Copy Documents and Entries>>> -- logic to create Entries for Library Documents INSERT INTO [Entries] ([ContentID],[DocID],[DTS],[UserID]) SELECT NN.[NewContentID],EE.[DocID],@DTS,@UserID FROM [Entries] EE JOIN @Children NN on NN.ContentID = EE.ContentID JOIN [Documents] DD on EE.[DocID] = DD.[DocID] and Isnull(LibTitle,'') <> '' -- Logic to create new documents for any documents used that do not have libtitles INSERT INTO [Documents] ([LibTitle],[DocContent],[DocAscii],[Config],[DTS],[UserID],[FileExtension]) OUTPUT CAST(INSERTED.[LibTitle] as INT),INSERTED.[DocID] INTO @NewDocuments SELECT str(DD.[DocID]),[DocContent],[DocAscii],[Config],@DTS,@UserID,[FileExtension] FROM [Entries] EE JOIN @Children NN on NN.ContentID = EE.ContentID JOIN [Documents] DD on EE.[DocID] = DD.[DocID] and Isnull(LibTitle,'') = '' UPDATE DD SET LibTitle = '' FROM Documents DD JOIN @NewDocuments ND on DD.[DocID] = ND.[NewDocID] where DTS = @DTS and UserID = @UserID -- Documents are Done -- SELECT * From Documents where DTS = @DTS and UserID = @UserID -- Logic to create entries for these newly created documents INSERT INTO [Entries] ([ContentID],[DocID],[DTS],[UserID]) SELECT NN.[NewContentID],ND.[NewDocID],@DTS,@UserID FROM [Entries] EE JOIN @Children NN on NN.ContentID = EE.ContentID JOIN @NewDocuments ND on EE.[DocID] = ND.[DocID] -- Logic to Create DROUsages for these newly created documents INSERT INTO [DROUsages] ([DocID],[ROID],[Config],[DTS],[UserID],[RODbID]) SELECT ND.[NewDocID],[ROID],[Config],@DTS,@UserID,[RODbID] FROM [DROUsages] RR JOIN @NewDocuments ND on RR.[DocID] = ND.[DocID] -- Entries are done -- SELECT * From Entries EE JOIN Documents DD on ee.DocID = DD.DocID where EE.DTS = @DTS and EE.UserID = @UserID -- <<< Copy RoUsages >>> INSERT INTO [RoUsages] ([ContentID],[ROID],[Config],[DTS],[UserID],[RODbID]) SELECT NN.[NewContentID],CAST([ROUsageID] as nvarchar(16)),[Config],@DTS,@UserID,[RODbID] FROM [RoUsages] RR Join @Children NN on RR.ContentID = NN.ContentID -- Update content records for newly copied records to use correct RO usage ids in the RO tags DECLARE @RowsAffected int SET @RowsAffected=1 WHILE @RowsAffected > 0 BEGIN UPDATE CC SET [TEXT] = C2.NewText FROM CONTENTS CC JOIN (SELECT C1.ContentID, .dbo.vefn_FixROText(C1.Text, CAST([ROID] as int), [ROUsageID]) NewText FROM CONTENTS C1 JOIN @Children NN on C1.ContentID = NN.NewContentID JOIN RoUsages RO on NN.NewContentID = RO.ContentID) C2 ON CC.ContentID = C2.ContentID WHERE [TEXT] <> C2.NewText SET @RowsAffected = @@RowCount END -- Update grid records for newly copied records to use correct RO usage ids in the RO tags SET @RowsAffected=1 WHILE @RowsAffected > 0 BEGIN UPDATE GG SET [Data] = G2.NewData FROM GRIDS GG JOIN (SELECT G1.ContentID, .dbo.vefn_FixROData(G1.Data, CAST([ROID] as int), [ROUsageID]) NewData FROM GRIDS G1 JOIN @Children NN on G1.ContentID = NN.NewContentID JOIN RoUsages RO on NN.NewContentID = RO.ContentID) G2 ON GG.ContentID = G2.ContentID WHERE Cast([Data] as varchar(max)) <> cast(G2.NewData as varchar(max)) SET @RowsAffected = @@RowCount END UPDATE RON SET [ROID] = ROO.[ROID] FROM RoUsages RON JOIN @Children NN on RON.ContentID = NN.NewContentID JOIN RoUsages ROO on CAST(RON.ROID as int) = ROO.RoUsageID -- RoUsages are done -- SELECT * From RoUsages where DTS = @DTS and UserID = @UserID -- <<< Copy Transtions >>> -- Note that the inserted record has the 'TranType' field set to old transitionid. This is done -- so that the next step can replace the old transitionid with the new transitionid in the -- content record's transition tokens. The TranType gets reset after the content records are -- updated. -- Also note that the 'toid/rangeid' may need converted to newly copied ids or may not. If it's -- not a range, then it always is converted to new, if there is a new. If it's a range, both -- the toid & the rangeid must be new in order for the conversion to be correct. You cannot -- have part of the range pointing to the new and part of the range pointing to the original -- locations. INSERT INTO .[dbo].[Transitions] ([FromID],[ToID],[RangeID],[IsRange],[TranType],[Config],[DTS],[UserID]) SELECT NNF.[NewContentID], -- if both toid & range are null, use the original toid & rangeid CASE WHEN NNT.[NewItemID] is null or NNR.[NewItemID] is null THEN [ToID] ELSE NNT.[NewItemID] END, CASE WHEN NNT.[NewItemID] is null or NNR.[NewItemID] is null THEN [RangeID] ELSE NNR.[NewItemID] END, [IsRange],[TransitionID],[Config],@DTS,@UserID FROM .[dbo].[Transitions] TT JOIN @Children NNF on TT.[FromID] = NNF.[ContentID] LEFT JOIN @Children NNT on TT.[ToID] = NNT.[ItemID] LEFT JOIN @Children NNR on TT.[RangeID] = NNR.[ItemID] -- -- Update content records for newly copied records to use correct TransitionIDs in the Transition tags SET @RowsAffected=1 WHILE @RowsAffected > 0 BEGIN UPDATE CC SET [TEXT] = C2.NewText FROM CONTENTS CC JOIN (SELECT C1.ContentID, .dbo.vefn_FixTransitionTextForCopy(C1.Text, TRO.TransitionID, TRO.TranType, TRO.[ToID], TRO.[RangeID],TR.[TransitionID], TR.[ToID], TR.[RangeID], .dbo.vefn_GetNewTranType(NN.FormatID, NN.NewFormatID, TRO.TranType)) NewText FROM CONTENTS C1 JOIN @Children NN on C1.ContentID = NN.NewContentID JOIN Transitions TR on NN.NewContentID = TR.FromID JOIN Transitions TRO on TR.TranType = TRO.TransitionID) C2 ON CC.ContentID = C2.ContentID WHERE [TEXT] <> C2.NewText SET @RowsAffected = @@RowCount END -- -- Update grid records for newly copied records to use correct TransitionIDs in the Transition tags SET @RowsAffected=1 WHILE @RowsAffected > 0 BEGIN UPDATE GG SET [DATA] = G2.NewData FROM GRIDS GG JOIN (SELECT G1.ContentID, .dbo.vefn_FixTransitionDataForCopy(G1.Data, TRO.TransitionID, TRO.TranType, TRO.[ToID], TRO.[RangeID],TR.[TransitionID], TR.[ToID], TR.[RangeID], .dbo.vefn_GetNewTranType(NN.FormatID, NN.NewFormatID, TRO.TranType)) NewData FROM GRIDS G1 JOIN @Children NN on G1.ContentID = NN.NewContentID JOIN Transitions TR on NN.NewContentID = TR.FromID JOIN Transitions TRO on TR.TranType = TRO.TransitionID) G2 ON GG.ContentID = G2.ContentID WHERE Cast([DATA] as varchar(max)) <> CAST(G2.NewData as varchar(max)) SET @RowsAffected = @@RowCount END -- Add 'Verification Required' AnnotationType DECLARE @typeID int SELECT @typeID = TypeID from AnnotationTypes where Name = 'Verification Required' IF(@typeID IS NULL) BEGIN INSERT INTO [AnnotationTypes] ([Name],[UserID]) VALUES ('Verification Required','Volian') SELECT @typeID = SCOPE_IDENTITY() END -- Add "Verification Required" Annotation for each Transition whose transition format changes INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) SELECT NN.NewItemID, @typeID,'Verify Transition Format',@UserID FROM Transitions TR JOIN @Children NN on TR.FromID = NN.NewContentID JOIN Transitions TRO on TR.TranType = TRO.TransitionID WHERE .dbo.vefn_CompareTranFormat(NN.FormatID, NN.NewFormatID, TRO.TranType) <> 0 UPDATE TR SET TR.[TranType] = .dbo.vefn_GetNewTranType(NN.FormatID, NN.NewFormatID, TRO.TranType) FROM Transitions TR JOIN @Children NN on TR.FromID = NN.NewContentID JOIN Transitions TRO on TR.TranType = TRO.TransitionID -- Transitions are done -- SELECT * From Transitions where DTS = @DTS and UserID = @UserID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getEntriesByDocID] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getEntriesByDocID] ( @DocID int ) WITH EXECUTE AS OWNER AS SELECT [Entries].[ContentID], [Entries].[DocID], [Entries].[DTS], [Entries].[UserID], [Entries].[LastChanged], [Contents].[Number] [Content_Number], [Contents].[Text] [Content_Text], [Contents].[Type] [Content_Type], [Contents].[FormatID] [Content_FormatID], [Contents].[Config] [Content_Config], [Contents].[DTS] [Content_DTS], [Contents].[UserID] [Content_UserID] FROM [Entries] JOIN [Contents] ON [Contents].[ContentID]=[Entries].[ContentID] WHERE [Entries].[DocID]=@DocID RETURN GO /****** Object: StoredProcedure [dbo].[getEntry] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getEntry] ( @ContentID int ) WITH EXECUTE AS OWNER AS SELECT [ContentID], [DocID], [DTS], [UserID], [LastChanged] FROM [Entries] WHERE [ContentID]=@ContentID RETURN GO /****** Object: StoredProcedure [dbo].[addEntry] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addEntry] ( @ContentID int, @DocID int, @DTS datetime, @UserID nvarchar(100), @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Entries] ( [ContentID], [DocID], [DTS], [UserID] ) VALUES ( @ContentID, @DocID, @DTS, @UserID ) SELECT @newLastChanged=[LastChanged] FROM [Entries] WHERE [ContentID]=@ContentID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getEntriesByContentID] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getEntriesByContentID] ( @ContentID int ) WITH EXECUTE AS OWNER AS SELECT [Entries].[ContentID], [Entries].[DocID], [Entries].[DTS], [Entries].[UserID], [Entries].[LastChanged], [Documents].[LibTitle] [Document_LibTitle], [Documents].[DocContent] [Document_DocContent], [Documents].[DocAscii] [Document_DocAscii], [Documents].[Config] [Document_Config], [Documents].[DTS] [Document_DTS], [Documents].[UserID] [Document_UserID], [Documents].[FileExtension] [Document_FileExtension] FROM [Entries] JOIN [Documents] ON [Documents].[DocID]=[Entries].[DocID] WHERE [Entries].[ContentID]=@ContentID RETURN GO /****** Object: StoredProcedure [dbo].[getEntries] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getEntries] WITH EXECUTE AS OWNER AS SELECT [ContentID], [DocID], [DTS], [UserID], [LastChanged] FROM [Entries] RETURN GO /****** Object: StoredProcedure [dbo].[updateEntry] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateEntry] ( @ContentID int, @DocID int, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Entries] SET [DocID]=@DocID, [DTS]=@DTS, [UserID]=@UserID WHERE [ContentID]=@ContentID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Entries] WHERE [ContentID]=@ContentID) RAISERROR('Entry record has been deleted by another user', 16, 1) ELSE RAISERROR('Entry has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Entries] WHERE [ContentID]=@ContentID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getContents] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getContents] WITH EXECUTE AS OWNER AS SELECT [ContentID], [Number], [Text], [Type], [FormatID], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[Contents].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[Contents].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[Contents].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[Contents].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[Contents].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[Contents].[ContentID]) [PartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[Contents].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[Contents].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[Contents].[ContentID]) [ZContentCount] FROM [Contents] RETURN GO /****** Object: StoredProcedure [dbo].[getContentsByFormatID] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getContentsByFormatID] ( @FormatID int ) WITH EXECUTE AS OWNER AS SELECT [Contents].[ContentID], [Contents].[Number], [Contents].[Text], [Contents].[Type], [Contents].[FormatID], [Contents].[Config], [Contents].[DTS], [Contents].[UserID], [Contents].[LastChanged], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[Contents].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[Contents].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[Contents].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[Contents].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[Contents].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[Contents].[ContentID]) [PartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[Contents].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[Contents].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[Contents].[ContentID]) [ZContentCount] FROM [Contents] WHERE [Contents].[FormatID]=@FormatID RETURN GO /****** Object: StoredProcedure [dbo].[getAffectedDRoUsages] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* getAffectedDROUsages 1, '00010000019c0000', 'KBR Test', 'Changed', 'KBR' */ CREATE PROCEDURE [getAffectedDRoUsages] ( @RODbID int, @ROID nvarchar(16), @RODesc nvarchar(MAX), @Command nvarchar(10), @UserID nvarchar(100) ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @typeID int SELECT @typeID = TypeID from AnnotationTypes where Name = 'Verification Required' -- Add "Verification Required" Annotation for each ROUsage INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) SELECT ItemID, @typeID,'Referenced Object (' + @RODesc + ') ' + @Command,@UserID FROM Items where CONTENTID in (SELECT ContentID FROM DROUsages DR JOIN Entries EE on EE.DocID = DR.DocID where RODbID = @RODbID AND ROID = @ROID) END SELECT [DROUsages].[DROUsageID], [DROUsages].[DocID], [DROUsages].[ROID], [DROUsages].[Config], [DROUsages].[DTS], [DROUsages].[UserID], [DROUsages].[LastChanged], [DROUsages].[RODbID], [Documents].[LibTitle] [Document_LibTitle], [Documents].[DocContent] [Document_DocContent], [Documents].[DocAscii] [Document_DocAscii], [Documents].[Config] [Document_Config], [Documents].[DTS] [Document_DTS], [Documents].[UserID] [Document_UserID], [Documents].[FileExtension] [Document_FileExtension] FROM [DRoUsages] JOIN [Documents] ON [Documents].[DocID]=[DROUsages].[DocID] WHERE [DRoUsages].[RODbID]=@RODbID AND [DRoUsages].[ROID]=@ROID RETURN GO /****** Object: StoredProcedure [dbo].[existsEntry] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsEntry] ( @ContentID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Entries] WHERE [ContentID]=@ContentID RETURN GO /****** Object: StoredProcedure [dbo].[vesp_ListContentsByItemID] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO --vesp_ListContentsByItemID 1 CREATE PROCEDURE [vesp_ListContentsByItemID] ( @ItemID int = 0 ) WITH EXECUTE AS OWNER AS BEGIN with Itemz(ItemID,PreviousID,ContentID,[DTS],[UserID],[LastChanged]) as ( Select ItemID,PreviousID,ContentID,[DTS],[UserID],[LastChanged] from Items where ItemID=@ItemID Union All -- Select C.ItemID,C.PreviousID,C.ContentID,C.[DTS],C.[UserID],C.[LastChanged] from Items C Join Itemz Z on C.PreviousID=Z.ItemID ) SELECT cc.[ContentID], cc.[Number], cc.[Text], cc.[Type], cc.[FormatID], cc.[Config], cc.[DTS], cc.[UserID], cc.[LastChanged], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=cc.[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=cc.[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=cc.[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=cc.[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=cc.[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=cc.[ContentID]) [PartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=cc.[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=cc.[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=cc.[ContentID]) [ZContentCount] FROM [Contents] cc join itemz zz on cc.contentid=zz.contentid OPTION (MAXRECURSION 1000) END GO /****** Object: StoredProcedure [dbo].[getROImagesByRODbID] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getROImagesByRODbID] ( @RODbID int ) WITH EXECUTE AS OWNER AS SELECT [ROImages].[ImageID], [ROImages].[RODbID], [ROImages].[FileName], [ROImages].[Content], [ROImages].[Config], [ROImages].[DTS], [ROImages].[UserID], [ROImages].[LastChanged], (SELECT COUNT(*) FROM [Figures] WHERE [Figures].[ImageID]=[ROImages].[ImageID]) [FigureCount] FROM [ROImages] WHERE [ROImages].[RODbID]=@RODbID RETURN GO /****** Object: StoredProcedure [dbo].[existsFigure] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsFigure] ( @FigureID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Figures] WHERE [FigureID]=@FigureID RETURN GO /****** Object: StoredProcedure [dbo].[getROImagesByRODbIDNoData] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* This is used to quickly retrieve ROImages without their data for the ROFst Update process */ Create PROCEDURE [getROImagesByRODbIDNoData] ( @RODbID int ) WITH EXECUTE AS OWNER AS SELECT [ROImages].[ImageID], [ROImages].[RODbID], [ROImages].[FileName], null [Content], [ROImages].[Config], [ROImages].[DTS], [ROImages].[UserID], [ROImages].[LastChanged], (SELECT COUNT(*) FROM [Figures] WHERE [Figures].[ImageID]=[ROImages].[ImageID]) [FigureCount] FROM [ROImages] WHERE [ROImages].[RODbID]=@RODbID RETURN GO /****** Object: StoredProcedure [dbo].[getROImage] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getROImage] ( @ImageID int ) WITH EXECUTE AS OWNER AS SELECT [ImageID], [RODbID], [FileName], [Content], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Figures] WHERE [Figures].[ImageID]=[ROImages].[ImageID]) [FigureCount] FROM [ROImages] WHERE [ImageID]=@ImageID SELECT [Figures].[FigureID], [Figures].[ROFstID], [Figures].[ImageID], [Figures].[Config], [Figures].[DTS], [Figures].[UserID], [Figures].[LastChanged], [ROFsts].[RODbID] [ROFst_RODbID], [ROFsts].[ROLookup] [ROFst_ROLookup], [ROFsts].[Config] [ROFst_Config], [ROFsts].[DTS] [ROFst_DTS], [ROFsts].[UserID] [ROFst_UserID] FROM [Figures] JOIN [ROFsts] ON [ROFsts].[ROFstID]=[Figures].[ROFstID] WHERE [Figures].[ImageID]=@ImageID RETURN GO /****** Object: StoredProcedure [dbo].[getROImageByRODbID_FileName_DTS] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getROImageByRODbID_FileName_DTS] ( @RODbID int, @FileName nvarchar(255), @DTS datetime ) WITH EXECUTE AS OWNER AS SELECT [ImageID], [RODbID], [FileName], [Content], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Figures] WHERE [Figures].[ImageID]=[ROImages].[ImageID]) [FigureCount] FROM [ROImages] WHERE [RODbID]=@RODbID AND [FileName]=@FileName AND [DTS]=@DTS RETURN GO /****** Object: StoredProcedure [dbo].[getROImages] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getROImages] WITH EXECUTE AS OWNER AS SELECT [ImageID], [RODbID], [FileName], [Content], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Figures] WHERE [Figures].[ImageID]=[ROImages].[ImageID]) [FigureCount] FROM [ROImages] RETURN GO /****** Object: StoredProcedure [dbo].[getROImageByROFstID_FileName] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getROImageByROFstID_FileName] ( @ROFstID int, @FileName nvarchar(255) ) WITH EXECUTE AS OWNER AS SELECT [ImageID], [RODbID], [FileName], [Content], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Figures] WHERE [Figures].[ImageID]=[ROImages].[ImageID]) [FigureCount] FROM [ROImages] --JOIN [Figures] ON -- [Figures].[ImageID]=[ROImages].[ImageID] WHERE [ImageID] in (select ImageID from Figures where ROFstID=@ROFstID) AND [ROImages].[FileName]=@FileName RETURN GO /****** Object: StoredProcedure [dbo].[deleteROImage] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteROImage] ( @ImageID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Figures] WHERE [ImageID]=@ImageID DELETE [ROImages] WHERE [ImageID] = @ImageID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[updateFigure] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateFigure] ( @FigureID int, @ROFstID int, @ImageID int, @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Figures] SET [ROFstID]=@ROFstID, [ImageID]=@ImageID, [Config]=@Config, [DTS]=@DTS, [UserID]=@UserID WHERE [FigureID]=@FigureID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Figures] WHERE [FigureID]=@FigureID) RAISERROR('Figure record has been deleted by another user', 16, 1) ELSE RAISERROR('Figure has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Figures] WHERE [FigureID]=@FigureID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[addFiguresByROFstIDandImageIDs] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addFiguresByROFstIDandImageIDs] ( @ROFstID int, @ImageIDs varchar(max) ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Figures] ( [ROFstID] ,[ImageID] ,[Config] ,[DTS] ,[UserID] ) select distinct FF.ROFstID, II.ID ImageID, '' Config, FF.DTS, FF.UserID from ROFsts FF , vefn_SplitInt(@ImageIDs,',') II where ROFstID=@ROFstID SELECT [FigureID] ,[ROFstID] ,[ImageID] ,[Config] ,[DTS] ,[UserID] ,[LastChanged] FROM [Figures] WHERE [ROFstID]=@ROFstID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[addFigure] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addFigure] ( @ROFstID int, @ImageID int, @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @newFigureID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Figures] ( [ROFstID], [ImageID], [Config], [DTS], [UserID] ) VALUES ( @ROFstID, @ImageID, @Config, @DTS, @UserID ) SELECT @newFigureID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Figures] WHERE [FigureID]=@newFigureID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getFigureByROFstID_ImageID] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getFigureByROFstID_ImageID] ( @ROFstID int, @ImageID int ) WITH EXECUTE AS OWNER AS SELECT [FigureID], [ROFstID], [ImageID], [Config], [DTS], [UserID], [LastChanged] FROM [Figures] WHERE [ROFstID]=@ROFstID AND [ImageID]=@ImageID RETURN GO /****** Object: StoredProcedure [dbo].[getFiguresByROFstID] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getFiguresByROFstID] ( @ROFstID int ) WITH EXECUTE AS OWNER AS SELECT [Figures].[FigureID], [Figures].[ROFstID], [Figures].[ImageID], [Figures].[Config], [Figures].[DTS], [Figures].[UserID], [Figures].[LastChanged], [ROImages].[RODbID] [ROImage_RODbID], [ROImages].[FileName] [ROImage_FileName], [ROImages].[Content] [ROImage_Content], [ROImages].[Config] [ROImage_Config], [ROImages].[DTS] [ROImage_DTS], [ROImages].[UserID] [ROImage_UserID] FROM [Figures] JOIN [ROImages] ON [ROImages].[ImageID]=[Figures].[ImageID] WHERE [Figures].[ROFstID]=@ROFstID RETURN GO /****** Object: StoredProcedure [dbo].[getFigure] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getFigure] ( @FigureID int ) WITH EXECUTE AS OWNER AS SELECT [FigureID], [ROFstID], [ImageID], [Config], [DTS], [UserID], [LastChanged] FROM [Figures] WHERE [FigureID]=@FigureID RETURN GO /****** Object: StoredProcedure [dbo].[getFigures] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getFigures] WITH EXECUTE AS OWNER AS SELECT [FigureID], [ROFstID], [ImageID], [Config], [DTS], [UserID], [LastChanged] FROM [Figures] RETURN GO /****** Object: StoredProcedure [dbo].[getFiguresByImageID] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getFiguresByImageID] ( @ImageID int ) WITH EXECUTE AS OWNER AS SELECT [Figures].[FigureID], [Figures].[ROFstID], [Figures].[ImageID], [Figures].[Config], [Figures].[DTS], [Figures].[UserID], [Figures].[LastChanged], [ROFsts].[RODbID] [ROFst_RODbID], [ROFsts].[ROLookup] [ROFst_ROLookup], [ROFsts].[Config] [ROFst_Config], [ROFsts].[DTS] [ROFst_DTS], [ROFsts].[UserID] [ROFst_UserID] FROM [Figures] JOIN [ROFsts] ON [ROFsts].[ROFstID]=[Figures].[ROFstID] WHERE [Figures].[ImageID]=@ImageID RETURN GO /****** Object: StoredProcedure [dbo].[deleteFigure] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteFigure] ( @FigureID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Figures] WHERE [FigureID] = @FigureID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[addROImage] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addROImage] ( @RODbID int, @FileName nvarchar(255), @Content varbinary(MAX), @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @newImageID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [ROImages] ( [RODbID], [FileName], [Content], [Config], [DTS], [UserID] ) VALUES ( @RODbID, @FileName, @Content, @Config, @DTS, @UserID ) SELECT @newImageID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [ROImages] WHERE [ImageID]=@newImageID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[updateROImage] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateROImage] ( @ImageID int, @RODbID int, @FileName nvarchar(255), @Content varbinary(MAX), @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [ROImages] SET [RODbID]=@RODbID, [FileName]=@FileName, [Content]=@Content, [Config]=@Config, [DTS]=@DTS, [UserID]=@UserID WHERE [ImageID]=@ImageID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [ROImages] WHERE [ImageID]=@ImageID) RAISERROR('ROImage record has been deleted by another user', 16, 1) ELSE RAISERROR('ROImage has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [ROImages] WHERE [ImageID]=@ImageID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[existsROImage] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsROImage] ( @ImageID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [ROImages] WHERE [ImageID]=@ImageID RETURN GO /****** Object: StoredProcedure [dbo].[existsDocument] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsDocument] ( @DocID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Documents] WHERE [DocID]=@DocID RETURN GO /****** Object: StoredProcedure [dbo].[updateDocument] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateDocument] ( @DocID int, @LibTitle nvarchar(1024)=null, @DocContent varbinary(MAX)=null, @DocAscii nvarchar(MAX)=null, @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @FileExtension nvarchar(10), @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Documents] SET [LibTitle]=@LibTitle, [DocContent]=@DocContent, [DocAscii]=@DocAscii, [Config]=@Config, [DTS]=@DTS, [UserID]=@UserID, [FileExtension]=@FileExtension WHERE [DocID]=@DocID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Documents] WHERE [DocID]=@DocID) RAISERROR('Document record has been deleted by another user', 16, 1) ELSE RAISERROR('Document has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Documents] WHERE [DocID]=@DocID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getDROUsagesByRODbID] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getDROUsagesByRODbID] ( @RODbID int ) WITH EXECUTE AS OWNER AS SELECT [DROUsages].[DROUsageID], [DROUsages].[DocID], [DROUsages].[ROID], [DROUsages].[Config], [DROUsages].[DTS], [DROUsages].[UserID], [DROUsages].[LastChanged], [DROUsages].[RODbID], [Documents].[LibTitle] [Document_LibTitle], [Documents].[DocContent] [Document_DocContent], [Documents].[DocAscii] [Document_DocAscii], [Documents].[Config] [Document_Config], [Documents].[DTS] [Document_DTS], [Documents].[UserID] [Document_UserID], [Documents].[FileExtension] [Document_FileExtension] FROM [DROUsages] JOIN [Documents] ON [Documents].[DocID]=[DROUsages].[DocID] WHERE [DROUsages].[RODbID]=@RODbID RETURN GO /****** Object: StoredProcedure [dbo].[getDRoUsagesByROIDs] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getDRoUsagesByROIDs] ( @ROIDs nvarchar(MAX) ) WITH EXECUTE AS OWNER AS SELECT [DROUsages].[DROUsageID], [DROUsages].[DocID], [DROUsages].[ROID], [DROUsages].[Config], [DROUsages].[DTS], [DROUsages].[UserID], [DROUsages].[LastChanged], [DROUsages].[RODbID], [Documents].[LibTitle] [Document_LibTitle], [Documents].[DocContent] [Document_DocContent], [Documents].[DocAscii] [Document_DocAscii], [Documents].[Config] [Document_Config], [Documents].[DTS] [Document_DTS], [Documents].[UserID] [Document_UserID], [Documents].[FileExtension] [Document_FileExtension] FROM [DRoUsages] JOIN vefn_SplitROSearch(@ROIDs) SS ON [DRoUsages].RODBID = SS.[RODBID] and [DRoUsages].[ROID] like SS.[ROID] + '%' JOIN [Documents] ON [Documents].[DocID]=[DROUsages].[DocID] RETURN GO /****** Object: StoredProcedure [dbo].[addDocument] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addDocument] ( @LibTitle nvarchar(1024)=null, @DocContent varbinary(MAX)=null, @DocAscii nvarchar(MAX)=null, @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @FileExtension nvarchar(10), @newDocID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Documents] ( [LibTitle], [DocContent], [DocAscii], [Config], [DTS], [UserID], [FileExtension] ) VALUES ( @LibTitle, @DocContent, @DocAscii, @Config, @DTS, @UserID, @FileExtension ) SELECT @newDocID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Documents] WHERE [DocID]=@newDocID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: UserDefinedFunction [dbo].[vefn_GetDocumentPageLength] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* print .dbo.[vefn_GetDocumentPageLength](1) select DocID, .dbo.[vefn_GetDocumentPageLength](DocID) PageLength from Documents */ CREATE FUNCTION [vefn_GetDocumentPageLength] (@DocID int) RETURNS float WITH EXECUTE AS OWNER AS BEGIN DECLARE @PageLength float SET @PageLength = (select top 1 v.value('.', 'nvarchar(100)') [Length] from (select DocID, cast (Config as xml) ConfigXML from Documents) T1 CROSS APPLY ConfigXML.nodes('//@Length') TempXML(v) WHERE DocID = @DocID) return @PageLength END; GO /****** Object: StoredProcedure [dbo].[addROFst] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addROFst] ( @RODbID int, @ROLookup varbinary(MAX), @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @newROFstID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [ROFsts] ( [RODbID], [ROLookup], [Config], [DTS], [UserID] ) VALUES ( @RODbID, @ROLookup, @Config, @DTS, @UserID ) SELECT @newROFstID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [ROFsts] WHERE [ROFstID]=@newROFstID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[updateROFst] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateROFst] ( @ROFstID int, @RODbID int, @ROLookup varbinary(MAX), @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [ROFsts] SET [RODbID]=@RODbID, [ROLookup]=@ROLookup, [Config]=@Config, [DTS]=@DTS, [UserID]=@UserID WHERE [ROFstID]=@ROFstID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [ROFsts] WHERE [ROFstID]=@ROFstID) RAISERROR('ROFst record has been deleted by another user', 16, 1) ELSE RAISERROR('ROFst has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [ROFsts] WHERE [ROFstID]=@ROFstID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[existsROFst] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsROFst] ( @ROFstID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [ROFsts] WHERE [ROFstID]=@ROFstID RETURN GO /****** Object: StoredProcedure [dbo].[getUser] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getUser] ( @UID int ) WITH EXECUTE AS OWNER AS SELECT [UID], [UserID], [FirstName], [MiddleName], [LastName], [Suffix], [CourtesyTitle], [PhoneNumber], [CFGName], [UserLogin], [UserName], [Config], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Memberships] WHERE [Memberships].[UID]=[Users].[UID]) [MembershipCount] FROM [Users] WHERE [UID]=@UID SELECT [Memberships].[UGID], [Memberships].[UID], [Memberships].[GID], [Memberships].[StartDate], [Memberships].[EndDate], [Memberships].[Config], [Memberships].[DTS], [Memberships].[UsrID], [Memberships].[LastChanged], [Groups].[GroupName] [Group_GroupName], [Groups].[GroupType] [Group_GroupType], [Groups].[Config] [Group_Config], [Groups].[DTS] [Group_DTS], [Groups].[UsrID] [Group_UsrID] FROM [Memberships] JOIN [Groups] ON [Groups].[GID]=[Memberships].[GID] WHERE [Memberships].[UID]=@UID RETURN GO /****** Object: StoredProcedure [dbo].[existsGroup] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsGroup] ( @GID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Groups] WHERE [GID]=@GID RETURN GO /****** Object: StoredProcedure [dbo].[getRole] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getRole] ( @RID int ) WITH EXECUTE AS OWNER AS SELECT [RID], [Name], [Title], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Assignments] WHERE [Assignments].[RID]=[Roles].[RID]) [AssignmentCount], (SELECT COUNT(*) FROM [Permissions] WHERE [Permissions].[RID]=[Roles].[RID]) [PermissionCount] FROM [Roles] WHERE [RID]=@RID SELECT [Assignments].[AID], [Assignments].[GID], [Assignments].[RID], [Assignments].[FolderID], [Assignments].[StartDate], [Assignments].[EndDate], [Assignments].[DTS], [Assignments].[UsrID], [Assignments].[LastChanged], [Folders].[ParentID] [Folder_ParentID], [Folders].[DBID] [Folder_DBID], [Folders].[Name] [Folder_Name], [Folders].[Title] [Folder_Title], [Folders].[ShortName] [Folder_ShortName], [Folders].[FormatID] [Folder_FormatID], [Folders].[ManualOrder] [Folder_ManualOrder], [Folders].[Config] [Folder_Config], [Folders].[DTS] [Folder_DTS], [Folders].[UsrID] [Folder_UsrID], [Groups].[GroupName] [Group_GroupName], [Groups].[GroupType] [Group_GroupType], [Groups].[Config] [Group_Config], [Groups].[DTS] [Group_DTS], [Groups].[UsrID] [Group_UsrID] FROM [Assignments] JOIN [Folders] ON [Folders].[FolderID]=[Assignments].[FolderID] JOIN [Groups] ON [Groups].[GID]=[Assignments].[GID] WHERE [Assignments].[RID]=@RID SELECT [Permissions].[PID], [Permissions].[RID], [Permissions].[PermLevel], [Permissions].[VersionType], [Permissions].[PermValue], [Permissions].[PermAD], [Permissions].[StartDate], [Permissions].[EndDate], [Permissions].[Config], [Permissions].[DTS], [Permissions].[UsrID], [Permissions].[LastChanged] FROM [Permissions] WHERE [Permissions].[RID]=@RID RETURN GO /****** Object: StoredProcedure [dbo].[getAssignmentsByRID] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getAssignmentsByRID] ( @RID int ) WITH EXECUTE AS OWNER AS SELECT [Assignments].[AID], [Assignments].[GID], [Assignments].[RID], [Assignments].[FolderID], [Assignments].[StartDate], [Assignments].[EndDate], [Assignments].[DTS], [Assignments].[UsrID], [Assignments].[LastChanged], [Folders].[ParentID] [Folder_ParentID], [Folders].[DBID] [Folder_DBID], [Folders].[Name] [Folder_Name], [Folders].[Title] [Folder_Title], [Folders].[ShortName] [Folder_ShortName], [Folders].[FormatID] [Folder_FormatID], [Folders].[ManualOrder] [Folder_ManualOrder], [Folders].[Config] [Folder_Config], [Folders].[DTS] [Folder_DTS], [Folders].[UsrID] [Folder_UsrID], [Groups].[GroupName] [Group_GroupName], [Groups].[GroupType] [Group_GroupType], [Groups].[Config] [Group_Config], [Groups].[DTS] [Group_DTS], [Groups].[UsrID] [Group_UsrID] FROM [Assignments] JOIN [Folders] ON [Folders].[FolderID]=[Assignments].[FolderID] JOIN [Groups] ON [Groups].[GID]=[Assignments].[GID] WHERE [Assignments].[RID]=@RID RETURN GO /****** Object: StoredProcedure [dbo].[getAssignmentsByFolderID] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getAssignmentsByFolderID] ( @FolderID int ) WITH EXECUTE AS OWNER AS SELECT [Assignments].[AID], [Assignments].[GID], [Assignments].[RID], [Assignments].[FolderID], [Assignments].[StartDate], [Assignments].[EndDate], [Assignments].[DTS], [Assignments].[UsrID], [Assignments].[LastChanged], [Groups].[GroupName] [Group_GroupName], [Groups].[GroupType] [Group_GroupType], [Groups].[Config] [Group_Config], [Groups].[DTS] [Group_DTS], [Groups].[UsrID] [Group_UsrID], [Roles].[Name] [Role_Name], [Roles].[Title] [Role_Title], [Roles].[DTS] [Role_DTS], [Roles].[UsrID] [Role_UsrID] FROM [Assignments] JOIN [Groups] ON [Groups].[GID]=[Assignments].[GID] JOIN [Roles] ON [Roles].[RID]=[Assignments].[RID] WHERE [Assignments].[FolderID]=@FolderID RETURN GO /****** Object: StoredProcedure [dbo].[updateGroup] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateGroup] ( @GID int, @GroupName nvarchar(50), @GroupType int=null, @Config nvarchar(MAX)=null, @DTS datetime, @UsrID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Groups] SET [GroupName]=@GroupName, [GroupType]=@GroupType, [Config]=@Config, [DTS]=@DTS, [UsrID]=@UsrID WHERE [GID]=@GID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Groups] WHERE [GID]=@GID) RAISERROR('Group record has been deleted by another user', 16, 1) ELSE RAISERROR('Group has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Groups] WHERE [GID]=@GID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getGroupByGroupName] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getGroupByGroupName] ( @GroupName nvarchar(50) ) WITH EXECUTE AS OWNER AS SELECT [GID], [GroupName], [GroupType], [Config], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Assignments] WHERE [Assignments].[GID]=[Groups].[GID]) [AssignmentCount], (SELECT COUNT(*) FROM [Memberships] WHERE [Memberships].[GID]=[Groups].[GID]) [MembershipCount] FROM [Groups] WHERE [GroupName]=@GroupName RETURN GO /****** Object: StoredProcedure [dbo].[getGroup] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getGroup] ( @GID int ) WITH EXECUTE AS OWNER AS SELECT [GID], [GroupName], [GroupType], [Config], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Assignments] WHERE [Assignments].[GID]=[Groups].[GID]) [AssignmentCount], (SELECT COUNT(*) FROM [Memberships] WHERE [Memberships].[GID]=[Groups].[GID]) [MembershipCount] FROM [Groups] WHERE [GID]=@GID SELECT [Assignments].[AID], [Assignments].[GID], [Assignments].[RID], [Assignments].[FolderID], [Assignments].[StartDate], [Assignments].[EndDate], [Assignments].[DTS], [Assignments].[UsrID], [Assignments].[LastChanged], [Folders].[ParentID] [Folder_ParentID], [Folders].[DBID] [Folder_DBID], [Folders].[Name] [Folder_Name], [Folders].[Title] [Folder_Title], [Folders].[ShortName] [Folder_ShortName], [Folders].[FormatID] [Folder_FormatID], [Folders].[ManualOrder] [Folder_ManualOrder], [Folders].[Config] [Folder_Config], [Folders].[DTS] [Folder_DTS], [Folders].[UsrID] [Folder_UsrID], [Roles].[Name] [Role_Name], [Roles].[Title] [Role_Title], [Roles].[DTS] [Role_DTS], [Roles].[UsrID] [Role_UsrID] FROM [Assignments] JOIN [Folders] ON [Folders].[FolderID]=[Assignments].[FolderID] JOIN [Roles] ON [Roles].[RID]=[Assignments].[RID] WHERE [Assignments].[GID]=@GID SELECT [Memberships].[UGID], [Memberships].[UID], [Memberships].[GID], [Memberships].[StartDate], [Memberships].[EndDate], [Memberships].[Config], [Memberships].[DTS], [Memberships].[UsrID], [Memberships].[LastChanged], [Users].[UserID] [User_UserID], [Users].[FirstName] [User_FirstName], [Users].[MiddleName] [User_MiddleName], [Users].[LastName] [User_LastName], [Users].[Suffix] [User_Suffix], [Users].[CourtesyTitle] [User_CourtesyTitle], [Users].[PhoneNumber] [User_PhoneNumber], [Users].[CFGName] [User_CFGName], [Users].[UserLogin] [User_UserLogin], [Users].[UserName] [User_UserName], [Users].[Config] [User_Config], [Users].[DTS] [User_DTS], [Users].[UsrID] [User_UsrID] FROM [Memberships] JOIN [Users] ON [Users].[UID]=[Memberships].[UID] WHERE [Memberships].[GID]=@GID RETURN GO /****** Object: StoredProcedure [dbo].[addGroup] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addGroup] ( @GroupName nvarchar(50), @GroupType int=null, @Config nvarchar(MAX)=null, @DTS datetime, @UsrID nvarchar(100), @newGID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Groups] ( [GroupName], [GroupType], [Config], [DTS], [UsrID] ) VALUES ( @GroupName, @GroupType, @Config, @DTS, @UsrID ) SELECT @newGID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Groups] WHERE [GID]=@newGID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[deleteGroup] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteGroup] ( @GID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Assignments] WHERE [GID]=@GID DELETE [Memberships] WHERE [GID]=@GID DELETE [Groups] WHERE [GID] = @GID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getMembershipsByUID] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getMembershipsByUID] ( @UID int ) WITH EXECUTE AS OWNER AS SELECT [Memberships].[UGID], [Memberships].[UID], [Memberships].[GID], [Memberships].[StartDate], [Memberships].[EndDate], [Memberships].[Config], [Memberships].[DTS], [Memberships].[UsrID], [Memberships].[LastChanged], [Groups].[GroupName] [Group_GroupName], [Groups].[GroupType] [Group_GroupType], [Groups].[Config] [Group_Config], [Groups].[DTS] [Group_DTS], [Groups].[UsrID] [Group_UsrID] FROM [Memberships] JOIN [Groups] ON [Groups].[GID]=[Memberships].[GID] WHERE [Memberships].[UID]=@UID RETURN GO /****** Object: StoredProcedure [dbo].[getGroups] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getGroups] WITH EXECUTE AS OWNER AS SELECT [GID], [GroupName], [GroupType], [Config], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Assignments] WHERE [Assignments].[GID]=[Groups].[GID]) [AssignmentCount], (SELECT COUNT(*) FROM [Memberships] WHERE [Memberships].[GID]=[Groups].[GID]) [MembershipCount] FROM [Groups] RETURN GO /****** Object: StoredProcedure [dbo].[addRoUsage] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addRoUsage] ( @ContentID int, @ROID nvarchar(16), @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @RODbID int, @newROUsageID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [RoUsages] ( [ContentID], [ROID], [Config], [DTS], [UserID], [RODbID] ) VALUES ( @ContentID, @ROID, @Config, @DTS, @UserID, @RODbID ) SELECT @newROUsageID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [RoUsages] WHERE [ROUsageID]=@newROUsageID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[updateRoUsage] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateRoUsage] ( @ROUsageID int, @ContentID int, @ROID nvarchar(16), @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @RODbID int, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [RoUsages] SET [ContentID]=@ContentID, [ROID]=@ROID, [Config]=@Config, [DTS]=@DTS, [UserID]=@UserID, [RODbID]=@RODbID WHERE [ROUsageID]=@ROUsageID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [RoUsages] WHERE [ROUsageID]=@ROUsageID) RAISERROR('RoUsage record has been deleted by another user', 16, 1) ELSE RAISERROR('RoUsage has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [RoUsages] WHERE [ROUsageID]=@ROUsageID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getAffectedRoUsages] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* getAffectedROUsages 1, '00010000019c0000', 'KBR Test', 'Changed', 'KBR' */ CREATE PROCEDURE [getAffectedRoUsages] ( @RODbID int, @ROID nvarchar(16), @RODesc nvarchar(MAX), @Command nvarchar(10), @UserID nvarchar(100) ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @typeID int SELECT @typeID = TypeID from AnnotationTypes where Name = 'Verification Required' -- Add "Verification Required" Annotation for each ROUsage INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) SELECT ItemID, @typeID,'Referenced Object (' + @RODesc + ') ' + @Command,@UserID FROM Items where CONTENTID in (SELECT ContentID FROM ROUSAGES where RODbID = @RODbID AND ROID = @ROID) END SELECT [RoUsages].[ROUsageID], [RoUsages].[ContentID], [RoUsages].[ROID], [RoUsages].[Config], [RoUsages].[DTS], [RoUsages].[UserID], [RoUsages].[LastChanged], [RoUsages].[RODbID], [Contents].[Number] [Content_Number], [Contents].[Text] [Content_Text], [Contents].[Type] [Content_Type], [Contents].[FormatID] [Content_FormatID], [Contents].[Config] [Content_Config], [Contents].[DTS] [Content_DTS], [Contents].[UserID] [Content_UserID] FROM [RoUsages] JOIN [Contents] ON [Contents].[ContentID]=[RoUsages].[ContentID] WHERE [RoUsages].[RODbID]=@RODbID AND [RoUsages].[ROID]=@ROID RETURN GO /****** Object: StoredProcedure [dbo].[deleteRoUsage] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteRoUsage] ( @ROUsageID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [RoUsages] WHERE [ROUsageID] = @ROUsageID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getRoUsage] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getRoUsage] ( @ROUsageID int ) WITH EXECUTE AS OWNER AS SELECT [ROUsageID], [ContentID], [ROID], [Config], [DTS], [UserID], [LastChanged], [RODbID] FROM [RoUsages] WHERE [ROUsageID]=@ROUsageID RETURN GO /****** Object: StoredProcedure [dbo].[getRoUsages] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getRoUsages] WITH EXECUTE AS OWNER AS SELECT [ROUsageID], [ContentID], [ROID], [Config], [DTS], [UserID], [LastChanged], [RODbID] FROM [RoUsages] RETURN GO /****** Object: StoredProcedure [dbo].[getRoUsagesByRODbID] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getRoUsagesByRODbID] ( @RODbID int ) WITH EXECUTE AS OWNER AS SELECT [RoUsages].[ROUsageID], [RoUsages].[ContentID], [RoUsages].[ROID], [RoUsages].[Config], [RoUsages].[DTS], [RoUsages].[UserID], [RoUsages].[LastChanged], [RoUsages].[RODbID], [Contents].[Number] [Content_Number], [Contents].[Text] [Content_Text], [Contents].[Type] [Content_Type], [Contents].[FormatID] [Content_FormatID], [Contents].[Config] [Content_Config], [Contents].[DTS] [Content_DTS], [Contents].[UserID] [Content_UserID] FROM [RoUsages] JOIN [Contents] ON [Contents].[ContentID]=[RoUsages].[ContentID] WHERE [RoUsages].[RODbID]=@RODbID RETURN GO /****** Object: StoredProcedure [dbo].[getRoUsagesByROIDs] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* findRoUsagesByROIDs 1,'1:000100000406,000200000229,00020000022A,00020000022B,0002000005F7,0002000005F9,0002000005FA,0002000005FB,000200000623,000200000626,000200000155,00020000018C,00020000018D,00020000022F,000200000230,00020000019E,000200000677,000200000678,000200000684,000D000000CA0042,000D000000CA0043,000D0000064A0042,000D000006600042,000D000006600043,000D000006670042,000D000006670043,000D000006680042,000D000006680043,000D0000067D0041,000D0000067D0042,000D0000067D0043,000D000006850042,000D000006850043,000D000009140042,000D000009140043,000D00000A320042,000D00000A360042,000D00000A500042,000D00000A500043,000D00000A630042,000D00000A630043,0010000022400041,0010000022400042,0010000022400043,001000002AE60042,001000002AE60043,001000003D8B0042,001000003D8B0043,001000003D8C0042,001000003D8C0043,0010000058AB0042,0010000058AB0043,0010000086550042,0010000086550043,001000009B550041,001000009B550042,001000009C1C0041,001000009C1C0042,001000009C1D0041,001000009C1D0042,001000009C1E0041,001000009C1E0042,001000009C1F0041,001000009C1F0042,001000009C200041,001000009C200042,001000009C210041,001000009C210042,001000009C220041,001000009C220042,001000009C230041,001000009C230042,001000009C240041,001000009C240042,001000009C250041,001000009C250042,001000009C260041,001000009C260042,00100000546E0042,00100000546E0043,001000009B900041,001000009B900042,001000009B910041,001000009B910042,001000009B920041,001000009B920042,001000009B930041,001000009B930042,001000009B940041,001000009B940042,001000009B950041,001000009B950042,001000009B960041,001000009B960042,001000009B970041,001000009B970042,001000009B980041,001000009B980042,001000009B990041,001000009B990042,001000009C270041,001000009C270042,001000009C280041,001000009C280042,001000009C290041,001000009C290042,001000009C2A0041,001000009C2A0042,001000009C2B0041,001000009C2B0042,001000009C2C0041,001000009C2C0042,00110000027E0042,00110000027E0043,00150000216A,001500002367,00150000236C,0015000029B7,001500000392,00150000039E,0015000021C7,0015000021E6,001500002261,001500002265,001500002266,001500002297,001500002754,001500002756,0015000004F4,001500002766,001500002546,001500002643,001500002645,001500002646,00150000266A,00150000266B,00150000266C,00150000266D,00150000266E,00150000266F,001500002670,001500002671,0015000026AA,001500000720' */ CREATE PROCEDURE [getRoUsagesByROIDs] ( @ROIDs nvarchar(MAX) ) WITH EXECUTE AS OWNER AS SELECT [RoUsages].[ROUsageID], [RoUsages].[ContentID], [RoUsages].[ROID], [RoUsages].[Config], [RoUsages].[DTS], [RoUsages].[UserID], [RoUsages].[LastChanged], [RoUsages].[RODbID], [Contents].[Number] [Content_Number], [Contents].[Text] [Content_Text], [Contents].[Type] [Content_Type], [Contents].[FormatID] [Content_FormatID], [Contents].[Config] [Content_Config], [Contents].[DTS] [Content_DTS], [Contents].[UserID] [Content_UserID] FROM [RoUsages] JOIN vefn_SplitROSearch(@ROIDs) SS ON [RoUsages].RODBID = SS.[RODBID] and [RoUsages].[ROID] like SS.[ROID] + '%' JOIN [Contents] ON [Contents].[ContentID]=[RoUsages].[ContentID] RETURN GO /****** Object: StoredProcedure [dbo].[existsRoUsage] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsRoUsage] ( @ROUsageID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [RoUsages] WHERE [ROUsageID]=@ROUsageID RETURN GO /****** Object: StoredProcedure [dbo].[getUsers] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getUsers] WITH EXECUTE AS OWNER AS SELECT [UID], [UserID], [FirstName], [MiddleName], [LastName], [Suffix], [CourtesyTitle], [PhoneNumber], [CFGName], [UserLogin], [UserName], [Config], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Memberships] WHERE [Memberships].[UID]=[Users].[UID]) [MembershipCount] FROM [Users] RETURN GO /****** Object: StoredProcedure [dbo].[existsMembership] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsMembership] ( @UGID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Memberships] WHERE [UGID]=@UGID RETURN GO /****** Object: StoredProcedure [dbo].[deleteUser] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteUser] ( @UID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Memberships] WHERE [UID]=@UID DELETE [Users] WHERE [UID] = @UID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[deleteMembership] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteMembership] ( @UGID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Memberships] WHERE [UGID] = @UGID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[updateMembership] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateMembership] ( @UGID int, @UID int, @GID int, @StartDate datetime, @EndDate datetime=null, @Config nvarchar(MAX)=null, @DTS datetime, @UsrID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Memberships] SET [UID]=@UID, [GID]=@GID, [StartDate]=@StartDate, [EndDate]=@EndDate, [Config]=@Config, [DTS]=@DTS, [UsrID]=@UsrID WHERE [UGID]=@UGID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Memberships] WHERE [UGID]=@UGID) RAISERROR('Membership record has been deleted by another user', 16, 1) ELSE RAISERROR('Membership has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Memberships] WHERE [UGID]=@UGID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[addMembership] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addMembership] ( @UID int, @GID int, @StartDate datetime, @EndDate datetime=null, @Config nvarchar(MAX)=null, @DTS datetime, @UsrID nvarchar(100), @newUGID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Memberships] ( [UID], [GID], [StartDate], [EndDate], [Config], [DTS], [UsrID] ) VALUES ( @UID, @GID, @StartDate, @EndDate, @Config, @DTS, @UsrID ) SELECT @newUGID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Memberships] WHERE [UGID]=@newUGID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getMembershipsByGID] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getMembershipsByGID] ( @GID int ) WITH EXECUTE AS OWNER AS SELECT [Memberships].[UGID], [Memberships].[UID], [Memberships].[GID], [Memberships].[StartDate], [Memberships].[EndDate], [Memberships].[Config], [Memberships].[DTS], [Memberships].[UsrID], [Memberships].[LastChanged], [Users].[UserID] [User_UserID], [Users].[FirstName] [User_FirstName], [Users].[MiddleName] [User_MiddleName], [Users].[LastName] [User_LastName], [Users].[Suffix] [User_Suffix], [Users].[CourtesyTitle] [User_CourtesyTitle], [Users].[PhoneNumber] [User_PhoneNumber], [Users].[CFGName] [User_CFGName], [Users].[UserLogin] [User_UserLogin], [Users].[UserName] [User_UserName], [Users].[Config] [User_Config], [Users].[DTS] [User_DTS], [Users].[UsrID] [User_UsrID] FROM [Memberships] JOIN [Users] ON [Users].[UID]=[Memberships].[UID] WHERE [Memberships].[GID]=@GID RETURN GO /****** Object: StoredProcedure [dbo].[getMemberships] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getMemberships] WITH EXECUTE AS OWNER AS SELECT [UGID], [UID], [GID], [StartDate], [EndDate], [Config], [DTS], [UsrID], [LastChanged] FROM [Memberships] RETURN GO /****** Object: StoredProcedure [dbo].[getMembership] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getMembership] ( @UGID int ) WITH EXECUTE AS OWNER AS SELECT [UGID], [UID], [GID], [StartDate], [EndDate], [Config], [DTS], [UsrID], [LastChanged] FROM [Memberships] WHERE [UGID]=@UGID RETURN GO /****** Object: StoredProcedure [dbo].[addZContent] Script Date: 01/06/2012 15:02:54 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addZContent] ( @ContentID int, @OldStepSequence nvarchar(32), @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [ZContents] ( [ContentID], [OldStepSequence] ) VALUES ( @ContentID, @OldStepSequence ) SELECT @newLastChanged=[LastChanged] FROM [ZContents] WHERE [ContentID]=@ContentID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[updateZContent] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateZContent] ( @ContentID int, @OldStepSequence nvarchar(32), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [ZContents] SET [OldStepSequence]=@OldStepSequence WHERE [ContentID]=@ContentID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [ZContents] WHERE [ContentID]=@ContentID) RAISERROR('ZContent record has been deleted by another user', 16, 1) ELSE RAISERROR('ZContent has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [ZContents] WHERE [ContentID]=@ContentID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getZContentsByContentID] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getZContentsByContentID] ( @ContentID int ) WITH EXECUTE AS OWNER AS SELECT [ZContents].[ContentID], [ZContents].[OldStepSequence], [ZContents].[LastChanged] FROM [ZContents] WHERE [ZContents].[ContentID]=@ContentID RETURN GO /****** Object: StoredProcedure [dbo].[deleteZContent] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteZContent] ( @ContentID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [ZContents] WHERE [ContentID] = @ContentID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getZContent] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getZContent] ( @ContentID int ) WITH EXECUTE AS OWNER AS SELECT [ContentID], [OldStepSequence], [LastChanged] FROM [ZContents] WHERE [ContentID]=@ContentID RETURN GO /****** Object: StoredProcedure [dbo].[existsZContent] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsZContent] ( @ContentID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [ZContents] WHERE [ContentID]=@ContentID RETURN GO /****** Object: StoredProcedure [dbo].[getZContents] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getZContents] WITH EXECUTE AS OWNER AS SELECT [ContentID], [OldStepSequence], [LastChanged] FROM [ZContents] RETURN GO /****** Object: StoredProcedure [dbo].[existsPermission] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsPermission] ( @PID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Permissions] WHERE [PID]=@PID RETURN GO /****** Object: StoredProcedure [dbo].[getRoles] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getRoles] WITH EXECUTE AS OWNER AS SELECT [RID], [Name], [Title], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Assignments] WHERE [Assignments].[RID]=[Roles].[RID]) [AssignmentCount], (SELECT COUNT(*) FROM [Permissions] WHERE [Permissions].[RID]=[Roles].[RID]) [PermissionCount] FROM [Roles] RETURN GO /****** Object: StoredProcedure [dbo].[getRoleByName] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getRoleByName] ( @Name nvarchar(50) ) WITH EXECUTE AS OWNER AS SELECT [RID], [Name], [Title], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Assignments] WHERE [Assignments].[RID]=[Roles].[RID]) [AssignmentCount], (SELECT COUNT(*) FROM [Permissions] WHERE [Permissions].[RID]=[Roles].[RID]) [PermissionCount] FROM [Roles] WHERE [Name]=@Name RETURN GO /****** Object: StoredProcedure [dbo].[getPermissionsByRID] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getPermissionsByRID] ( @RID int ) WITH EXECUTE AS OWNER AS SELECT [Permissions].[PID], [Permissions].[RID], [Permissions].[PermLevel], [Permissions].[VersionType], [Permissions].[PermValue], [Permissions].[PermAD], [Permissions].[StartDate], [Permissions].[EndDate], [Permissions].[Config], [Permissions].[DTS], [Permissions].[UsrID], [Permissions].[LastChanged] FROM [Permissions] WHERE [Permissions].[RID]=@RID RETURN GO /****** Object: StoredProcedure [dbo].[getPermission] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getPermission] ( @PID int ) WITH EXECUTE AS OWNER AS SELECT [PID], [RID], [PermLevel], [VersionType], [PermValue], [PermAD], [StartDate], [EndDate], [Config], [DTS], [UsrID], [LastChanged] FROM [Permissions] WHERE [PID]=@PID RETURN GO /****** Object: StoredProcedure [dbo].[getPermissions] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getPermissions] WITH EXECUTE AS OWNER AS SELECT [PID], [RID], [PermLevel], [VersionType], [PermValue], [PermAD], [StartDate], [EndDate], [Config], [DTS], [UsrID], [LastChanged] FROM [Permissions] RETURN GO /****** Object: StoredProcedure [dbo].[deleteRole] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteRole] ( @RID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Assignments] WHERE [RID]=@RID DELETE [Permissions] WHERE [RID]=@RID DELETE [Roles] WHERE [RID] = @RID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[deletePermission] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deletePermission] ( @PID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Permissions] WHERE [PID] = @PID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[updatePermission] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updatePermission] ( @PID int, @RID int, @PermLevel int, @VersionType int, @PermValue int, @PermAD int, @StartDate datetime, @EndDate datetime=null, @Config nvarchar(MAX)=null, @DTS datetime, @UsrID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Permissions] SET [RID]=@RID, [PermLevel]=@PermLevel, [VersionType]=@VersionType, [PermValue]=@PermValue, [PermAD]=@PermAD, [StartDate]=@StartDate, [EndDate]=@EndDate, [Config]=@Config, [DTS]=@DTS, [UsrID]=@UsrID WHERE [PID]=@PID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Permissions] WHERE [PID]=@PID) RAISERROR('Permission record has been deleted by another user', 16, 1) ELSE RAISERROR('Permission has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Permissions] WHERE [PID]=@PID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[addPermission] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addPermission] ( @RID int, @PermLevel int, @VersionType int, @PermValue int, @PermAD int, @StartDate datetime, @EndDate datetime=null, @Config nvarchar(MAX)=null, @DTS datetime, @UsrID nvarchar(100), @newPID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Permissions] ( [RID], [PermLevel], [VersionType], [PermValue], [PermAD], [StartDate], [EndDate], [Config], [DTS], [UsrID] ) VALUES ( @RID, @PermLevel, @VersionType, @PermValue, @PermAD, @StartDate, @EndDate, @Config, @DTS, @UsrID ) SELECT @newPID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Permissions] WHERE [PID]=@newPID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[addUser] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addUser] ( @UserID nvarchar(100), @FirstName nvarchar(50)=null, @MiddleName nvarchar(50)=null, @LastName nvarchar(50)=null, @Suffix nvarchar(10)=null, @CourtesyTitle nvarchar(10)=null, @PhoneNumber nvarchar(30)=null, @CFGName nvarchar(8)=null, @UserLogin nvarchar(10)=null, @UserName nvarchar(32)=null, @Config nvarchar(MAX)=null, @DTS datetime, @UsrID nvarchar(100), @newUID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Users] ( [UserID], [FirstName], [MiddleName], [LastName], [Suffix], [CourtesyTitle], [PhoneNumber], [CFGName], [UserLogin], [UserName], [Config], [DTS], [UsrID] ) VALUES ( @UserID, @FirstName, @MiddleName, @LastName, @Suffix, @CourtesyTitle, @PhoneNumber, @CFGName, @UserLogin, @UserName, @Config, @DTS, @UsrID ) SELECT @newUID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Users] WHERE [UID]=@newUID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[updateUser] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateUser] ( @UID int, @UserID nvarchar(100), @FirstName nvarchar(50)=null, @MiddleName nvarchar(50)=null, @LastName nvarchar(50)=null, @Suffix nvarchar(10)=null, @CourtesyTitle nvarchar(10)=null, @PhoneNumber nvarchar(30)=null, @CFGName nvarchar(8)=null, @UserLogin nvarchar(10)=null, @UserName nvarchar(32)=null, @Config nvarchar(MAX)=null, @DTS datetime, @UsrID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Users] SET [UserID]=@UserID, [FirstName]=@FirstName, [MiddleName]=@MiddleName, [LastName]=@LastName, [Suffix]=@Suffix, [CourtesyTitle]=@CourtesyTitle, [PhoneNumber]=@PhoneNumber, [CFGName]=@CFGName, [UserLogin]=@UserLogin, [UserName]=@UserName, [Config]=@Config, [DTS]=@DTS, [UsrID]=@UsrID WHERE [UID]=@UID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Users] WHERE [UID]=@UID) RAISERROR('User record has been deleted by another user', 16, 1) ELSE RAISERROR('User has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Users] WHERE [UID]=@UID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[existsUser] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsUser] ( @UID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Users] WHERE [UID]=@UID RETURN GO /****** Object: StoredProcedure [dbo].[getTransitionsByFromID] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getTransitionsByFromID] ( @FromID int ) WITH EXECUTE AS OWNER AS SELECT [Transitions].[TransitionID], [Transitions].[FromID], [Transitions].[ToID], [Transitions].[RangeID], [Transitions].[IsRange], [Transitions].[TranType], [Transitions].[Config], [Transitions].[DTS], [Transitions].[UserID], [Transitions].[LastChanged], [Items_RangeID].[PreviousID] [Item_RangeID_PreviousID], [Items_RangeID].[ContentID] [Item_RangeID_ContentID], [Items_RangeID].[DTS] [Item_RangeID_DTS], [Items_RangeID].[UserID] [Item_RangeID_UserID], [Items_ToID].[PreviousID] [Item_ToID_PreviousID], [Items_ToID].[ContentID] [Item_ToID_ContentID], [Items_ToID].[DTS] [Item_ToID_DTS], [Items_ToID].[UserID] [Item_ToID_UserID], (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=[Transitions].[TransitionID]) [ZTransitionCount] FROM [Transitions] JOIN [Items] [Items_RangeID] ON [Items_RangeID].[ItemID]=[Transitions].[RangeID] JOIN [Items] [Items_ToID] ON [Items_ToID].[ItemID]=[Transitions].[ToID] WHERE [Transitions].[FromID]=@FromID RETURN GO /****** Object: StoredProcedure [dbo].[existsItem] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsItem] ( @ItemID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Items] WHERE [ItemID]=@ItemID RETURN GO /****** Object: StoredProcedure [dbo].[vesp_ListContentPath] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- vesp_ListContentPath 148 create PROCEDURE [vesp_ListContentPath] ( @ContentID int ) WITH EXECUTE AS OWNER AS BEGIN with ContentZ(BaseID,ContentID,ItemID,Number,Text,Item,Level,PreviousID) as ( Select II.ItemID,CC.ContentID,II.ItemID,CC.Number,CC.Text,1,1,II.PreviousID from Items II join Contents CC on CC.ContentID=II.ContentID where @ContentID=II.ContentID Union All -- Select BaseID,CC.ContentID,II.ItemID,CC.Number,CC.Text,ZZ.Item+1,ZZ.Level,II.PreviousID FROM ContentZ ZZ Join Items II on II.ItemID = ZZ.PreviousID Join Contents CC on II.ContentID = CC.ContentID where ZZ.PreviousID is not null Union All Select BaseID,CC.ContentID,II.ItemID,CC.Number,CC.Text,1,ZZ.Level+1,II.PreviousID FROM ContentZ ZZ Join Parts PP on ZZ.ItemID = PP.ItemID Join Contents CC on PP.ContentID = CC.ContentID Join Items II on II.ContentID = CC.ContentID where ZZ.PreviousID is null --and ZZ.ItemID in(717,715,711,662) ) Select ZZ.BaseID,ZZ.Level,MaxItem,ZZ.Number,ZZ.Text from ContentZ ZZ join (select BaseID, Level, max(item) MaxItem from ContentZ group by BaseID,Level) T1 on T1.BaseID=ZZ.BaseID and T1.Level = ZZ.Level where Item=1 order by ZZ.BaseID,ZZ.Level Desc, Item Desc end GO /****** Object: StoredProcedure [dbo].[getPartsByContentID] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getPartsByContentID] ( @ContentID int ) WITH EXECUTE AS OWNER AS SELECT [Parts].[ContentID], [Parts].[FromType], [Parts].[ItemID], [Parts].[DTS], [Parts].[UserID], [Parts].[LastChanged], [Items].[PreviousID] [Item_PreviousID], [Items].[ContentID] [Item_ContentID], [Items].[DTS] [Item_DTS], [Items].[UserID] [Item_UserID] FROM [Parts] JOIN [Items] ON [Items].[ItemID]=[Parts].[ItemID] WHERE [Parts].[ContentID]=@ContentID RETURN GO /****** Object: StoredProcedure [dbo].[vesp_CleanUpItems] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select *, .dbo.ve_GetParts(ContentID,6) SubSteps from items where contentid in(select contentid from contents where text like 'DISPATCH operator to open breaker%') select * from items where itemid in(298,299,436,440) select itemid from items where previousid is null and itemid not in (select itemid from parts) --select * from contents where text like 'foldout cip%' select count(*) from parts */ CREATE procedure [vesp_CleanUpItems] WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION BEGIN with Itemz(ItemID) as( select itemid from items where previousid is null and itemid not in(1) and itemid not in (select itemid from parts) UNION ALL select ii.itemid from items ii join itemz zz on zz.itemid = ii.previousid ) delete from items where itemid in (select itemid from itemz) END IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: UserDefinedFunction [dbo].[vefn_SiblingChildrenItems] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select * from Transitions where (ToID in(select ItemID From dbo.vefn_ChildrenItems(185,184))) OR (RangeID in(select ItemID From dbo.vefn_ChildrenItems(185,184))) AND NOT (FromID in(Select ContentID From dbo.vefn_ChildrenItems(185,184))) */ CREATE FUNCTION [vefn_SiblingChildrenItems](@ItemID int) RETURNS @SiblingChildren TABLE ( ItemID int PRIMARY KEY, ContentID int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], 0 [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 as [pContentID],[DTS] As [pDTS], [UserID] As [pUserID], [LastChanged] As [pLastChanged] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,P.[ContentID] as [pContentID],P.[DTS] As [pDTS],P.[UserID] As [pUserID],P.[LastChanged] As [pLastChanged] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID -- Siblings Union All select [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null from Itemz Z join Items I on I.PreviousID = Z.ItemID ) insert into @SiblingChildren select ItemID, ContentID from Itemz RETURN END GO /****** Object: UserDefinedFunction [dbo].[vefn_SiblingItems] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select * from Transitions where (ToID in(select ItemID From dbo.vefn_ChildrenItems(185,184))) OR (RangeID in(select ItemID From dbo.vefn_ChildrenItems(185,184))) AND NOT (FromID in(Select ContentID From dbo.vefn_ChildrenItems(185,184))) */ CREATE FUNCTION [vefn_SiblingItems](@ItemID int, @ParentID int) RETURNS @Siblings TABLE ( ItemID int PRIMARY KEY, ContentID int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], @ParentID [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 [pContentID],[DTS] [pDTS], [UserID] [pUserID], [LastChanged] [pLastChanged] FROM [Items] where [ItemID]=@ItemID -- Siblings Union All select [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null from Itemz Z join Items I on I.PreviousID = Z.ItemID ) insert into @Siblings select ItemID, ContentID from Itemz RETURN END GO /****** Object: StoredProcedure [dbo].[getAnnotationsByTypeID] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getAnnotationsByTypeID] ( @TypeID int ) WITH EXECUTE AS OWNER AS SELECT [Annotations].[AnnotationID], [Annotations].[ItemID], [Annotations].[TypeID], [Annotations].[RtfText], [Annotations].[SearchText], [Annotations].[Config], [Annotations].[DTS], [Annotations].[UserID], [Annotations].[LastChanged], [Items].[PreviousID] [Item_PreviousID], [Items].[ContentID] [Item_ContentID], [Items].[DTS] [Item_DTS], [Items].[UserID] [Item_UserID] FROM [Annotations] JOIN [Items] ON [Items].[ItemID]=[Annotations].[ItemID] WHERE [Annotations].[TypeID]=@TypeID RETURN GO /****** Object: StoredProcedure [dbo].[getAnnotationType] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getAnnotationType] ( @TypeID int ) WITH EXECUTE AS OWNER AS SELECT [TypeID], [Name], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[TypeID]=[AnnotationTypes].[TypeID]) [AnnotationCount] FROM [AnnotationTypes] WHERE [TypeID]=@TypeID SELECT [Annotations].[AnnotationID], [Annotations].[ItemID], [Annotations].[TypeID], [Annotations].[RtfText], [Annotations].[SearchText], [Annotations].[Config], [Annotations].[DTS], [Annotations].[UserID], [Annotations].[LastChanged], [Items].[PreviousID] [Item_PreviousID], [Items].[ContentID] [Item_ContentID], [Items].[DTS] [Item_DTS], [Items].[UserID] [Item_UserID] FROM [Annotations] JOIN [Items] ON [Items].[ItemID]=[Annotations].[ItemID] WHERE [Annotations].[TypeID]=@TypeID RETURN GO /****** Object: UserDefinedFunction [dbo].[FindText] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO Create FUNCTION [FindText](@LookFor varchar(255)) RETURNS @Results TABLE ( ItemID int PRIMARY KEY, ContentID int ) WITH EXECUTE AS OWNER BEGIN insert into @Results select itemid,ii.contentid from items ii join contents cc on ii.contentid = cc.contentid where text like @LookFor RETURN END GO /****** Object: UserDefinedFunction [dbo].[ve_GetShortPath] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select ItemID, CC.Type, dbo.ve_GetPath(ItemID) from Items II join Contents CC on II.ContentID = CC.ContentID where ItemID in(111,265,266,267) */ -- drop function ve_GetPath CREATE FUNCTION [ve_GetShortPath] (@ItemID int) RETURNS varchar(max) WITH EXECUTE AS OWNER AS BEGIN -- declare @STructID int --set @StructID=11 declare @Path varchar(max); with Itemz(ItemCount,ItemID,PreviousID,FromType,CType,Number,Text,PPath, Path) as ( Select 1,ItemID,PreviousID,0,C.Type/10000,C.Number,C.Text, Cast(Case when C.Type < 20000 then '`' + [dbo].[ve_GetShortPart](C.Number,C.Text) else '' end as nvarchar(max)) PPath, Cast(Case when C.Type < 20000 then '`' + [dbo].[ve_GetShortPart](C.Number,C.Text) else '1' end as nvarchar(max)) Path from Items I join Contents C on I.ContentID = C.ContentID where ItemID=@ItemID Union All -- siblings Select ItemCount+1,I.PreviousID,II.PreviousID,0,C.Type/10000,Z.Number,Z.Text,PPath,cast(ItemCount + 1 as nvarchar(3)) + PPath from Items I join Contents C on I.ContentID = C.ContentID Join Items II on II.ItemID = I.PreviousID Join Itemz Z on I.ItemID=Z.ItemID where I.PreviousID != 0 Union All -- children select 1,I.ItemID,I.PreviousID,P.FromType,C.Type/10000,C.Number,C.Text, case C.Type/10000 when 0 then '`' + [dbo].[ve_GetShortPart](C.Number,C.Text) when 1 then '`' + [dbo].[ve_GetShortPart](C.Number,C.Text) +'`' + cast(ItemCount + 0 as varchar(3)) else case P.FromType when 1 then 'PRC`' + cast(ItemCount + 0 as varchar(3)) when 2 then '`SEC`' + cast(ItemCount + 0 as varchar(3)) when 3 then '`Caution`' + cast(ItemCount + 0 as varchar(3)) when 4 then '`Note`' + cast(ItemCount + 0 as varchar(3)) when 5 then '`RNO`' when 7 then '`Table`' else '`' + cast(ItemCount + 0 as varchar(3)) end end + PPath PPath, --'1' + case C.Type/10000 when 0 then '`' + [dbo].[ve_GetShortPart](C.Number,C.Text) when 1 then '`' + [dbo].[ve_GetShortPart](C.Number,C.Text) +'`' + cast(ItemCount + 0 as varchar(3)) else case P.FromType when 1 then 'PRC`' + cast(ItemCount + 0 as varchar(3)) when 2 then '`SEC`' + cast(ItemCount + 0 as varchar(3)) when 3 then '`Caution`' + cast(ItemCount + 0 as varchar(3)) when 4 then '`Note`' + cast(ItemCount + 0 as varchar(3)) when 5 then '`RNO' when 7 then '`Table' else '`' + cast(ItemCount + 0 as varchar(3)) end end + PPath Path from Parts P join Items I on I.ContentID = P.ContentID join Contents C on I.ContentID = C.ContentID join Itemz Z on P.ItemID=Z.ItemID ) select @Path = path From Itemz where ItemCount=1 and CType=0 OPTION (MAXRECURSION 10000) return REPLACE(@Path,'\u8209?','-') END; GO /****** Object: UserDefinedFunction [dbo].[ve_GetPath] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select ItemID, CC.Type, dbo.ve_GetPath(ItemID) from Items II join Contents CC on II.ContentID = CC.ContentID where ItemID in(111,265,266,267) */ -- drop function ve_GetPath CREATE FUNCTION [ve_GetPath] (@ItemID int) RETURNS varchar(max) WITH EXECUTE AS OWNER AS BEGIN -- declare @STructID int --set @StructID=11 declare @Path varchar(max); with Itemz(ItemCount,ItemID,PreviousID,FromType,CType,Number,Text,PPath, Path) as ( Select 1,ItemID,PreviousID,0,C.Type/10000,C.Number,C.Text, Cast(Case when C.Type < 20000 then '`' + C.Number +'`' + C.Text else '' end as nvarchar(max)) PPath, Cast(Case when C.Type < 20000 then '`' + C.Number +'`' + C.Text else '1' end as nvarchar(max)) Path from Items I join Contents C on I.ContentID = C.ContentID where ItemID=@ItemID Union All -- siblings Select ItemCount+1,I.PreviousID,II.PreviousID,0,C.Type/10000,Z.Number,Z.Text,PPath,cast(ItemCount + 1 as nvarchar(3)) + PPath from Items I join Contents C on I.ContentID = C.ContentID Join Items II on II.ItemID = I.PreviousID Join Itemz Z on I.ItemID=Z.ItemID where I.PreviousID != 0 Union All -- children select 1,I.ItemID,I.PreviousID,P.FromType,C.Type/10000,C.Number,C.Text, case C.Type/10000 when 0 then '`' + C.Number +'`' + C.Text when 1 then '`' + C.Number +'`' + C.Text +'`' + cast(ItemCount + 0 as varchar(3)) else case P.FromType when 1 then 'PRC`' + cast(ItemCount + 0 as varchar(3)) when 2 then '`SEC`' + cast(ItemCount + 0 as varchar(3)) when 3 then '`Caution`' + cast(ItemCount + 0 as varchar(3)) when 4 then '`Note`' + cast(ItemCount + 0 as varchar(3)) when 5 then '`RNO`' when 7 then '`Table`' else '`' + cast(ItemCount + 0 as varchar(3)) end end + PPath PPath, --'1' + case C.Type/10000 when 0 then '`' + C.Number +'`' + C.Text when 1 then '`' + C.Number +'`' + C.Text +'`' + cast(ItemCount + 0 as varchar(3)) else case P.FromType when 1 then 'PRC`' + cast(ItemCount + 0 as varchar(3)) when 2 then '`SEC`' + cast(ItemCount + 0 as varchar(3)) when 3 then '`Caution`' + cast(ItemCount + 0 as varchar(3)) when 4 then '`Note`' + cast(ItemCount + 0 as varchar(3)) when 5 then '`RNO' when 7 then '`Table' else '`' + cast(ItemCount + 0 as varchar(3)) end end + PPath Path from Parts P join Items I on I.ContentID = P.ContentID join Contents C on I.ContentID = C.ContentID join Itemz Z on P.ItemID=Z.ItemID ) select @Path = path From Itemz where ItemCount=1 and CType=0 OPTION (MAXRECURSION 10000) return @Path END; GO /****** Object: UserDefinedFunction [dbo].[ve_GetParts] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO --select .dbo.ve_GetParts(756,6) CREATE FUNCTION [ve_GetParts] (@ContentID int,@FromType int) RETURNS varchar(max) WITH EXECUTE AS OWNER AS BEGIN declare @retval varchar(max) begin with ContentZ(AllContents,PreviousID,HasChildren) as ( Select cast(II.ContentID as varchar(max)) AllContents,II.ItemID PreviousID, case when Exists(select ItemID from Items where PreviousID = II.ItemID) then 1 else 0 end HasChildren from Items II join Parts PP on II.ItemID=PP.ItemID where PP.ContentID=@ContentID and PP.FromType = @FromType Union All -- Select ZZ.AllContents + '.' + cast(II.ContentID as varchar(max)) AllContents,II.ItemID PreviousID, case when Exists(select ItemID from Items where PreviousID = II.ItemID) then 1 else 0 end HasChildren from Items II Join ContentZ ZZ on II.PreviousID = ZZ.PreviousID ) Select @retval = AllContents from ContentZ where HasChildren=0 OPTION (MAXRECURSION 1000) end return @retval end /* ALTER FUNCTION [dbo].[ve_GetPath] (@StructID int) RETURNS varchar(max) WITH EXECUTE AS OWNER AS BEGIN -- declare @STructID int --set @StructID=11 declare @Path varchar(max); with Struct(FromType,FromID,Item,PPath,Path) as ( Select FromType,FromID,0 Item,Cast('' as varchar(max)) PPath , Cast(case FromType when 1 then 'PRC.000' when 2 then '.SEC.000' when 3 then '.CAU.000' when 4 then '.NOT.000' when 5 then '.RNO' when 7 then '.TAB' else '.000' end as varchar(max)) Path from Structures where StructureID=@StructID Union All -- Child Select A.FromType,A.FromID,0 as Item,Path, Cast(case A.FromType when 1 then 'PRC.000' when 2 then '.SEC.000' when 3 then '.CAU.000' when 4 then '.NOT.000' when 5 then '.RNO' when 7 then '.TAB' else '.000' end + Path as varchar(max)) Path from Structures A Join Struct C on C.FromID=A.StructureID where C.FromType <> 0 Union All -- Sibling Select A.FromType,A.FromID,Item + 1 Item,PPath, case A.FromType when 1 then 'PRC.' when 2 then '.SEC.' when 3 then '.CAU.' when 4 then '.NOT.' when 5 then '.RNO.' when 7 then '.TAB.' else '.' end + right('000' + cast(Item + 1 as varchar(3)),3) + PPath Path from Structures A Join Struct C on C.FromID=A.StructureID where C.FromType = 0 ) --select * from Struct OPTION (MAXRECURSION 1000) Select @Path = Path from Struct where FromID=0 OPTION (MAXRECURSION 1000) --print @path return @Path END; */ GO /****** Object: UserDefinedFunction [dbo].[ve_GetNextTranCount] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select dbo.ve_GetNextTranCount(251) NextTrans select *, dbo.ve_GetNextTranCount(ItemID) NextTrans from vefn_AllHighLevelSteps() Order By dbo.ve_GetNextTranCount(ItemID) DESC Select count(*) from Transitions TT join contents CC on TT.FromID = CC.ContentID where FromID in (Select ContentID from vefn_ChildItems(247)) AND (ToID = 251 or RangeID = 251) declare @ItemID int; set @ItemID=251 declare @Count int; declare @PreviousID as int select @PreviousID = PreviousID from items where ItemID = @ItemID Print @PreviousID if @PreviousID is not null BEGIN Select @Count = count(*) from vefn_ChildItems(247) --Select @Count = count(*) from Transitions TT --join contents CC on TT.FromID = CC.ContentID --where FromID in (Select ContentID from vefn_ChildItems(@PreviousID)) --AND (ToID = @ItemID or RangeID = @ItemID) END --ELSE --set @Count=0 Print 'I''m here' Print @Count Select * from vefn_ChildItems(247) */ CREATE FUNCTION [ve_GetNextTranCount] (@ItemID int) RETURNS int WITH EXECUTE AS OWNER AS BEGIN declare @Count int; declare @PreviousID as int select @PreviousID = PreviousID from items where ItemID = @ItemID if @PreviousID is not null BEGIN Select @Count = count(*) from Transitions TT join contents CC on TT.FromID = CC.ContentID where FromID in (Select ContentID from vefn_ChildItems(@PreviousID)) AND (ToID = @ItemID or RangeID = @ItemID) END ELSE set @Count=0 return @Count END; GO /****** Object: UserDefinedFunction [dbo].[ve_GetChildCount] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* -- Select Procedures with Children select ItemID, dbo.ve_GetChildCount(ItemID) ChildCount from [Items] II Join [Contents] CC on II.ContentID = CC.ContentID and CC.Type = 0 and CC.ContentID in (Select ContentID from Parts) order dbo.ve_GetChildCount(ItemID) desc */ CREATE FUNCTION [ve_GetChildCount] (@ItemID int) RETURNS int WITH EXECUTE AS OWNER AS BEGIN declare @Count int; with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged]) as ( Select 0 [Level], 0 [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID -- Siblings Union All select [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.[Level] > 0 ) Select @Count = Count(*) from Itemz OPTION (MAXRECURSION 10000) return @Count END; GO /****** Object: StoredProcedure [dbo].[updateItem] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateItem] ( @ItemID int, @PreviousID int=null, @ContentID int, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Items] SET [PreviousID]=@PreviousID, [ContentID]=@ContentID, [DTS]=@DTS, [UserID]=@UserID WHERE [ItemID]=@ItemID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Items] WHERE [ItemID]=@ItemID) RAISERROR('Item record has been deleted by another user', 16, 1) ELSE RAISERROR('Item has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Items] WHERE [ItemID]=@ItemID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getItemAndChildren] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- getItemAndChildren 111 CREATE PROCEDURE [getItemAndChildren] (@ItemID int) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged]) as ( Select 0 [Level], 0 [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID -- Siblings Union All select [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.[Level] > 0 ) select I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged] from ItemZ I join Contents C on C.ContentID = I.ContentID order by I.[Level] , I.[FromType], I.[Ordinal] END GO /****** Object: StoredProcedure [dbo].[getItemNextAndChildren] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- getItemNextAndChildren 111 CREATE PROCEDURE [getItemNextAndChildren] (@ItemID int) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged]) as ( Select 0 [Level], 0 [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID -- Siblings Union All select [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] from Itemz Z join Items I on I.PreviousID = Z.ItemID ) select I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged] from ItemZ I join Contents C on C.ContentID = I.ContentID order by I.[Level] , I.[FromType], I.[Ordinal] END GO /****** Object: UserDefinedFunction [dbo].[vefn_FindExternalChildTransitions] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Select * from vefn_FindExternalChildTransitions(185) */ CREATE FUNCTION [vefn_FindExternalChildTransitions](@ItemID int) RETURNS @Children TABLE ( FromItemID int, ToID int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 [pContentID],[DTS] [pDTS], [UserID] [pUserID], [LastChanged] [pLastChanged] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID],P.[LastChanged] [pLastChanged] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID -- Siblings Union All select [Level] ,Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.[Level] > 0 ) insert into @Children select ItemID [FromItemID], case when TT.ToID in(select ItemID from Itemz) then TT.ToID else TT.RangeID end [ToID] from Transitions TT join Items II on II.ContentID=TT.FromID where (ToID in(select ItemID from Itemz where Level > 0) OR RangeID in(select ItemID from Itemz where Level > 0)) AND FromID not in(Select ContentID from ItemZ) RETURN END GO /****** Object: UserDefinedFunction [dbo].[vefn_FindExternalTransitions] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Select * from vefn_FindExternalTransitions(185) */ CREATE FUNCTION [vefn_FindExternalTransitions](@ItemID int) RETURNS @Children TABLE ( [FromItemID] int, [TransitionID] [int] NOT NULL, [FromID] [int] NOT NULL, [ToID] [int] NOT NULL, [RangeID] [int] NOT NULL, [Config] [nvarchar](max) NULL ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 [pContentID],[DTS] [pDTS], [UserID] [pUserID], [LastChanged] [pLastChanged] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID],P.[LastChanged] [pLastChanged] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID -- Siblings Union All select [Level] ,Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.[Level] > 0 ) insert into @Children select ItemID [FromItemID], TT.[TransitionID], TT.[FromID], TT.[ToID], TT.[RangeID], TT.[Config] from Transitions TT join Items II on II.ContentID=TT.FromID where (ToID in(select ItemID from Itemz) OR RangeID in(select ItemID from Itemz)) AND FromID not in(Select ContentID from ItemZ) RETURN END GO /****** Object: UserDefinedFunction [dbo].[vefn_FindInternalTransitions] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Select * from vefn_FindInternalTransitions(185) */ CREATE FUNCTION [vefn_FindInternalTransitions](@ItemID int) RETURNS @Children TABLE ( FromItemID int, ToID int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 [pContentID],[DTS] [pDTS], [UserID] [pUserID], [LastChanged] [pLastChanged] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID],P.[LastChanged] [pLastChanged] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID -- Siblings Union All select [Level] ,Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.[Level] > 0 ) insert into @Children select ItemID [FromItemID], case when TT.ToID in(select ItemID from Itemz) then TT.ToID else TT.RangeID end [ToID] from Transitions TT join Items II on II.ContentID=TT.FromID where (ToID in(select ItemID from Itemz) OR RangeID in(select ItemID from Itemz)) AND FromID in(Select ContentID from ItemZ) RETURN END GO /****** Object: UserDefinedFunction [dbo].[vefn_FindInternalTransitionsForCopy] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Select * from vefn_FindInternalTransitionsForCopy(10277) */ CREATE FUNCTION [vefn_FindInternalTransitionsForCopy](@ItemID int) RETURNS @Transitions TABLE ( TransitionID int, FromID int, TranType int, ToID int, RangeID int, OldTransition int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 [pContentID],[DTS] [pDTS], [UserID] [pUserID], [LastChanged] [pLastChanged] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID],P.[LastChanged] [pLastChanged] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID -- Siblings Union All select [Level] ,Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.[Level] > 0 ) insert into @Transitions select TransitionID, FromID, TT.TranType, TT.ToID, TT.RangeID, CAST(TT.Config as int) --case when TT.ToID in(select ItemID from Itemz) then TT.ToID else TT.RangeID end [ToID] from Transitions TT join Items II on II.ContentID=TT.FromID where (ToID in(select ItemID from Itemz) OR RangeID in(select ItemID from Itemz)) AND FromID in(Select ContentID from ItemZ) RETURN END GO /****** Object: UserDefinedFunction [dbo].[vefn_FindAffectedTransitions] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select top 1 * from items order by itemid desc Select FromID,.dbo.ve_GetPathFromContentID(FromID) ContentPath ,ToID,dbo.ve_GetPath(ToID) ToPath ,RangeID,dbo.ve_GetPath(RangeID) RangePath ,cc.Text from vefn_FindAffectedTransitions(2102) ttz join transitions tt on ttz.TransitionID = tt.TransitionID --join items ii on ii.ItemID = tt.fromID join contents cc on tt.FromID = cc.contentid */ CREATE FUNCTION [vefn_FindAffectedTransitions](@ItemID int) RETURNS @Transitions TABLE ( TransitionID int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 [pContentID],[DTS] [pDTS], [UserID] [pUserID], [LastChanged] [pLastChanged] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID],P.[LastChanged] [pLastChanged] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID -- All Siblings Union All select [Level] ,Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null from Itemz Z join Items I on I.PreviousID = Z.ItemID --where Z.[Level] > 0 -- This would limit the siblings to the siblings of the children and not the initial ItemID ) , Itemz2([Level], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 [pContentID],[DTS] [pDTS], [UserID] [pUserID], [LastChanged] [pLastChanged] FROM [Items] where [ItemID]=@ItemID -- All Siblings Union All select [Level] ,Z.[Ordinal] -1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null from Itemz2 Z join Items I on Z.PreviousID = I.ItemID --where Z.[Level] > 0 -- This would limit the siblings to the siblings of the children and not the initial ItemID ) insert into @Transitions select TransitionID from Transitions TT where (ToID in(select ItemID from Itemz) OR RangeID in(select ItemID from Itemz)) UNION select TransitionID from Transitions TT JOIN Itemz2 on ToID=ItemID and RangeID=ItemID and IsRange = 2 RETURN END GO /****** Object: UserDefinedFunction [dbo].[vefn_ChildItemsRange] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE FUNCTION [vefn_ChildItemsRange](@StartItemID int, @EndItemID int, @DestFormat int) RETURNS @Children TABLE ( ItemID int PRIMARY KEY, ContentID int, FormatID int ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @FormatID int SELECT @FormatID = isnull(@DestFormat,.dbo.vefn_GetInheritedFormat(@StartItemID,1)) BEGIN with Itemz([Level], [ItemID], [ContentID], [FormatID], [FoundEnd]) as ( Select 0 [Level], [ItemID], I.[ContentID], IsNull(C.[FormatID], @FormatID), case [ItemID] when @EndItemID then 1 else 0 end [FoundEnd] FROM [Items] I JOIN [Contents] C on I.ContentID = C.ContentID where [ItemID]=@StartItemID Union All -- Children select [Level] + 1, I.[ItemID], I.[ContentID], IsNull(C.[FormatID], Z.[FormatID]), case I.[ItemID] when @EndItemID then 1 else 0 end [FoundEnd] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID JOIN [Contents] C on I.ContentID = C.ContentID -- Siblings Union All select [Level] , I.[ItemID], I.[ContentID], IsNull(C.[FormatID], Z.[FormatID]), case I.[ItemID] when @EndItemID then 1 else 0 end [FoundEnd] from Itemz Z join Items I on I.PreviousID = Z.ItemID JOIN [Contents] C on I.ContentID = C.ContentID where FoundEnd = 0 ) insert into @Children select ItemID, ContentID, FormatID from Itemz RETURN END END GO /****** Object: UserDefinedFunction [dbo].[vefn_ChildrenItems] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select * from Transitions where (ToID in(select ItemID From dbo.vefn_ChildrenItems(185,184))) OR (RangeID in(select ItemID From dbo.vefn_ChildrenItems(185,184))) AND NOT (FromID in(Select ContentID From dbo.vefn_ChildrenItems(185,184))) */ CREATE FUNCTION [vefn_ChildrenItems](@ItemID int, @ParentID int) RETURNS @Children TABLE ( ItemID int PRIMARY KEY, ContentID int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], @ParentID [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 [pContentID],[DTS] [pDTS], [UserID] [pUserID], [LastChanged] [pLastChanged] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID],P.[LastChanged] [pLastChanged] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID -- Siblings Union All select [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.[Level] > 0 ) insert into @Children select ItemID, ContentID from Itemz RETURN END GO /****** Object: StoredProcedure [dbo].[addItem] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addItem] ( @PreviousID int=null, @ContentID int, @DTS datetime, @UserID nvarchar(100), @newItemID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Items] ( [PreviousID], [ContentID], [DTS], [UserID] ) VALUES ( @PreviousID, @ContentID, @DTS, @UserID ) SELECT @newItemID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Items] WHERE [ItemID]=@newItemID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: UserDefinedFunction [dbo].[vefn_ChildItems] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* declare @PreviousID as int declare @ItemID as int set @ItemID = 450 select @PreviousID = PreviousID from items where ItemID = @ItemID Select * from Items where ItemID = @ItemID select * from Transitions where FromID in (Select ContentID from vefn_ChildItems(@PreviousID)) AND (ToID = @ItemID or RangeID = @ItemID) select CC.Text from Transitions TT join contents CC on TT.FromID = CC.ContentID where FromID in (Select ContentID from vefn_ChildItems(@PreviousID)) AND (ToID = @ItemID or RangeID = @ItemID) */ CREATE FUNCTION [vefn_ChildItems](@ItemID int) RETURNS @Children TABLE ( ItemID int PRIMARY KEY, ContentID int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ItemID], [ContentID]) as ( Select 0 [Level], [ItemID], [ContentID] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1, I.[ItemID], I.[ContentID] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID -- Siblings Union All select [Level] , I.[ItemID], I.[ContentID] from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.[Level] > 0 ) insert into @Children select ItemID, ContentID from Itemz RETURN END GO /****** Object: UserDefinedFunction [dbo].[ve_GetSiblingCount] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select top 5 CC.Number,CC.Text,Type,ItemID, dbo.ve_GetSiblingCount(ItemID) HLStepCount from Contents CC Join Parts PP on PP.ContentID = CC.ContentID where CC.Type >= 10000 and CC.Type < 20000 order by dbo.ve_GetSiblingCount(ItemID) desc select top 5 CC.Number,CC.Text,Type,ItemID, dbo.ve_GetSiblingCount(ItemID) SectionCount from Contents CC Join Parts PP on PP.ContentID = CC.ContentID where CC.Type < 10000 order by dbo.ve_GetSiblingCount(ItemID) desc select top 5 CC.Text,Type,ItemID, dbo.ve_GetSiblingCount(ItemID) SubStepCount from Contents CC Join Parts PP on PP.ContentID = CC.ContentID where CC.Type >= 20000 order by dbo.ve_GetSiblingCount(ItemID) desc */ CREATE FUNCTION [ve_GetSiblingCount] (@ItemID int) RETURNS int WITH EXECUTE AS OWNER AS BEGIN declare @Count int; with Itemz([Direction], [ItemID], [PreviousID]) as ( Select 0 Direction,[ItemID], [PreviousID] FROM [Items] where [ItemID]=@ItemID -- Siblings Previous Union All select -1 Direction,I.[ItemID], I.[PreviousID] from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.Direction <= 0 -- Siblings Next Union All select 1 Direction,I.[ItemID], I.[PreviousID] from Itemz Z join Items I on I.ItemID = Z.PreviousID where Z.Direction >= 0 ) Select @Count = Count(*) from Itemz return @Count END; GO /****** Object: StoredProcedure [dbo].[getExternalTransitions] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* exec getExternalTransitions 4984 */ CREATE PROCEDURE [getExternalTransitions] ( @ItemID int ) WITH EXECUTE AS OWNER AS SELECT TT.[TransitionID], TT.[FromID], TT.[ToID], TT.[RangeID], TT.[IsRange], TT.[TranType], TT.[Config], TT.[DTS], TT.[UserID], TT.[LastChanged], (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=TT.[TransitionID]) [ZTransitionCount] from transitions tt join items ii on tt.FromID = ii.ContentID where TT.ToID = @ItemID AND TT.FromID not in(select ContentID from vefn_childItems(@ItemID)) RETURN GO /****** Object: UserDefinedFunction [dbo].[vefn_GetFormatValues] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* SELECT * from vefn_GetFormatValues('WidSAdjByLevel') SELECT * from vefn_GetFormatValues('MatchProcNumber') SELECT * from vefn_GetFormatValues('TofCPositionAdj') */ CREATE FUNCTION [vefn_GetFormatValues](@FieldName as varchar(255)) RETURNS @AllValues TABLE ( FormatID int, Name varchar(100), ParentNode XML, Node XML, FieldValue varchar(MAX) ) WITH EXECUTE AS OWNER AS BEGIN declare @NodeName as varchar(255) set @NodeName = (Select distinct v.value('local-name(..)', 'varchar(255)') MyName FROM Formats CROSS APPLY Data.nodes('(*//@*[local-name()=sql:variable("@FieldName")])') TempXML(v)) Insert into @AllValues Select FormatID, Name, v.query('..') ParentNode, v.query('.') Node, v.value('(./@*[local-name()=sql:variable("@FieldName")])[1]','varchar(255)') FieldValue FROM Formats CROSS APPLY Data.nodes('(//*[local-name()=sql:variable("@NodeName")])') TempXML(v) RETURN END GO /****** Object: StoredProcedure [dbo].[addFormat] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addFormat] ( @ParentID int, @Name nvarchar(20), @Description nvarchar(250)=null, @Data xml, @GenMac xml=null, @DTS datetime, @UserID nvarchar(100), @newFormatID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Formats] ( [ParentID], [Name], [Description], [Data], [GenMac], [DTS], [UserID] ) VALUES ( @ParentID, @Name, @Description, @Data, @GenMac, @DTS, @UserID ) SELECT @newFormatID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Formats] WHERE [FormatID]=@newFormatID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: UserDefinedFunction [dbo].[vefn_GetFormatFieldNoValue] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Select * from vefn_GetFormatFieldNoValue('Font') Select * from vefn_GetFormatFieldNoValue('PSADJBNGROW') Select * from vefn_GetFormatFieldNoValue('SectionTitle') Select * from vefn_GetFormatFieldNoValue('PrintNoTitle') Select * from vefn_GetFormatFieldNoValue('Off') */ CREATE FUNCTION [vefn_GetFormatFieldNoValue](@find varchar(255)) RETURNS @FormatFields TABLE ( FormatID int ,Name varchar(20) ,Description varchar(250) ,Path varchar(max) ) WITH EXECUTE AS OWNER AS BEGIN INSERT INTO @FormatFields Select FormatID, Name, Description, case when v9.exist('.') is null THEN '' ELSE v9.value('local-name(.)','varchar(max)') + '/' END + case when v8.exist('.') is null THEN '' ELSE v8.value('local-name(.)','varchar(max)') + '/' END + case when v7.exist('.') is null THEN '' ELSE v7.value('local-name(.)','varchar(max)') + '/' END + case when v6.exist('.') is null THEN '' ELSE v6.value('local-name(.)','varchar(max)') + '/' END + case when v5.exist('.') is null THEN '' ELSE v5.value('local-name(.)','varchar(max)') + '/' END + case when v4.exist('.') is null THEN '' ELSE v4.value('local-name(.)','varchar(max)') + '/' END + case when v3.exist('.') is null THEN '' ELSE v3.value('local-name(.)','varchar(max)') + '/' END + case when v2.exist('.') is null THEN '' ELSE v2.value('local-name(.)','varchar(max)') + '/' END + case when v1.exist('.') is null THEN '' ELSE v1.value('local-name(.)','varchar(max)') + '/' END + + '@' + v.value('local-name(.)','varchar(max)') Path FROM Formats CROSS APPLY Data.nodes('//*/@*') TempXML(v) OUTER APPLY v.nodes('..') TempXML1(v1) OUTER APPLY v1.nodes('..') TempXML2(v2) OUTER APPLY v2.nodes('..') TempXML3(v3) OUTER APPLY v3.nodes('..') TempXML4(v4) OUTER APPLY v4.nodes('..') TempXML5(v5) OUTER APPLY v5.nodes('..') TempXML6(v6) OUTER APPLY v6.nodes('..') TempXML7(v7) OUTER APPLY v7.nodes('..') TempXML8(v8) OUTER APPLY v8.nodes('..') TempXML9(v9) where v.value('local-name(.)', 'varchar(255)') like '%' + @find + '%' RETURN END GO /****** Object: UserDefinedFunction [dbo].[vefn_GetFormatFieldByStepType] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Select * from vefn_GetFormatFieldByStepType('Font') Select * from vefn_GetFormatFieldByStepType('PSADJBNGROW') Select * from vefn_GetFormatFieldByStepType('SectionTitle') Select * from vefn_GetFormatFieldByStepType('PrintNoTitle') Select * from vefn_GetFormatFieldByStepType('Off') where name ='AEP' */ CREATE FUNCTION [vefn_GetFormatFieldByStepType](@find varchar(255)) RETURNS @FormatFields TABLE ( FormatID int ,Name varchar(20) ,Description varchar(250) ,Path varchar(max) ,StepType varchar(255) ,Value varchar(255) ) WITH EXECUTE AS OWNER AS BEGIN INSERT INTO @FormatFields Select FormatID, Name, Description, case when v9.exist('.') is null THEN '' ELSE v9.value('local-name(.)','varchar(max)') + '/' END + case when v8.exist('.') is null THEN '' ELSE v8.value('local-name(.)','varchar(max)') + '/' END + case when v7.exist('.') is null THEN '' ELSE v7.value('local-name(.)','varchar(max)') + '/' END + case when v6.exist('.') is null THEN '' ELSE v6.value('local-name(.)','varchar(max)') + '/' END + case when v5.exist('.') is null THEN '' ELSE v5.value('local-name(.)','varchar(max)') + '/' END + case when v4.exist('.') is null THEN '' ELSE v4.value('local-name(.)','varchar(max)') + '/' END + case when v3.exist('.') is null THEN '' ELSE v3.value('local-name(.)','varchar(max)') + '/' END + case when v2.exist('.') is null THEN '' ELSE v2.value('local-name(.)','varchar(max)') + '/' END + case when v1.exist('.') is null THEN '' ELSE v1.value('local-name(.)','varchar(max)') + '/' END + .dbo.vefn_XmlPath(v1.query('.')) + + '@' + v.value('local-name(.)','varchar(max)') Path , coalesce(v.value('../@Type','varchar(255)'),v.value('../../@Type','varchar(255)'),v.value('../../../@Type','varchar(255)')) StepType , v.value('.', 'varchar(255)') Value FROM Formats CROSS APPLY Data.nodes('//*/@*') TempXML(v) OUTER APPLY v.nodes('..') TempXML1(v1) OUTER APPLY v1.nodes('..') TempXML2(v2) OUTER APPLY v2.nodes('..') TempXML3(v3) OUTER APPLY v3.nodes('..') TempXML4(v4) OUTER APPLY v4.nodes('..') TempXML5(v5) OUTER APPLY v5.nodes('..') TempXML6(v6) OUTER APPLY v6.nodes('..') TempXML7(v7) OUTER APPLY v7.nodes('..') TempXML8(v8) OUTER APPLY v8.nodes('..') TempXML9(v9) where v.value('local-name(.)', 'varchar(255)') like '%' + @find + '%' OR v.value('.', 'varchar(255)') like '%' + @find + '%' UNION ALL Select FormatID, Name, Description, case when v9.exist('.') is null THEN '' ELSE v9.value('local-name(.)','varchar(max)') + '/' END + case when v8.exist('.') is null THEN '' ELSE v8.value('local-name(.)','varchar(max)') + '/' END + case when v7.exist('.') is null THEN '' ELSE v7.value('local-name(.)','varchar(max)') + '/' END + case when v6.exist('.') is null THEN '' ELSE v6.value('local-name(.)','varchar(max)') + '/' END + case when v5.exist('.') is null THEN '' ELSE v5.value('local-name(.)','varchar(max)') + '/' END + case when v4.exist('.') is null THEN '' ELSE v4.value('local-name(.)','varchar(max)') + '/' END + case when v3.exist('.') is null THEN '' ELSE v3.value('local-name(.)','varchar(max)') + '/' END + case when v2.exist('.') is null THEN '' ELSE v2.value('local-name(.)','varchar(max)') + '/' END + case when v1.exist('.') is null THEN '' ELSE v1.value('local-name(.)','varchar(max)') + coalesce('[' + v1.value('@Index','varchar(255)')+']','') + '/' END + + v.value('local-name(.)','varchar(max)') Path , coalesce(v.value('../@Type','varchar(255)'),v.value('../../@Type','varchar(255)'),v.value('../../../@Type','varchar(255)')) StepType , '{node}' FROM Formats CROSS APPLY Data.nodes('//*') TempXML(v) OUTER APPLY v.nodes('..') TempXML1(v1) OUTER APPLY v1.nodes('..') TempXML2(v2) OUTER APPLY v2.nodes('..') TempXML3(v3) OUTER APPLY v3.nodes('..') TempXML4(v4) OUTER APPLY v4.nodes('..') TempXML5(v5) OUTER APPLY v5.nodes('..') TempXML6(v6) OUTER APPLY v6.nodes('..') TempXML7(v7) OUTER APPLY v7.nodes('..') TempXML8(v8) OUTER APPLY v8.nodes('..') TempXML9(v9) where v.value('local-name(.)', 'varchar(255)') like '%' + @find + '%' RETURN END GO /****** Object: UserDefinedFunction [dbo].[vefn_GetFormatFieldByStepType2] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Select * from vefn_GetFormatFieldByStepType2('Font') Select * from vefn_GetFormatFieldByStepType2('PSADJBNGROW') Select * from vefn_GetFormatFieldByStepType2('SectionTitle') Select * from vefn_GetFormatFieldByStepType2('PrintNoTitle') Select * from vefn_GetFormatFieldByStepType2('Off') */ CREATE FUNCTION [vefn_GetFormatFieldByStepType2](@find varchar(255)) RETURNS @FormatFields TABLE ( FormatID int ,Name varchar(20) ,Description varchar(250) ,Path varchar(max) ,StepType varchar(255) ,Indx varchar(255) ,Value varchar(255) ) WITH EXECUTE AS OWNER AS BEGIN INSERT INTO @FormatFields Select FormatID, Name, Description, .dbo.vefn_XmlPath(v9.query('.')) + .dbo.vefn_XmlPath(v8.query('.')) + .dbo.vefn_XmlPath(v7.query('.')) + .dbo.vefn_XmlPath(v6.query('.')) + .dbo.vefn_XmlPath(v5.query('.')) + .dbo.vefn_XmlPath(v4.query('.')) + .dbo.vefn_XmlPath(v3.query('.')) + .dbo.vefn_XmlPath(v2.query('.')) + .dbo.vefn_XmlPath(v1.query('.')) + + '@' + v.value('local-name(.)','varchar(max)') Path , coalesce(v.value('../@Type','varchar(255)'),v.value('../../@Type','varchar(255)'),v.value('../../../@Type','varchar(255)')) StepType , coalesce(v1.value('@Index','varchar(255)'),v2.value('@Index','varchar(255)'),v3.value('@Index','varchar(255)')) Indx , v.value('.', 'varchar(255)') Value FROM Formats CROSS APPLY Data.nodes('//*/@*') TempXML(v) OUTER APPLY v.nodes('..') TempXML1(v1) OUTER APPLY v1.nodes('..') TempXML2(v2) OUTER APPLY v2.nodes('..') TempXML3(v3) OUTER APPLY v3.nodes('..') TempXML4(v4) OUTER APPLY v4.nodes('..') TempXML5(v5) OUTER APPLY v5.nodes('..') TempXML6(v6) OUTER APPLY v6.nodes('..') TempXML7(v7) OUTER APPLY v7.nodes('..') TempXML8(v8) OUTER APPLY v8.nodes('..') TempXML9(v9) where v.value('local-name(.)', 'varchar(255)') like '%' + @find + '%' OR v.value('.', 'varchar(255)') like '%' + @find + '%' RETURN END GO /****** Object: UserDefinedFunction [dbo].[vefn_GetFormatField] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Select * from vefn_GetFormatField('Font') Select * from vefn_GetFormatField('PSADJBNGROW') Select * from vefn_GetFormatField('SectionTitle') Select * from vefn_GetFormatField('PrintNoTitle') */ CREATE FUNCTION [vefn_GetFormatField](@find varchar(255)) RETURNS @FormatFields TABLE ( FormatID int ,Name varchar(20) ,Description varchar(250) ,Path varchar(max) ,Value varchar(255) ) WITH EXECUTE AS OWNER AS BEGIN INSERT INTO @FormatFields Select FormatID, Name, Description, case when v9.exist('.') is null THEN '' ELSE v9.value('local-name(.)','varchar(max)') + '/' END + case when v8.exist('.') is null THEN '' ELSE v8.value('local-name(.)','varchar(max)') + '/' END + case when v7.exist('.') is null THEN '' ELSE v7.value('local-name(.)','varchar(max)') + '/' END + case when v6.exist('.') is null THEN '' ELSE v6.value('local-name(.)','varchar(max)') + '/' END + case when v5.exist('.') is null THEN '' ELSE v5.value('local-name(.)','varchar(max)') + '/' END + case when v4.exist('.') is null THEN '' ELSE v4.value('local-name(.)','varchar(max)') + '/' END + case when v3.exist('.') is null THEN '' ELSE v3.value('local-name(.)','varchar(max)') + '/' END + case when v2.exist('.') is null THEN '' ELSE v2.value('local-name(.)','varchar(max)') + '/' END + case when v1.exist('.') is null THEN '' ELSE v1.value('local-name(.)','varchar(max)') + '/' END + + '@' + v.value('local-name(.)','varchar(max)') Path , v.value('.', 'varchar(255)') Value FROM Formats CROSS APPLY Data.nodes('//*/@*') TempXML(v) OUTER APPLY v.nodes('..') TempXML1(v1) OUTER APPLY v1.nodes('..') TempXML2(v2) OUTER APPLY v2.nodes('..') TempXML3(v3) OUTER APPLY v3.nodes('..') TempXML4(v4) OUTER APPLY v4.nodes('..') TempXML5(v5) OUTER APPLY v5.nodes('..') TempXML6(v6) OUTER APPLY v6.nodes('..') TempXML7(v7) OUTER APPLY v7.nodes('..') TempXML8(v8) OUTER APPLY v8.nodes('..') TempXML9(v9) where v.value('local-name(.)', 'varchar(255)') like '%' + @find + '%' OR v.value('.', 'varchar(255)') like '%' + @find + '%' UNION Select FormatID, Name, Description, case when v9.exist('.') is null THEN '' ELSE v9.value('local-name(.)','varchar(max)') + '/' END + case when v8.exist('.') is null THEN '' ELSE v8.value('local-name(.)','varchar(max)') + '/' END + case when v7.exist('.') is null THEN '' ELSE v7.value('local-name(.)','varchar(max)') + '/' END + case when v6.exist('.') is null THEN '' ELSE v6.value('local-name(.)','varchar(max)') + '/' END + case when v5.exist('.') is null THEN '' ELSE v5.value('local-name(.)','varchar(max)') + '/' END + case when v4.exist('.') is null THEN '' ELSE v4.value('local-name(.)','varchar(max)') + '/' END + case when v3.exist('.') is null THEN '' ELSE v3.value('local-name(.)','varchar(max)') + '/' END + case when v2.exist('.') is null THEN '' ELSE v2.value('local-name(.)','varchar(max)') + '/' END + case when v1.exist('.') is null THEN '' ELSE v1.value('local-name(.)','varchar(max)') + '/' END + + v.value('local-name(.)','varchar(max)') Path , '{node}' FROM Formats CROSS APPLY Data.nodes('//*') TempXML(v) OUTER APPLY v.nodes('..') TempXML1(v1) OUTER APPLY v1.nodes('..') TempXML2(v2) OUTER APPLY v2.nodes('..') TempXML3(v3) OUTER APPLY v3.nodes('..') TempXML4(v4) OUTER APPLY v4.nodes('..') TempXML5(v5) OUTER APPLY v5.nodes('..') TempXML6(v6) OUTER APPLY v6.nodes('..') TempXML7(v7) OUTER APPLY v7.nodes('..') TempXML8(v8) OUTER APPLY v8.nodes('..') TempXML9(v9) where v.value('local-name(.)', 'varchar(255)') like '%' + @find + '%' RETURN END GO /****** Object: StoredProcedure [dbo].[updateFormat] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateFormat] ( @FormatID int, @ParentID int, @Name nvarchar(20), @Description nvarchar(250)=null, @Data xml, @GenMac xml=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Formats] SET [ParentID]=@ParentID, [Name]=@Name, [Description]=@Description, [Data]=@Data, [GenMac]=@GenMac, [DTS]=@DTS, [UserID]=@UserID WHERE [FormatID]=@FormatID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Formats] WHERE [FormatID]=@FormatID) RAISERROR('Format record has been deleted by another user', 16, 1) ELSE RAISERROR('Format has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Formats] WHERE [FormatID]=@FormatID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[existsFormat] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsFormat] ( @FormatID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Formats] WHERE [FormatID]=@FormatID RETURN GO /****** Object: StoredProcedure [dbo].[vesp_GetFormatFieldsAll] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* vesp_GetFormatFieldsAll 'PrintNoTitle' vesp_GetFormatFieldsAll 'Sep' vesp_GetFormatFieldsAll 'TabFormat' vesp_GetFormatFieldsAll 'ShowSectionTitles' vesp_GetFormatFieldsAll 'Caution' vesp_GetFormatFieldsAll 'Ident' */ CREATE PROCEDURE [vesp_GetFormatFieldsAll] ( @find varchar(255) ) WITH EXECUTE AS OWNER AS BEGIN declare @pivotlist varchar(max) select @pivotlist = stuff((select distinct ',[' + [Name] + ']' from Formats order by ',[' + [Name] + ']' for xml path('')),1,1,'') DECLARE @query VARCHAR(max) SET @query = 'SELECT * FROM (Select Name,Path,Value From vefn_GetFormatField(''' + @find + ''')) T1 PIVOT ( Count(Name) FOR [Name] IN (' + @pivotlist + ') ) AS Pivot1 ORDER BY PATH,VALUE' print @Query EXECUTE(@query) END GO /****** Object: UserDefinedFunction [dbo].[vefn_GetGenMacMacros] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Select * from vefn_GetGenMacMacros() */ CREATE FUNCTION [vefn_GetGenMacMacros]() RETURNS @GenMacMacros TABLE ( FormatID int ,Name varchar(20) ,Description varchar(250) ,MacroName varchar(255) ) WITH EXECUTE AS OWNER AS BEGIN INSERT INTO @GenMacMacros Select FormatID, Name, Description,v.value('@id','varchar(20)') MacroName FROM Formats CROSS APPLY GenMac.nodes('//g') TempXML(v) RETURN END GO /****** Object: UserDefinedFunction [dbo].[vefn_GetNullFormatValues] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* SELECT * from vefn_GetNullFormatValues('WidSAdjByLevel') SELECT * from vefn_GetNullFormatValues('MatchProcNumber') SELECT * from vefn_GetNullFormatValues('TofCPositionAdj') */ CREATE FUNCTION [vefn_GetNullFormatValues](@FieldName as varchar(255)) RETURNS @NullValues TABLE ( FormatID int, Name varchar(100), ParentNode XML, Node XML ) WITH EXECUTE AS OWNER AS BEGIN declare @NodeName as varchar(255) set @NodeName = (Select distinct v.value('local-name(..)', 'varchar(255)') MyName FROM Formats CROSS APPLY Data.nodes('(*//@*[local-name()=sql:variable("@FieldName")])') TempXML(v)) Insert into @NullValues Select FormatID, Name, ParentNode, Node FROM ( Select FormatID, Name, v.query('..') ParentNode, v.query('.') Node, v.value('(./@*[local-name()=sql:variable("@FieldName")])[1]','varchar(255)') FieldValue FROM Formats CROSS APPLY Data.nodes('(//*[local-name()=sql:variable("@NodeName")])') TempXML(v) ) t1 WHERE FieldValue is null RETURN END GO /****** Object: UserDefinedFunction [dbo].[vefn_GetTransFormat] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Samples select .dbo.vefn_GetTransFormat(1,6) select .dbo.vefn_GetTransFormat(1,1) select .dbo.vefn_GetTransFormat(1,2) select .dbo.vefn_GetTransFormat(1,3) */ CREATE FUNCTION [vefn_GetTransFormat] (@FormatID int, @TranType int) RETURNS varchar(max) WITH EXECUTE AS OWNER AS BEGIN -- Walk up the Formats (inheritance) looking for the TransFormat Declare @TransFormat as varchar(MAX) BEGIN with Formatz([MyOrder],[FormatID],[ParentID],[Data]) as ( Select 0,FormatID, ParentID, Data From Formats where FormatID=@FormatID Union All Select [MyOrder]+1,FF.FormatID, FF.ParentID, FF.Data From Formats FF Join Formatz ZZ on ZZ.ParentID=FF.FormatID Where ZZ.FormatID <> ZZ.ParentID) Select Top 1 @TransFormat=v.value('./@TransFormat', 'varchar(MAX)') FROM Formatz CROSS APPLY Data.nodes('//TransTypes') TempXML(v) where v.value('./@TransType', 'int')=@TranType order by [MyOrder] END return @TransFormat END GO /****** Object: UserDefinedFunction [dbo].[vefn_SectionFormats] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO --select FormatID --,10000 + v.value('../@Index', 'int') [SectionType] --,[Name] --,v.value('../@Name', 'varchar(255)') [SectionFormatName] --,v.value('@TopRow', 'int') TopRow --,v.value('@PageLength', 'int') PageLength --,v.value('@FooterLength', 'int') FooterLength --,v.value('@LeftMargin', 'int') LeftMargin --,v.value('@PageWidth', 'int') PageWidth --from Formats --CROSS APPLY Data.nodes('//DocStyle/Layout') TempXML(v) /* select * from vefn_SectionFormats() where Name = 'OHLP' */ CREATE FUNCTION [vefn_SectionFormats]() RETURNS @SectionFormats TABLE ( [FormatID] int ,[SectionType] int ,[Name] nvarchar(20) ,[SectionFormatName] nvarchar(max) ,[TopRow] int ,[PageLength] int ,[FooterLength] int ,[LeftMargin] int ,[PageWidth] int ) WITH EXECUTE AS OWNER AS BEGIN Insert into @SectionFormats select FormatID ,10000 + v.value('../@Index', 'int') [SectionType] ,[Name] ,v.value('../@Name', 'varchar(255)') [SectionFormatName] ,v.value('@TopRow', 'int') TopRow ,v.value('@PageLength', 'int') PageLength ,v.value('@FooterLength', 'int') FooterLength ,v.value('@LeftMargin', 'int') LeftMargin ,v.value('@PageWidth', 'int') PageWidth from Formats CROSS APPLY Data.nodes('//DocStyle/Layout') TempXML(v) RETURN END GO /****** Object: StoredProcedure [dbo].[getPartsByItemID] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getPartsByItemID] ( @ItemID int ) WITH EXECUTE AS OWNER AS SELECT [Parts].[ContentID], [Parts].[FromType], [Parts].[ItemID], [Parts].[DTS], [Parts].[UserID], [Parts].[LastChanged], [Contents].[Number] [Content_Number], [Contents].[Text] [Content_Text], [Contents].[Type] [Content_Type], [Contents].[FormatID] [Content_FormatID], [Contents].[Config] [Content_Config], [Contents].[DTS] [Content_DTS], [Contents].[UserID] [Content_UserID] FROM [Parts] JOIN [Contents] ON [Contents].[ContentID]=[Parts].[ContentID] WHERE [Parts].[ItemID]=@ItemID RETURN GO /****** Object: StoredProcedure [dbo].[getPart] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getPart] ( @ContentID int, @FromType int ) WITH EXECUTE AS OWNER AS SELECT [ContentID], [FromType], [ItemID], [DTS], [UserID], [LastChanged] FROM [Parts] WHERE [ContentID]=@ContentID AND [FromType]=@FromType RETURN GO /****** Object: StoredProcedure [dbo].[getParts] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getParts] WITH EXECUTE AS OWNER AS SELECT [ContentID], [FromType], [ItemID], [DTS], [UserID], [LastChanged] FROM [Parts] RETURN GO /****** Object: StoredProcedure [dbo].[deletePart] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deletePart] ( @ContentID int, @FromType int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Parts] WHERE [ContentID] = @ContentID AND [FromType] = @FromType IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[existsPart] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsPart] ( @ContentID int, @FromType int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Parts] WHERE [ContentID]=@ContentID AND [FromType]=@FromType RETURN GO /****** Object: StoredProcedure [dbo].[updatePart] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updatePart] ( @ContentID int, @FromType int, @ItemID int, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Parts] SET [ItemID]=@ItemID, [DTS]=@DTS, [UserID]=@UserID WHERE [ContentID]=@ContentID AND [FromType]=@FromType AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Parts] WHERE [ContentID]=@ContentID AND [FromType]=@FromType) RAISERROR('Part record has been deleted by another user', 16, 1) ELSE RAISERROR('Part has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Parts] WHERE [ContentID]=@ContentID AND [FromType]=@FromType IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: View [dbo].[vDuplicates2] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO create view [vDuplicates2] as SELECT Min(ContentID) MinID,Max(ContentID) MaxID,[Number],[Text],[Type],[FormatID],[Config],count(*) HowMany FROM [Contents] where contentid in (select contentid from parts) group by [Number],[Text],[Type],[FormatID],[Config] having count(*) > 1 and type >= 20000 GO /****** Object: StoredProcedure [dbo].[addPart] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addPart] ( @ContentID int, @FromType int, @ItemID int, @DTS datetime, @UserID nvarchar(100), @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Parts] ( [ContentID], [FromType], [ItemID], [DTS], [UserID] ) VALUES ( @ContentID, @FromType, @ItemID, @DTS, @UserID ) SELECT @newLastChanged=[LastChanged] FROM [Parts] WHERE [ContentID]=@ContentID AND [FromType]=@FromType IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: View [dbo].[vDuplicates1] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE view [vDuplicates1] as SELECT Min(ContentID) MinID,Max(ContentID) MaxID,[Number],[Text],[Type],[FormatID],[Config],count(*) HowMany FROM [Contents] where contentid not in (select contentid from parts) group by [Number],[Text],[Type],[FormatID],[Config] having count(*) > 1 and type >= 20000 GO /****** Object: StoredProcedure [dbo].[deleteDetail] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteDetail] ( @DetailID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Details] WHERE [DetailID] = @DetailID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[addDetail] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addDetail] ( @ContentID int, @ItemType int, @Text nvarchar(MAX), @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @newDetailID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Details] ( [ContentID], [ItemType], [Text], [Config], [DTS], [UserID] ) VALUES ( @ContentID, @ItemType, @Text, @Config, @DTS, @UserID ) SELECT @newDetailID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Details] WHERE [DetailID]=@newDetailID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getDetailsByContentID] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getDetailsByContentID] ( @ContentID int ) WITH EXECUTE AS OWNER AS SELECT [Details].[DetailID], [Details].[ContentID], [Details].[ItemType], [Details].[Text], [Details].[Config], [Details].[DTS], [Details].[UserID], [Details].[LastChanged] FROM [Details] WHERE [Details].[ContentID]=@ContentID RETURN GO /****** Object: StoredProcedure [dbo].[getDetail] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getDetail] ( @DetailID int ) WITH EXECUTE AS OWNER AS SELECT [DetailID], [ContentID], [ItemType], [Text], [Config], [DTS], [UserID], [LastChanged] FROM [Details] WHERE [DetailID]=@DetailID RETURN GO /****** Object: StoredProcedure [dbo].[getDetails] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getDetails] WITH EXECUTE AS OWNER AS SELECT [DetailID], [ContentID], [ItemType], [Text], [Config], [DTS], [UserID], [LastChanged] FROM [Details] RETURN GO /****** Object: StoredProcedure [dbo].[updateDetail] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateDetail] ( @DetailID int, @ContentID int, @ItemType int, @Text nvarchar(MAX), @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Details] SET [ContentID]=@ContentID, [ItemType]=@ItemType, [Text]=@Text, [Config]=@Config, [DTS]=@DTS, [UserID]=@UserID WHERE [DetailID]=@DetailID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Details] WHERE [DetailID]=@DetailID) RAISERROR('Detail record has been deleted by another user', 16, 1) ELSE RAISERROR('Detail has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Details] WHERE [DetailID]=@DetailID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[existsDetail] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsDetail] ( @DetailID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Details] WHERE [DetailID]=@DetailID RETURN GO /****** Object: StoredProcedure [dbo].[existsContent] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsContent] ( @ContentID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Contents] WHERE [ContentID]=@ContentID RETURN GO /****** Object: StoredProcedure [dbo].[getTransitionsByRangeID] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getTransitionsByRangeID] ( @RangeID int ) WITH EXECUTE AS OWNER AS SELECT [Transitions].[TransitionID], [Transitions].[FromID], [Transitions].[ToID], [Transitions].[RangeID], [Transitions].[IsRange], [Transitions].[TranType], [Transitions].[Config], [Transitions].[DTS], [Transitions].[UserID], [Transitions].[LastChanged], [Contents].[Number] [Content_Number], [Contents].[Text] [Content_Text], [Contents].[Type] [Content_Type], [Contents].[FormatID] [Content_FormatID], [Contents].[Config] [Content_Config], [Contents].[DTS] [Content_DTS], [Contents].[UserID] [Content_UserID], (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=[Transitions].[TransitionID]) [ZTransitionCount] FROM [Transitions] JOIN [Contents] ON [Contents].[ContentID]=[Transitions].[FromID] WHERE [Transitions].[RangeID]=@RangeID RETURN GO /****** Object: StoredProcedure [dbo].[getTransitionsByToID] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getTransitionsByToID] ( @ToID int ) WITH EXECUTE AS OWNER AS SELECT [Transitions].[TransitionID], [Transitions].[FromID], [Transitions].[ToID], [Transitions].[RangeID], [Transitions].[IsRange], [Transitions].[TranType], [Transitions].[Config], [Transitions].[DTS], [Transitions].[UserID], [Transitions].[LastChanged], [Contents].[Number] [Content_Number], [Contents].[Text] [Content_Text], [Contents].[Type] [Content_Type], [Contents].[FormatID] [Content_FormatID], [Contents].[Config] [Content_Config], [Contents].[DTS] [Content_DTS], [Contents].[UserID] [Content_UserID], (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=[Transitions].[TransitionID]) [ZTransitionCount] FROM [Transitions] JOIN [Contents] ON [Contents].[ContentID]=[Transitions].[FromID] WHERE [Transitions].[ToID]=@ToID RETURN GO /****** Object: StoredProcedure [dbo].[updateContent] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateContent] ( @ContentID int, @Number nvarchar(256)=null, @Text nvarchar(MAX)=null, @Type int=null, @FormatID int=null, @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Contents] SET [Number]=@Number, [Text]=@Text, [Type]=@Type, [FormatID]=@FormatID, [Config]=@Config, [DTS]=@DTS, [UserID]=@UserID WHERE [ContentID]=@ContentID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Contents] WHERE [ContentID]=@ContentID) RAISERROR('Content record has been deleted by another user', 16, 1) ELSE RAISERROR('Content has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Contents] WHERE [ContentID]=@ContentID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[addContent] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addContent] ( @Number nvarchar(256)=null, @Text nvarchar(MAX)=null, @Type int=null, @FormatID int=null, @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @newContentID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Contents] ( [Number], [Text], [Type], [FormatID], [Config], [DTS], [UserID] ) VALUES ( @Number, @Text, @Type, @FormatID, @Config, @DTS, @UserID ) SELECT @newContentID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Contents] WHERE [ContentID]=@newContentID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[deleteAnnotation] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteAnnotation] ( @AnnotationID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Annotations] WHERE [AnnotationID] = @AnnotationID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[deleteAnnotationType] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteAnnotationType] ( @TypeID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Annotations] WHERE [TypeID]=@TypeID DELETE [AnnotationTypes] WHERE [TypeID] = @TypeID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[addAnnotation] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addAnnotation] ( @ItemID int, @TypeID int, @RtfText nvarchar(MAX)=null, @SearchText nvarchar(MAX)=null, @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @newAnnotationID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Annotations] ( [ItemID], [TypeID], [RtfText], [SearchText], [Config], [DTS], [UserID] ) VALUES ( @ItemID, @TypeID, @RtfText, @SearchText, @Config, @DTS, @UserID ) SELECT @newAnnotationID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Annotations] WHERE [AnnotationID]=@newAnnotationID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getAnnotationsByItemID] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getAnnotationsByItemID] ( @ItemID int ) WITH EXECUTE AS OWNER AS SELECT [Annotations].[AnnotationID], [Annotations].[ItemID], [Annotations].[TypeID], [Annotations].[RtfText], [Annotations].[SearchText], [Annotations].[Config], [Annotations].[DTS], [Annotations].[UserID], [Annotations].[LastChanged], [AnnotationTypes].[Name] [AnnotationType_Name], [AnnotationTypes].[Config] [AnnotationType_Config], [AnnotationTypes].[DTS] [AnnotationType_DTS], [AnnotationTypes].[UserID] [AnnotationType_UserID] FROM [Annotations] JOIN [AnnotationTypes] ON [AnnotationTypes].[TypeID]=[Annotations].[TypeID] WHERE [Annotations].[ItemID]=@ItemID RETURN GO /****** Object: StoredProcedure [dbo].[getAnnotation] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getAnnotation] ( @AnnotationID int ) WITH EXECUTE AS OWNER AS SELECT [AnnotationID], [ItemID], [TypeID], [RtfText], [SearchText], [Config], [DTS], [UserID], [LastChanged] FROM [Annotations] WHERE [AnnotationID]=@AnnotationID RETURN GO /****** Object: StoredProcedure [dbo].[updateAnnotation] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateAnnotation] ( @AnnotationID int, @ItemID int, @TypeID int, @RtfText nvarchar(MAX)=null, @SearchText nvarchar(MAX)=null, @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Annotations] SET [ItemID]=@ItemID, [TypeID]=@TypeID, [RtfText]=@RtfText, [SearchText]=@SearchText, [Config]=@Config, [DTS]=@DTS, [UserID]=@UserID WHERE [AnnotationID]=@AnnotationID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Annotations] WHERE [AnnotationID]=@AnnotationID) RAISERROR('Annotation record has been deleted by another user', 16, 1) ELSE RAISERROR('Annotation has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Annotations] WHERE [AnnotationID]=@AnnotationID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getAnnotationTypes] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getAnnotationTypes] WITH EXECUTE AS OWNER AS SELECT [TypeID], [Name], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[TypeID]=[AnnotationTypes].[TypeID]) [AnnotationCount] FROM [AnnotationTypes] RETURN GO /****** Object: StoredProcedure [dbo].[getAnnotations] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getAnnotations] WITH EXECUTE AS OWNER AS SELECT [AnnotationID], [ItemID], [TypeID], [RtfText], [SearchText], [Config], [DTS], [UserID], [LastChanged] FROM [Annotations] RETURN GO /****** Object: StoredProcedure [dbo].[getAnnotationTypeByName] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getAnnotationTypeByName] ( @Name nvarchar(100) ) WITH EXECUTE AS OWNER AS SELECT [TypeID], [Name], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[TypeID]=[AnnotationTypes].[TypeID]) [AnnotationCount] FROM [AnnotationTypes] WHERE [Name]=@Name RETURN GO /****** Object: StoredProcedure [dbo].[existsAnnotation] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsAnnotation] ( @AnnotationID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Annotations] WHERE [AnnotationID]=@AnnotationID RETURN GO /****** Object: StoredProcedure [dbo].[addAnnotationType] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addAnnotationType] ( @Name nvarchar(100), @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @newTypeID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [AnnotationTypes] ( [Name], [Config], [DTS], [UserID] ) VALUES ( @Name, @Config, @DTS, @UserID ) SELECT @newTypeID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [AnnotationTypes] WHERE [TypeID]=@newTypeID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[updateAnnotationType] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateAnnotationType] ( @TypeID int, @Name nvarchar(100), @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [AnnotationTypes] SET [Name]=@Name, [Config]=@Config, [DTS]=@DTS, [UserID]=@UserID WHERE [TypeID]=@TypeID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [AnnotationTypes] WHERE [TypeID]=@TypeID) RAISERROR('AnnotationType record has been deleted by another user', 16, 1) ELSE RAISERROR('AnnotationType has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [AnnotationTypes] WHERE [TypeID]=@TypeID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[existsAnnotationType] Script Date: 01/06/2012 15:02:55 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsAnnotationType] ( @TypeID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [AnnotationTypes] WHERE [TypeID]=@TypeID RETURN GO /****** Object: UserDefinedFunction [dbo].[vefn_AnnotationTypeSplit] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select * from vefn_AnnotationTypeSplit('1,4') select * from vefn_AnnotationTypeSplit(null) select * from vefn_AnnotationTypeSplit('') */ CREATE FUNCTION [vefn_AnnotationTypeSplit](@AnnotationTypeList varchar(MAX)) RETURNS @IDs TABLE ( TypeID int PRIMARY KEY, Name varchar(100) ) WITH EXECUTE AS OWNER AS BEGIN IF(isnull(@AnnotationTypeList,'') = '') Insert into @IDs Select TypeID, Name from AnnotationTypes else Insert into @IDs Select TypeID,NAME from AnnotationTypes where TypeID in(select ID from vefn_SplitInt(@AnnotationTypeList,',')) RETURN END GO /****** Object: StoredProcedure [dbo].[addTransition] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addTransition] ( @FromID int, @ToID int, @RangeID int, @IsRange int, @TranType int, @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @newTransitionID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Transitions] ( [FromID], [ToID], [RangeID], [IsRange], [TranType], [Config], [DTS], [UserID] ) VALUES ( @FromID, @ToID, @RangeID, @IsRange, @TranType, @Config, @DTS, @UserID ) SELECT @newTransitionID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Transitions] WHERE [TransitionID]=@newTransitionID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getExternalTransitionsToChildren] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* exec getExternalTransitionsToChildren 9392 */ CREATE PROCEDURE [getExternalTransitionsToChildren] ( @ItemID int ) WITH EXECUTE AS OWNER AS SELECT TT.[TransitionID], TT.[FromID], TT.[ToID], TT.[RangeID], TT.[IsRange], TT.[TranType], TT.[Config], TT.[DTS], TT.[UserID], TT.[LastChanged], (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=TT.[TransitionID]) [ZTransitionCount] FROM vefn_childItems(@ItemID) II JOIN Transitions TT on TT.ToID = II.ItemID AND TT.ToID <> @ItemID where TT.FromID not in(select ContentID from vefn_childItems(@ItemID)) RETURN GO /****** Object: StoredProcedure [dbo].[deleteTransition] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteTransition] ( @TransitionID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [ZTransitions] WHERE [TransitionID]=@TransitionID DELETE [Transitions] WHERE [TransitionID] = @TransitionID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getPastedAffectedTransitions] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getPastedAffectedTransitions] ( @ItemID int ) WITH EXECUTE AS OWNER AS SELECT TT.[TransitionID], [FromID], [ToID], [RangeID], [IsRange], [TranType], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=TT.[TransitionID]) [ZTransitionCount] FROM [Transitions] TT join vefn_ChildItems(@ItemID) CC on CC.ContentID = TT.FromID RETURN GO /****** Object: StoredProcedure [dbo].[getTransitions] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getTransitions] WITH EXECUTE AS OWNER AS SELECT [TransitionID], [FromID], [ToID], [RangeID], [IsRange], [TranType], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=[Transitions].[TransitionID]) [ZTransitionCount] FROM [Transitions] RETURN GO /****** Object: StoredProcedure [dbo].[getTransition] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getTransition] ( @TransitionID int ) WITH EXECUTE AS OWNER AS SELECT [TransitionID], [FromID], [ToID], [RangeID], [IsRange], [TranType], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=[Transitions].[TransitionID]) [ZTransitionCount] FROM [Transitions] WHERE [TransitionID]=@TransitionID SELECT [ZTransitions].[TransitionID], [ZTransitions].[oldto], [ZTransitions].[LastChanged] FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=@TransitionID RETURN GO /****** Object: StoredProcedure [dbo].[existsTransition] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsTransition] ( @TransitionID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Transitions] WHERE [TransitionID]=@TransitionID RETURN GO /****** Object: StoredProcedure [dbo].[getAffectedTransitions] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* exec getAffectedTransitions 2102 */ CREATE PROCEDURE [getAffectedTransitions] ( @ItemID int ) WITH EXECUTE AS OWNER AS SELECT TT.[TransitionID], [FromID], [ToID], [RangeID], [IsRange], [TranType], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=TT.[TransitionID]) [ZTransitionCount] FROM [Transitions] TT join vefn_FindAffectedTransitions(@ItemID) TTZ on TTZ.TransitionID = TT.TransitionID RETURN GO /****** Object: StoredProcedure [dbo].[updateTransition] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateTransition] ( @TransitionID int, @FromID int, @ToID int, @RangeID int, @IsRange int, @TranType int, @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Transitions] SET [FromID]=@FromID, [ToID]=@ToID, [RangeID]=@RangeID, [IsRange]=@IsRange, [TranType]=@TranType, [Config]=@Config, [DTS]=@DTS, [UserID]=@UserID WHERE [TransitionID]=@TransitionID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Transitions] WHERE [TransitionID]=@TransitionID) RAISERROR('Transition record has been deleted by another user', 16, 1) ELSE RAISERROR('Transition has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Transitions] WHERE [TransitionID]=@TransitionID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[updateFolder] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateFolder] ( @FolderID int, @ParentID int, @DBID int, @Name nvarchar(100), @Title nvarchar(510)=null, @ShortName nvarchar(20), @FormatID int=null, @ManualOrder float=null, @Config nvarchar(MAX)=null, @DTS datetime, @UsrID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Folders] SET [ParentID]=@ParentID, [DBID]=@DBID, [Name]=@Name, [Title]=@Title, [ShortName]=@ShortName, [FormatID]=@FormatID, [ManualOrder]=@ManualOrder, [Config]=@Config, [DTS]=@DTS, [UsrID]=@UsrID WHERE [FolderID]=@FolderID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Folders] WHERE [FolderID]=@FolderID) RAISERROR('Folder record has been deleted by another user', 16, 1) ELSE RAISERROR('Folder has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Folders] WHERE [FolderID]=@FolderID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[addFolder] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addFolder] ( @ParentID int, @DBID int, @Name nvarchar(100), @Title nvarchar(510)=null, @ShortName nvarchar(20), @FormatID int=null, @ManualOrder float=null, @Config nvarchar(MAX)=null, @DTS datetime, @UsrID nvarchar(100), @newFolderID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Folders] ( [ParentID], [DBID], [Name], [Title], [ShortName], [FormatID], [ManualOrder], [Config], [DTS], [UsrID] ) VALUES ( @ParentID, @DBID, @Name, @Title, @ShortName, @FormatID, @ManualOrder, @Config, @DTS, @UsrID ) SELECT @newFolderID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Folders] WHERE [FolderID]=@newFolderID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: Trigger [trigAddFolder] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ============================================= -- Author: -- Create date: -- Description: -- ============================================= CREATE TRIGGER [trigAddFolder] ON [Folders] AFTER INSERT AS BEGIN SET NOCOUNT ON; --select max(fld.ManualOrder) from folders fld join inserted ins on fld.ParentID = Ins.ParentID --Select ROW_NUMBER() OVER(Partition by [ParentID] Order BY FolderID) + (select max(ManualOrder) from folders where ParentID = Inserted.ParentID) as RowNumber,* from Inserted Update Fld set Fld.ManualOrder = Ins.RowNumber From Folders Fld join (Select ROW_NUMBER() OVER(Partition by [ParentID] Order BY FolderID) + (select isnull(max(ManualOrder),0) from folders where ParentID = Inserted.ParentID) as RowNumber,* from Inserted) Ins on Ins.FolderID = Fld.FolderID Print 'Trigger Fired' END GO /****** Object: StoredProcedure [dbo].[getAssignmentsByGID] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getAssignmentsByGID] ( @GID int ) WITH EXECUTE AS OWNER AS SELECT [Assignments].[AID], [Assignments].[GID], [Assignments].[RID], [Assignments].[FolderID], [Assignments].[StartDate], [Assignments].[EndDate], [Assignments].[DTS], [Assignments].[UsrID], [Assignments].[LastChanged], [Folders].[ParentID] [Folder_ParentID], [Folders].[DBID] [Folder_DBID], [Folders].[Name] [Folder_Name], [Folders].[Title] [Folder_Title], [Folders].[ShortName] [Folder_ShortName], [Folders].[FormatID] [Folder_FormatID], [Folders].[ManualOrder] [Folder_ManualOrder], [Folders].[Config] [Folder_Config], [Folders].[DTS] [Folder_DTS], [Folders].[UsrID] [Folder_UsrID], [Roles].[Name] [Role_Name], [Roles].[Title] [Role_Title], [Roles].[DTS] [Role_DTS], [Roles].[UsrID] [Role_UsrID] FROM [Assignments] JOIN [Folders] ON [Folders].[FolderID]=[Assignments].[FolderID] JOIN [Roles] ON [Roles].[RID]=[Assignments].[RID] WHERE [Assignments].[GID]=@GID RETURN GO /****** Object: StoredProcedure [dbo].[vesp_ResetFolderManualOrder] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [vesp_ResetFolderManualOrder] WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION update fld set Fld.ManualOrder =Fld.MyRow from (Select ROW_NUMBER() OVER(Partition by ParentID Order BY FolderID) MyRow,* from folders ) fld IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ResetFolderManualOrder Succeeded' ELSE PRINT 'Procedure Creation: vesp_ResetFolderManualOrder Error on Creation' GO /****** Object: StoredProcedure [dbo].[existsFolder] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsFolder] ( @FolderID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Folders] WHERE [FolderID]=@FolderID RETURN GO /****** Object: StoredProcedure [dbo].[deleteAssignment] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteAssignment] ( @AID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Assignments] WHERE [AID] = @AID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[existsAssignment] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsAssignment] ( @AID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Assignments] WHERE [AID]=@AID RETURN GO /****** Object: StoredProcedure [dbo].[getAssignments] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getAssignments] WITH EXECUTE AS OWNER AS SELECT [AID], [GID], [RID], [FolderID], [StartDate], [EndDate], [DTS], [UsrID], [LastChanged] FROM [Assignments] RETURN GO /****** Object: StoredProcedure [dbo].[getAssignment] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getAssignment] ( @AID int ) WITH EXECUTE AS OWNER AS SELECT [AID], [GID], [RID], [FolderID], [StartDate], [EndDate], [DTS], [UsrID], [LastChanged] FROM [Assignments] WHERE [AID]=@AID RETURN GO /****** Object: StoredProcedure [dbo].[updateAssignment] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateAssignment] ( @AID int, @GID int, @RID int, @FolderID int, @StartDate datetime, @EndDate datetime=null, @DTS datetime, @UsrID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Assignments] SET [GID]=@GID, [RID]=@RID, [FolderID]=@FolderID, [StartDate]=@StartDate, [EndDate]=@EndDate, [DTS]=@DTS, [UsrID]=@UsrID WHERE [AID]=@AID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Assignments] WHERE [AID]=@AID) RAISERROR('Assignment record has been deleted by another user', 16, 1) ELSE RAISERROR('Assignment has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Assignments] WHERE [AID]=@AID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[addAssignment] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addAssignment] ( @GID int, @RID int, @FolderID int, @StartDate datetime, @EndDate datetime=null, @DTS datetime, @UsrID nvarchar(100), @newAID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Assignments] ( [GID], [RID], [FolderID], [StartDate], [EndDate], [DTS], [UsrID] ) VALUES ( @GID, @RID, @FolderID, @StartDate, @EndDate, @DTS, @UsrID ) SELECT @newAID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Assignments] WHERE [AID]=@newAID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[updateGrid] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateGrid] ( @ContentID int, @Data xml, @Config xml=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Grids] SET [Data]=@Data, [Config]=@Config, [DTS]=@DTS, [UserID]=@UserID WHERE [ContentID]=@ContentID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Grids] WHERE [ContentID]=@ContentID) RAISERROR('Grid record has been deleted by another user', 16, 1) ELSE RAISERROR('Grid has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Grids] WHERE [ContentID]=@ContentID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[existsGrid] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsGrid] ( @ContentID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Grids] WHERE [ContentID]=@ContentID RETURN GO /****** Object: StoredProcedure [dbo].[deleteGrid] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteGrid] ( @ContentID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Grids] WHERE [ContentID] = @ContentID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[addGrid] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addGrid] ( @ContentID int, @Data xml, @Config xml=null, @DTS datetime, @UserID nvarchar(100), @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Grids] ( [ContentID], [Data], [Config], [DTS], [UserID] ) VALUES ( @ContentID, @Data, @Config, @DTS, @UserID ) SELECT @newLastChanged=[LastChanged] FROM [Grids] WHERE [ContentID]=@ContentID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getGridsByContentID] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getGridsByContentID] ( @ContentID int ) WITH EXECUTE AS OWNER AS SELECT [Grids].[ContentID], [Grids].[Data], [Grids].[Config], [Grids].[DTS], [Grids].[UserID], [Grids].[LastChanged] FROM [Grids] WHERE [Grids].[ContentID]=@ContentID RETURN GO /****** Object: StoredProcedure [dbo].[getGrids] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getGrids] WITH EXECUTE AS OWNER AS SELECT [ContentID], [Data], [Config], [DTS], [UserID], [LastChanged] FROM [Grids] RETURN GO /****** Object: StoredProcedure [dbo].[getGrid] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getGrid] ( @ContentID int ) WITH EXECUTE AS OWNER AS SELECT [ContentID], [Data], [Config], [DTS], [UserID], [LastChanged] FROM [Grids] WHERE [ContentID]=@ContentID RETURN GO /****** Object: StoredProcedure [dbo].[addImage] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addImage] ( @ContentID int, @ImageType int, @FileName nvarchar(255), @Data varbinary(MAX), @Config xml=null, @DTS datetime, @UserID nvarchar(100), @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Images] ( [ContentID], [ImageType], [FileName], [Data], [Config], [DTS], [UserID] ) VALUES ( @ContentID, @ImageType, @FileName, @Data, @Config, @DTS, @UserID ) SELECT @newLastChanged=[LastChanged] FROM [Images] WHERE [ContentID]=@ContentID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getImage] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getImage] ( @ContentID int ) WITH EXECUTE AS OWNER AS SELECT [ContentID], [ImageType], [FileName], [Data], [Config], [DTS], [UserID], [LastChanged] FROM [Images] WHERE [ContentID]=@ContentID RETURN GO /****** Object: StoredProcedure [dbo].[getImages] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getImages] WITH EXECUTE AS OWNER AS SELECT [ContentID], [ImageType], [FileName], [Data], [Config], [DTS], [UserID], [LastChanged] FROM [Images] RETURN GO /****** Object: StoredProcedure [dbo].[getImagesByContentID] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getImagesByContentID] ( @ContentID int ) WITH EXECUTE AS OWNER AS SELECT [Images].[ContentID], [Images].[ImageType], [Images].[FileName], [Images].[Data], [Images].[Config], [Images].[DTS], [Images].[UserID], [Images].[LastChanged] FROM [Images] WHERE [Images].[ContentID]=@ContentID RETURN GO /****** Object: StoredProcedure [dbo].[deleteImage] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteImage] ( @ContentID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Images] WHERE [ContentID] = @ContentID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[existsImage] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsImage] ( @ContentID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Images] WHERE [ContentID]=@ContentID RETURN GO /****** Object: StoredProcedure [dbo].[updateImage] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateImage] ( @ContentID int, @ImageType int, @FileName nvarchar(255), @Data varbinary(MAX), @Config xml=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Images] SET [ImageType]=@ImageType, [FileName]=@FileName, [Data]=@Data, [Config]=@Config, [DTS]=@DTS, [UserID]=@UserID WHERE [ContentID]=@ContentID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Images] WHERE [ContentID]=@ContentID) RAISERROR('Image record has been deleted by another user', 16, 1) ELSE RAISERROR('Image has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Images] WHERE [ContentID]=@ContentID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[updateZTransition] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateZTransition] ( @TransitionID int, @Oldto nvarchar(32), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [ZTransitions] SET [oldto]=@Oldto WHERE [TransitionID]=@TransitionID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [ZTransitions] WHERE [TransitionID]=@TransitionID) RAISERROR('ZTransition record has been deleted by another user', 16, 1) ELSE RAISERROR('ZTransition has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [ZTransitions] WHERE [TransitionID]=@TransitionID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getZTransitionsByTransitionID] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getZTransitionsByTransitionID] ( @TransitionID int ) WITH EXECUTE AS OWNER AS SELECT [ZTransitions].[TransitionID], [ZTransitions].[oldto], [ZTransitions].[LastChanged] FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=@TransitionID RETURN GO /****** Object: StoredProcedure [dbo].[getZTransition] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getZTransition] ( @TransitionID int ) WITH EXECUTE AS OWNER AS SELECT [TransitionID], [oldto], [LastChanged] FROM [ZTransitions] WHERE [TransitionID]=@TransitionID RETURN GO /****** Object: StoredProcedure [dbo].[getZTransitions] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getZTransitions] WITH EXECUTE AS OWNER AS SELECT [TransitionID], [oldto], [LastChanged] FROM [ZTransitions] RETURN GO /****** Object: StoredProcedure [dbo].[existsZTransition] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsZTransition] ( @TransitionID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [ZTransitions] WHERE [TransitionID]=@TransitionID RETURN GO /****** Object: StoredProcedure [dbo].[deleteZTransition] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteZTransition] ( @TransitionID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [ZTransitions] WHERE [TransitionID] = @TransitionID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[addZTransition] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addZTransition] ( @TransitionID int, @Oldto nvarchar(32), @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [ZTransitions] ( [TransitionID], [oldto] ) VALUES ( @TransitionID, @Oldto ) SELECT @newLastChanged=[LastChanged] FROM [ZTransitions] WHERE [TransitionID]=@TransitionID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[deleteDROUsage] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [deleteDROUsage] ( @DROUsageID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [DROUsages] WHERE [DROUsageID] = @DROUsageID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[existsDROUsage] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsDROUsage] ( @DROUsageID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [DROUsages] WHERE [DROUsageID]=@DROUsageID RETURN GO /****** Object: StoredProcedure [dbo].[updateDROUsage] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateDROUsage] ( @DROUsageID int, @DocID int, @ROID nvarchar(16), @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @RODbID int, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [DROUsages] SET [DocID]=@DocID, [ROID]=@ROID, [Config]=@Config, [DTS]=@DTS, [UserID]=@UserID, [RODbID]=@RODbID WHERE [DROUsageID]=@DROUsageID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [DROUsages] WHERE [DROUsageID]=@DROUsageID) RAISERROR('DROUsage record has been deleted by another user', 16, 1) ELSE RAISERROR('DROUsage has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [DROUsages] WHERE [DROUsageID]=@DROUsageID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[getDROUsages] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getDROUsages] WITH EXECUTE AS OWNER AS SELECT [DROUsageID], [DocID], [ROID], [Config], [DTS], [UserID], [LastChanged], [RODbID] FROM [DROUsages] RETURN GO /****** Object: StoredProcedure [dbo].[getDROUsage] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [getDROUsage] ( @DROUsageID int ) WITH EXECUTE AS OWNER AS SELECT [DROUsageID], [DocID], [ROID], [Config], [DTS], [UserID], [LastChanged], [RODbID] FROM [DROUsages] WHERE [DROUsageID]=@DROUsageID RETURN GO /****** Object: StoredProcedure [dbo].[addDROUsage] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addDROUsage] ( @DocID int, @ROID nvarchar(16), @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @RODbID int, @newDROUsageID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [DROUsages] ( [DocID], [ROID], [Config], [DTS], [UserID], [RODbID] ) VALUES ( @DocID, @ROID, @Config, @DTS, @UserID, @RODbID ) SELECT @newDROUsageID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [DROUsages] WHERE [DROUsageID]=@newDROUsageID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[updateRole] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [updateRole] ( @RID int, @Name nvarchar(50), @Title nvarchar(250), @DTS datetime, @UsrID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Roles] SET [Name]=@Name, [Title]=@Title, [DTS]=@DTS, [UsrID]=@UsrID WHERE [RID]=@RID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Roles] WHERE [RID]=@RID) RAISERROR('Role record has been deleted by another user', 16, 1) ELSE RAISERROR('Role has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Roles] WHERE [RID]=@RID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[existsRole] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [existsRole] ( @RID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Roles] WHERE [RID]=@RID RETURN GO /****** Object: StoredProcedure [dbo].[addRole] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addRole] ( @Name nvarchar(50), @Title nvarchar(250), @DTS datetime, @UsrID nvarchar(100), @newRID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Roles] ( [Name], [Title], [DTS], [UsrID] ) VALUES ( @Name, @Title, @DTS, @UsrID ) SELECT @newRID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Roles] WHERE [RID]=@newRID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[vesp_GetGenMacMacros] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* vesp_GetGenMacMacros */ CREATE PROCEDURE [vesp_GetGenMacMacros] WITH EXECUTE AS OWNER AS BEGIN declare @pivotlist varchar(max) select @pivotlist = stuff((select distinct ',[' + [Name] + ']' from vefn_GetGenMacMacros() order by ',[' + [Name] + ']' for xml path('')),1,1,'') DECLARE @query VARCHAR(max) SET @query = 'SELECT * FROM (Select Name,''Format Description'' Path, Description From Formats) T1 PIVOT ( Max(Description) FOR [Name] IN (' + @pivotlist + ') ) As Pivot2' EXECUTE(@query) SET @query = 'SELECT * FROM (Select Name,''FormatID'' Path, FormatID From Formats) T1 PIVOT ( Max(FormatID) FOR [Name] IN (' + @pivotlist + ') ) As Pivot2' EXECUTE(@query) SET @query = 'SELECT * FROM (Select Name,MacroName From vefn_GetGenMacMacros()) T1 PIVOT ( Count(Name) FOR [Name] IN (' + @pivotlist + ') ) AS Pivot1 ORDER BY MacroName' print @Query EXECUTE(@query) END GO /****** Object: StoredProcedure [dbo].[PasteItemSiblingBefore] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [PasteItemSiblingBefore] ( @ItemID int=null, @StartItemID int=null, @Type int=null, @DTS datetime, @UserID nvarchar(100), @NewItemID int output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION -- First make a copy of the input CopyStartID -- DestFormatID is the formatid for the destination parent's format DECLARE @DestFormatID int SET @DestFormatID = .dbo.vefn_GetInheritedFormat(@ItemID, 0) EXECUTE CopyItemAndChildren @StartItemID, @DestFormatID, @UserID, @NewItemID OUTPUT -- First adjust previous fields, may also have to do parts, if before first one in list. DECLARE @PreviousID int, @ContentID int, @newLastChanged timestamp, @NewType int SELECT @PreviousID = [PreviousID], @NewType=ISNULL(@Type,[Type]) FROM [ITEMS] II JOIN [CONTENTS] CC ON CC.[ContentID]=II.[CONTENTID] WHERE [ItemID]=@ItemID UPDATE [ITEMS] SET [PreviousID]=@NewItemID where [ItemID]=@ItemID UPDATE [ITEMS] SET [PreviousID]=@PreviousID where [ItemID]=@NewItemID UPDATE [CONTENTS] SET [Type]=@Type FROM [CONTENTS] CC JOIN [ITEMS] ii ON CC.[ContentID]=II.[ContentID] WHERE [ItemID]=@NewItemID UPDATE [PARTS] SET [ItemID]=@NewItemID where [ItemID]=@ItemID UPDATE [DOCVERSIONS] SET [ItemID] = @NewItemID where [ItemID]=@ItemID IF @PreviousID is null -- The step is replacing the first step BEGIN -- Update content records for the transitions Update CC Set Text = DBO.vefn_FixTransitionText(Text,TT.TransitionID,TT.TranType,TT.ToID,TT.RangeID,@ItemID,@NewItemID) From CONTENTS CC JOIN Transitions TT ON TT.FromID = CC.ContentID WHERE TT.ToID = @ItemID OR TT.RangeID = @ItemID -- Update transitions that pointed to @ItemID to point to @newItemID Update TRANSITIONS Set ToID = CASE ToID WHEN @ItemID THEN @NewItemID ELSE ToID END, RangeID = CASE RangeID WHEN @ItemID THEN @NewItemID ELSE RangeID END WHERE ToID = @ItemID OR RangeID = @ItemID END ELSE -- Check for Transitions that point to the Next Step BEGIN -- Get a list of Transitions which need to change children of @ItemID that point to @NextID DECLARE @NextStepTransitions TABLE ( [TransitionID] int PRIMARY KEY, [FromID] [int], [ToID] [int], [RangeID] [int], [TranType] [int], [Config] [nvarchar](max) ) Insert into @NextStepTransitions select * from vefn_NextStepTransitions(@ItemID,@PreviousID) IF (SELECT COUNT(*) from @NextStepTransitions) > 0 -- Next Step Transitions BEGIN -- Update all transitions in the list to point to @newItemID Update TT Set TT.ToID = CASE TT.ToID WHEN @ItemID THEN @NewItemID ELSE TT.ToID END, TT.RangeID = CASE TT.RangeID WHEN @ItemID THEN @NewItemID ELSE TT.RangeID END From TRANSITIONS TT JOIN @NextStepTransitions NS ON NS.TransitionID = TT.TransitionID -- Update content records for the transitions Update CC Set Text = DBO.vefn_FixTransitionText(Text,NS.TransitionID,NS.TranType,NS.ToID,NS.RangeID,@ItemID,@NewItemID) From CONTENTS CC JOIN @NextStepTransitions NS ON NS.FromID = CC.ContentID END END -- Add 'Verification Required' AnnotationType DECLARE @typeID int SELECT @typeID = TypeID from AnnotationTypes where Name = 'Verification Required' IF(@typeID IS NULL) BEGIN INSERT INTO [AnnotationTypes] ([Name],[UserID]) VALUES ('Verification Required','Volian') SELECT @typeID = SCOPE_IDENTITY() END -- Add "Verification Required" Annotation for each Transition that points to @newItemID or @NextID INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) SELECT ItemID, @typeID,'Verify Transition Destination',@UserID FROM Items where CONTENTID in (SELECT FromID FROM TRANSITIONS where ToID IN(@ItemID,@NewItemID) OR RangeID IN(@ItemID,@NewItemID)) -- Transition Text gets updated in ItemInsertExt.cs IF( @@TRANCOUNT > 0 ) COMMIT EXECUTE GetItem @NewItemID END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[PasteItemReplace] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ItemID is item to replace -- StartItemID is item to copy CREATE PROCEDURE [PasteItemReplace] ( @ItemID int=null, @StartItemID int=null, @Type int=null, @DTS datetime, @UserID nvarchar(100), @NewItemID int output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DECLARE @ContentID AS INT DECLARE @NextItemID AS INT DECLARE @PreviousItemID AS INT DECLARE @ExternalChildCount AS INT DECLARE @ExternalCount AS INT DECLARE @Path AS VARCHAR(MAX) DECLARE @Children AS TABLE ( ItemID INT PRIMARY KEY, ContentID INT ) -- First check if the replaced item can be deleted, i.e. it doesn't have transitions -- pointing to it or children. DECLARE @ExternalTrans TABLE ( [FromItemID] int, [TransitionID] [int] NOT NULL, [FromID] [int] NOT NULL, [ToID] [int] NOT NULL, [RangeID] [int] NOT NULL, [Config] [nvarchar](max) NULL ) SET NOCOUNT ON SELECT @ContentID = ContentID, @PreviousItemID = PreviousID FROM Items WHERE ItemID = @ItemID SELECT @NextItemID = ItemID FROM Items WHERE PreviousID = @ItemID --SELECT @ExternalCount = count(*) FROM vefn_FindExternalTransitions(@ItemID) SELECT @ExternalChildCount = count(*) FROM vefn_FindExternalChildTransitions(@ItemID) SET @Path = [dbo].[ve_GetShortPath](@ItemID) --IF @ExternalCount > 0 AND @NextItemID is null --BEGIN -- RAISERROR ('###Cannot Delete Item###Step %d has External Transitions and has no next step - (%s)',16,1,@ItemID,@Path) -- RETURN --END IF @ExternalChildCount > 0 BEGIN RAISERROR ('###Cannot Delete Item###Step %d has External Transitions to it''s children - (%s)',16,1,@ItemID,@Path) RETURN END -- Copy the item, 'NewItemID' represents the new item(s) -- DestFormatID is the formatid for the destination parent's format DECLARE @DestFormatID int SET @DestFormatID = .dbo.vefn_GetInheritedFormat(@ItemID, 0) EXECUTE CopyItemAndChildren @StartItemID, @DestFormatID, @UserID, @NewItemID OUTPUT -- Adjust the next/previous to point to the new item DECLARE @PreviousID int SELECT @PreviousID = [PreviousID] FROM [ITEMS] II WHERE [ItemID]=@ItemID UPDATE [ITEMS] SET [PreviousID]=@PreviousID where [ItemID]=@NewItemID UPDATE [CONTENTS] SET [Type]=@Type FROM [CONTENTS] CC JOIN [ITEMS] ii ON CC.[ContentID]=II.[ContentID] WHERE [ItemID]=@NewItemID UPDATE [ITEMS] SET [PreviousID]=@NewItemID where [PreviousID]=@ItemID UPDATE [PARTS] SET [ItemID]=@NewItemID where [ItemID]=@ItemID -- UPDATE DocVersion if this was a procedure UPDATE DocVersions SET ItemID=@NewItemID where ItemID = @ItemID -- If there were 'external transitions' that pointed to the original -- top replaced step, adjust them to point to the new top. INSERT INTO @ExternalTrans SELECT * FROM vefn_FindExternalTransitions(@ItemID) IF (SELECT COUNT(*) from @ExternalTrans) > 0 BEGIN -- Update content records for the transitions Update CC Set Text = DBO.vefn_FixTransitionText(Text,TT.TransitionID,TT.TranType,TT.ToID,TT.RangeID,@ItemID,@NewItemID) From CONTENTS CC JOIN Transitions TT ON TT.FromID = CC.ContentID WHERE TransitionID in(Select TransitionID from @ExternalTrans) -- Update transitions that point to @ItemID to Point to @NextItemID UPDATE TRANSITIONS SET ToID = case when ToID = @ItemID then @NewItemID else ToID END, RangeID = case when RangeID = @ItemID then @NewItemID else RangeID END WHERE TransitionID in(Select TransitionID from @ExternalTrans) DECLARE @typeID int -- AnnotationType SELECT @typeID = TypeID from AnnotationTypes where Name = 'Verification Required' IF(@typeID IS NULL) BEGIN INSERT INTO [AnnotationTypes] ([Name],[UserID]) VALUES ('Verification Required','Volian') SELECT @typeID = SCOPE_IDENTITY() END -- Add 'Verification Required' annotions for transtions that pointed to top step -- and need to point to INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) SELECT ItemID, @typeID,'Verify Replaced Step Transition Destination',@UserID FROM Items where ItemID in (SELECT FromItemID FROM @ExternalTrans) END -- Remove the old one -- Get list of Children INSERT INTO @Children SELECT * FROM vefn_ChildItems(@ItemID) -- Delete Annotations for @ItemID and children DELETE from Annotations where ItemID in(Select ItemID from @Children) -- Delete Details associated with @ContentID and children DELETE from Details where ContentID in(Select ContentID from @Children) -- Delete Grids associated with @ContentID and children DELETE from Grids where ContentID in(Select ContentID from @Children) -- Delete Images associated with @ContentID and children DELETE from Images where ContentID in(Select ContentID from @Children) -- Delete Entries associated with @ContentID and children DELETE from Entries where ContentID in(Select ContentID from @Children) -- Delete ROUsages associated with @ContentID and children DELETE from RoUsages where ContentID in(Select ContentID from @Children) -- Delete ZTransitions records associated with @ContentID and children DELETE FROM ZTransitions where TransitionID in(SELECT TransitionID from Transitions where FromID in(SELECT ContentID FROM @Children) or FromID = @ContentID) -- Delete Transitions associated with @ContentID and children DELETE FROM Transitions where FromID in(SELECT ContentID FROM @Children) or FromID = @ContentID -- Delete Parts associated with @ContentID and children DELETE from Parts where ContentID in(Select ContentID from @Children) -- Delete ZContents associated with @ContentID and children DELETE from ZContents where ContentID in(Select ContentID from @Children) -- Disconnect Items from Each Other DELETE from Items where ItemID in(Select ItemID from @Children) and PreviousID Is Not Null -- Disconnect Items to be deleted from each other Update Items set PreviousID = null where ItemID in (Select ItemID from @Children) and PreviousID Is Not Null -- Delete Item Records DELETE from Items where ItemID in(Select ItemID from @Children) -- DELETE Contents DELETE from Contents where ContentID in(Select ContentID from @Children) IF( @@TRANCOUNT > 0 ) COMMIT EXECUTE GetItem @NewItemID END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: UserDefinedFunction [dbo].[vefn_DocVersionSplit] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select * from vefn_DocVersionSplit('1,4') select * from vefn_DocVersionSplit(null) select * from vefn_DocVersionSplit('') */ CREATE FUNCTION [vefn_DocVersionSplit](@DocVersionList varchar(MAX)) RETURNS @IDs TABLE ( VersionID int PRIMARY KEY, ItemID int, DVPath varchar(MAX) ) WITH EXECUTE AS OWNER AS BEGIN IF(isnull(@DocVersionList,'') = '') Insert into @IDs Select VersionID, ItemID, dbo.ve_GetFolderPath(VersionID) from DocVersions where ItemID is not null else Insert into @IDs Select ID, ItemID, dbo.ve_GetFolderPath(VersionID) from vefn_SplitInt(@DocVersionList,',') as T join DocVersions DV on VersionID = T.ID RETURN END GO /****** Object: StoredProcedure [dbo].[Standardize] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Standardize '%engineering evaluation%' Standardize '%preferred running order%' Standardize '%provide normal spray%' */ CREATE PROCEDURE [Standardize] ( @LookFor varchar(255) ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DECLARE @ContentID INT SET @Contentid = (select min(ContentID) FROM FindText(@LookFor)) UPDATE Items SET ContentID = @ContentID WHERE ItemID in(SELECT ItemID FROM FindText(@LookFor)) IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[PasteItemSiblingAfter] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [PasteItemSiblingAfter] ( @ItemID int=null, @StartItemID int=null, -- ItemID is destination, StartItemID is top of copy @Type int=null, @DTS datetime, @UserID nvarchar(100), @NewItemID int output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION -- First make a copy of the input StartItemID -- DestFormatID is the formatid for the destination parent's format DECLARE @DestFormatID int SET @DestFormatID = .dbo.vefn_GetInheritedFormat(@ItemID, 0) EXECUTE CopyItemAndChildren @StartItemID, @DestFormatID, @UserID, @NewItemID OUTPUT -- Adjust previous field DECLARE @NextID int SELECT @NextID = [ItemID] FROM [ITEMS] WHERE [PreviousID]=@ItemID IF @NextID is not null -- step after the copy point. Adjust it's previous to point to the new step BEGIN UPDATE [ITEMS] SET [PreviousID]=@NewItemID, [DTS]=@DTS, [UserID]=@UserID where [ItemID]=@NextID END UPDATE [ITEMS] SET [PreviousID]=@ItemID where [ItemID]=@NewItemID UPDATE [CONTENTS] SET [Type]=@Type FROM [CONTENTS] CC JOIN [ITEMS] ii ON CC.[ContentID]=II.[ContentID] WHERE [ItemID]=@NewItemID -- Check for Transitions that point to the Next Step BEGIN -- Get a list of Transitions which need to change children of @ItemID that point to @NextID DECLARE @NextStepTransitions TABLE ( [TransitionID] int PRIMARY KEY, [FromID] [int], [ToID] [int], [RangeID] [int], [TranType] [int], [Config] [nvarchar](max) ) Insert into @NextStepTransitions select * from vefn_NextStepTransitions(@NextID,@ItemID) IF (SELECT COUNT(*) from @NextStepTransitions) > 0 -- Next Step Transitions BEGIN -- Update all transitions in the list to point to @newItemID Update TT Set TT.ToID = CASE TT.ToID WHEN @NextID THEN @NewItemID ELSE TT.ToID END, TT.RangeID = CASE TT.RangeID WHEN @NextID THEN @NewItemID ELSE TT.RangeID END From TRANSITIONS TT JOIN @NextStepTransitions NS ON NS.TransitionID = TT.TransitionID -- Update content records for the transitions Update CC Set Text = DBO.vefn_FixTransitionText(Text,NS.TransitionID,NS.TranType,NS.ToID,NS.RangeID,@NextID,@NewItemID) From CONTENTS CC JOIN @NextStepTransitions NS ON NS.FromID = CC.ContentID END END -- Add 'Verification Required' AnnotationType DECLARE @typeID int SELECT @typeID = TypeID from AnnotationTypes where Name = 'Verification Required' IF(@typeID IS NULL) BEGIN INSERT INTO [AnnotationTypes] ([Name],[UserID]) VALUES ('Verification Required','Volian') SELECT @typeID = SCOPE_IDENTITY() END -- Add "Verification Required" Annotation for each Transition that points to @newItemID or @NextID INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) SELECT ItemID, @typeID,'Verify Next Step Transition Destination',@UserID FROM Items where CONTENTID in (SELECT FromID FROM TRANSITIONS where ToID IN(@newItemID) OR RangeID IN(@newItemID)) INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) SELECT ItemID, @typeID,'Verify Transition Destination',@UserID FROM Items where CONTENTID in (SELECT FromID FROM TRANSITIONS where ToID IN(@NextID) OR RangeID IN(@NextID)) -- Transition Text gets updated in ItemInsertExt.cs IF( @@TRANCOUNT > 0 ) COMMIT EXECUTE GetItem @NewItemID END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: UserDefinedFunction [dbo].[ve_GetPathFromContentID] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select top 5 [dbo].[ve_GetPathFromContentID](FromID)FromPath ,[dbo].[ve_GetPath](ToID) ToPath ,[dbo].[ve_GetPath](RangeID) RangePath from transitions */ CREATE FUNCTION [ve_GetPathFromContentID] (@ContentID int) RETURNS varchar(max) WITH EXECUTE AS OWNER AS BEGIN declare @ItemID int; select top 1 @ItemID=ItemID from Items where ContentID = @ContentID; return DBO.ve_GetPath(@ItemID) END GO /****** Object: UserDefinedFunction [dbo].[vefn_HighLevelStepTransitions] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select * from vefn_HighLevelStepTransitions(105,104) where TransCount > 0 */ CREATE FUNCTION [vefn_HighLevelStepTransitions](@ItemID int, @ParentID int) RETURNS @HighLevelStepTransitions TABLE ( ParentID int ,ItemID int PRIMARY KEY ,Path varchar(max) ,TransCount int ,ExternalTransitions int ,InternalTransitions int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], @ParentID [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 [pContentID],[DTS] [pDTS], [UserID] [pUserID], [LastChanged] [pLastChanged] FROM [Items] where [ItemID]=@ItemID -- Siblings Union All select [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null from Itemz Z join Items I on I.PreviousID = Z.ItemID --where Z.[Level] > 0 ) Insert into @HighLevelStepTransitions select [ParentID],ItemID,dbo.ve_GetPath([ItemID]) ,(Select Count(*) from Transitions where ToID=ItemID OR RangeID=ItemID ) TransCount ,(Select count(*) from vefn_FindExternalTransitions(ItemID)) ExternalTransitions ,(Select count(*) from vefn_FindInternalTransitions(ItemID)) InternalTransitions from Itemz RETURN END GO /****** Object: StoredProcedure [dbo].[addItemSiblingBefore] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addItemSiblingBefore] ( @ItemID int=null, @Number nvarchar(30)=null, @Text nvarchar(MAX)=null, @FormatID int=null, @Config nvarchar(MAX)=null, @Type int=null, @DTS datetime, @UserID nvarchar(100), @newItemID int output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DECLARE @PreviousID int, @ContentID int, @newLastChanged timestamp, @NewType int SELECT @PreviousID = [PreviousID], @NewType=ISNULL(@Type,[Type]) FROM [ITEMS] II JOIN [CONTENTS] CC ON CC.[ContentID]=II.[CONTENTID] WHERE [ItemID]=@ItemID EXECUTE AddContent @Number, @Text, @NewType, @FormatID, @Config, @DTS, @UserID, @ContentID output, @newLastChanged output EXECUTE AddItem @PreviousID, @ContentID, @DTS, @UserID , @newItemID output, @newLastChanged output UPDATE [ITEMS] SET [PreviousID]=@newItemID where [ItemID]=@ItemID -- Should be UpdateItem UPDATE [PARTS] SET [ItemID]=@newItemID where [ItemID]=@ItemID -- Should be UpdatePart IF @PreviousID is null -- The step is replacing the first step BEGIN -- Update content records for the transitions Update CC Set Text = DBO.vefn_FixTransitionText(Text,TT.TransitionID,TT.TranType,TT.ToID,TT.RangeID,@ItemID,@newItemID) From CONTENTS CC JOIN Transitions TT ON TT.FromID = CC.ContentID WHERE TT.ToID = @ItemID OR TT.RangeID = @ItemID -- Update transitions that pointed to @ItemID to point to @newItemID Update TRANSITIONS Set ToID = CASE ToID WHEN @ItemID THEN @newItemID ELSE ToID END, RangeID = CASE RangeID WHEN @ItemID THEN @newItemID ELSE RangeID END WHERE ToID = @ItemID OR RangeID = @ItemID END ELSE -- Check for Transitions that point to the Next Step BEGIN -- Get a list of Transitions which need to change children of @ItemID that point to @NextID DECLARE @NextStepTransitions TABLE ( [TransitionID] int PRIMARY KEY, [FromID] [int], [ToID] [int], [RangeID] [int], [TranType] [int], [Config] [nvarchar](max) ) Insert into @NextStepTransitions select * from vefn_NextStepTransitions(@ItemID,@PreviousID) IF (SELECT COUNT(*) from @NextStepTransitions) > 0 -- Next Step Transitions BEGIN -- Update all transitions in the list to point to @newItemID Update TT Set TT.ToID = CASE TT.ToID WHEN @ItemID THEN @newItemID ELSE TT.ToID END, TT.RangeID = CASE TT.RangeID WHEN @ItemID THEN @newItemID ELSE TT.RangeID END From TRANSITIONS TT JOIN @NextStepTransitions NS ON NS.TransitionID = TT.TransitionID -- Update content records for the transitions Update CC Set Text = DBO.vefn_FixTransitionText(Text,NS.TransitionID,NS.TranType,NS.ToID,NS.RangeID,@ItemID,@newItemID) From CONTENTS CC JOIN @NextStepTransitions NS ON NS.FromID = CC.ContentID END END -- Add 'Verification Required' AnnotationType DECLARE @typeID int SELECT @typeID = TypeID from AnnotationTypes where Name = 'Verification Required' IF(@typeID IS NULL) BEGIN INSERT INTO [AnnotationTypes] ([Name],[UserID]) VALUES ('Verification Required','Volian') SELECT @typeID = SCOPE_IDENTITY() END -- Add "Verification Required" Annotation for each Transition that points to @newItemID or @NextID INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) SELECT ItemID, @typeID,'Verify Transition Destination',@UserID FROM Items where CONTENTID in (SELECT FromID FROM TRANSITIONS where ToID IN(@ItemID,@newItemID) OR RangeID IN(@ItemID,@newItemID)) -- Transition Text gets updated in ItemInsertExt.cs IF( @@TRANCOUNT > 0 ) COMMIT PRINT 'Sibling Added Before ' + ltrim(str(@newItemID)) EXECUTE GetItem @newItemID END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: StoredProcedure [dbo].[addItemSiblingAfter] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [addItemSiblingAfter] ( @ItemID int=null, @Number nvarchar(30)=null, @Text nvarchar(MAX)=null, @FormatID int=null, @Config nvarchar(MAX)=null, @Type int=null, @DTS datetime, @UserID nvarchar(100), @newItemID int output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DECLARE @NextID int, @ContentID int, @newLastChanged timestamp, @NewType int SELECT @NewType=ISNULL(@Type,[Type]) FROM [ITEMS] II JOIN [CONTENTS] CC ON II.[ContentID]=CC.[ContentID] WHERE [ItemID]=@ItemID SELECT @NextID = [ItemID] FROM [ITEMS] WHERE [PreviousID]=@ItemID EXECUTE AddContent @Number, @Text, @NewType, @FormatID, @Config, @DTS, @UserID, @ContentID output, @newLastChanged output EXECUTE AddItem @ItemID, @ContentID, @DTS, @UserID , @newItemID output, @newLastChanged output UPDATE [ITEMS] SET [PreviousID]=@newItemID, [DTS]=@DTS, [UserID]=@UserID where [ItemID]=@NextID -- Should be UpdateItem -- Get a list of Transitions which need to change children of @ItemID that point to @NextID DECLARE @NextStepTransitions TABLE ( [TransitionID] int PRIMARY KEY, [FromID] [int], [ToID] [int], [RangeID] [int], [TranType] [int], [Config] [nvarchar](max) ) Insert into @NextStepTransitions select * from vefn_NextStepTransitions(@NextID,@ItemID) IF (SELECT COUNT(*) from @NextStepTransitions) > 0 -- Next Step Transitions BEGIN -- Update all transitions in the list to point to @newItemID Update TT Set TT.ToID = CASE TT.ToID WHEN @NextID THEN @newItemID ELSE TT.ToID END, TT.RangeID = CASE TT.RangeID WHEN @NextID THEN @newItemID ELSE TT.RangeID END From TRANSITIONS TT JOIN @NextStepTransitions NS ON NS.TransitionID = TT.TransitionID -- Update content records for the transitions Update CC Set Text = DBO.vefn_FixTransitionText(Text,NS.TransitionID,NS.TranType,NS.ToID,NS.RangeID,@NextID,@newItemID) From CONTENTS CC JOIN @NextStepTransitions NS ON NS.FromID = CC.ContentID END -- Add 'Verification Required' AnnotationType DECLARE @typeID int SELECT @typeID = TypeID from AnnotationTypes where Name = 'Verification Required' IF(@typeID IS NULL) BEGIN INSERT INTO [AnnotationTypes] ([Name],[UserID]) VALUES ('Verification Required','Volian') SELECT @typeID = SCOPE_IDENTITY() END -- Add "Verification Required" Annotation for each Transition that points to @newItemID or @NextID INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) SELECT ItemID, @typeID,'Verify Next Step Transition Destination',@UserID FROM Items where CONTENTID in (SELECT FromID FROM TRANSITIONS where ToID IN(@newItemID) OR RangeID IN(@newItemID)) INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) SELECT ItemID, @typeID,'Verify Transition Destination',@UserID FROM Items where CONTENTID in (SELECT FromID FROM TRANSITIONS where ToID IN(@NextID) OR RangeID IN(@NextID)) -- Transition Text gets updated in ItemInsertExt.cs IF( @@TRANCOUNT > 0 ) COMMIT EXECUTE GetItem @newItemID END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: UserDefinedFunction [dbo].[vefn_AllHighLevelSteps] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE FUNCTION [vefn_AllHighLevelSteps]() RETURNS @HighLevelStepTransitions TABLE ( ParentID int ,ItemID int PRIMARY KEY ,Ordinal int ,Path varchar(max) ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], ParentID [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 [pContentID],[DTS] [pDTS], [UserID] [pUserID], [LastChanged] [pLastChanged] FROM (select II.ItemID ParentID, PP.ItemID, PreviousID, II.ContentID, II.DTS, II.UserID, II.LastChanged from Items II Join Contents CC on II.ContentID = CC.ContentID Join Parts PP on PP.ContentID = II.ContentID and FromType = 6 where CC.Type = 10000) TT -- Siblings Union All select [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null from Itemz Z join Items I on I.PreviousID = Z.ItemID --where Z.[Level] > 0 ) Insert into @HighLevelStepTransitions select [ParentID],ItemID,Ordinal,dbo.ve_GetPath([ItemID]) Path from Itemz Order by ParentID,ItemID RETURN END GO /****** Object: UserDefinedFunction [dbo].[ve_GetShortPathFromContentID] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select top 5 [dbo].[ve_GetShortPathFromContentID](FromID)FromPath ,[dbo].[ve_GetShortPath](ToID) ToPath ,[dbo].[ve_GetShortPath](RangeID) RangePath from transitions */ CREATE FUNCTION [ve_GetShortPathFromContentID] (@ContentID int) RETURNS varchar(max) WITH EXECUTE AS OWNER AS BEGIN declare @ItemID int; select top 1 @ItemID=ItemID from Items where ContentID = @ContentID; return DBO.ve_GetShortPath(@ItemID) END GO /****** Object: UserDefinedFunction [dbo].[vefn_AllHighLevelStepTransitions] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select * from vefn_AllHighLevelStepTransitions() where ExternalTransitions > 0 */ CREATE FUNCTION [vefn_AllHighLevelStepTransitions]() RETURNS @HighLevelStepTransitions TABLE ( ParentID int ,ItemID int PRIMARY KEY ,Ordinal int ,Path varchar(max) ,TransCount int ,ExternalTransitions int ,ExternalChildTransitions int ,InternalTransitions int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], ParentID [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 [pContentID],[DTS] [pDTS], [UserID] [pUserID], [LastChanged] [pLastChanged] FROM (select II.ItemID ParentID, PP.ItemID, PreviousID, II.ContentID, II.DTS, II.UserID, II.LastChanged from Items II Join Contents CC on II.ContentID = CC.ContentID Join Parts PP on PP.ContentID = II.ContentID and FromType = 6 where CC.Type = 10000) TT -- Siblings Union All select [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null from Itemz Z join Items I on I.PreviousID = Z.ItemID --where Z.[Level] > 0 ) Insert into @HighLevelStepTransitions select [ParentID],ItemID,Ordinal,dbo.ve_GetShortPath([ItemID]) Path,(Select Count(*) from Transitions where ToID=ItemID OR RangeID=ItemID ) TransCount ,(Select count(*) from vefn_FindExternalTransitions(ItemID)) ExternalTransitions ,(Select count(*) from vefn_FindExternalChildTransitions(ItemID)) ExternalChildTransitions ,(Select count(*) from vefn_FindInternalTransitions(ItemID)) InternalTransitions from Itemz where (Select Count(*) from Transitions where ToID=ItemID OR RangeID=ItemID ) > 0 OR(Select count(*) from vefn_FindExternalTransitions(ItemID)) > 0 OR(Select count(*) from vefn_FindInternalTransitions(ItemID)) > 0 Order by ParentID,ItemID RETURN END GO /****** Object: StoredProcedure [dbo].[addItemChild] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO --http://www.code-magazine.com/articleprint.aspx?quickid=0305111&page=4&printmode=true --http://aleemkhan.wordpress.com/2006/07/21/t-sql-error-handling-pattern-for-nested-transactions-and-stored-procedures/ CREATE PROCEDURE [addItemChild] ( @ItemID int=null, @Number nvarchar(30)=null, @Text nvarchar(MAX)=null, @FormatID int=null, @Config nvarchar(MAX)=null, @FromType int=null, @Type int=null, @DTS datetime, @UserID nvarchar(100), @newItemID int output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DECLARE @ChildID int, @ContentID int, @ParentContentID int, @LastChanged timestamp , @newLastChanged timestamp, @Error int, @Rowcount int, @ChildDeleted int SELECT @ChildID = pp.[ItemID],@ParentContentID = ii.ContentID, @LastChanged = pp.LastChanged FROM [ITEMS] ii LEFT JOIN [PARTS] pp on pp.ContentID=ii.ContentID and pp.FromType=@FromType WHERE ii.[ItemID]=@ItemID IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[tblParts]') AND OBJECTPROPERTY(id,N'IsTable') = 1) BEGIN SELECT @ChildDeleted = pp.[ItemID],@ParentContentID = ii.ContentID, @LastChanged = pp.LastChanged FROM [ITEMS] ii LEFT JOIN [tblPARTS] pp on pp.ContentID=ii.ContentID and pp.FromType=@FromType WHERE ii.[ItemID]=@ItemID and pp.DateEnd is not null END EXECUTE AddContent @Number, @Text, @Type, @FormatID, @Config, @DTS, @UserID, @ContentID output, @newLastChanged output EXECUTE AddItem null, @ContentID, @DTS, @UserID , @newItemID output, @newLastChanged output IF @ChildID is null -- No existing child - Add Parts record BEGIN IF @ChildDeleted is not null BEGIN INSERT INTO [tblParts_shadow] ([ContentID],[FromType],[ItemID],[DTS],[UserID],[DateEnd]) SELECT [ContentID],[FromType],[ItemID],[DTS],[UserID],[DateEnd] FROM [tblParts] WHERE ItemID = @ChildDeleted DELETE FROM [tblParts] WHERE ItemID = @ChildDeleted END EXECUTE AddPart @ParentContentID, @FromType, @newItemID, @DTS, @UserID, @newLastChanged output END ELSE -- Update existing Parts record BEGIN EXECUTE UpdatePart @ParentContentID, @FromType, @newItemID, @DTS, @UserID, @LastChanged, @newLastChanged output UPDATE [Items] SET [PreviousID]=@newItemID WHERE [ItemID]=@ChildID -- Update content records for the transitions Update CC Set Text = DBO.vefn_FixTransitionText(Text,TT.TransitionID,TT.TranType,TT.ToID,TT.RangeID,@ItemID,@newItemID) From CONTENTS CC JOIN Transitions TT ON TT.FromID = CC.ContentID WHERE TT.ToID = @ChildID OR TT.RangeID = @ChildID -- Update transitions that pointed to @ItemID to point to @newItemID Update TRANSITIONS Set ToID = CASE ToID WHEN @ChildID THEN @newItemID ELSE ToID END, RangeID = CASE RangeID WHEN @ChildID THEN @newItemID ELSE RangeID END WHERE ToID = @ChildID OR RangeID = @ChildID -- Add 'Verification Required' AnnotationType DECLARE @typeID int SELECT @typeID = TypeID from AnnotationTypes where Name = 'Verification Required' IF(@typeID IS NULL) BEGIN INSERT INTO [AnnotationTypes] ([Name],[UserID]) VALUES ('Verification Required','Volian') SELECT @typeID = SCOPE_IDENTITY() END -- Add "Verification Required" Annotation for each Transition that points to @newItemID or @NextID -- I don't expect to see any transitions that point to @ChildID. They should have changed in -- the update above to point to @newItemID. This is here for consistency with the other insert -- stored procedures INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) SELECT ItemID, @typeID,'Verify Transition Destination',@UserID FROM Items where CONTENTID in (SELECT FromID FROM TRANSITIONS where ToID IN(@ChildID,@newItemID) OR RangeID IN(@ChildID,@newItemID)) -- Transition Text gets updated in ItemInsertExt.cs END IF( @@TRANCOUNT > 0 ) COMMIT PRINT 'Child Added ' + ltrim(str(@newItemID)) EXECUTE GetItem @newItemID END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO /****** Object: UserDefinedFunction [dbo].[vefn_NextStepTransitions] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select * from vefn_NextStepTransitions(450,443) */ CREATE FUNCTION [vefn_NextStepTransitions](@ItemID int, @PreviousID int) RETURNS @Transitions TABLE ( [TransitionID] int PRIMARY KEY, [FromID] [int], [ToID] [int], [RangeID] [int], [TranType] [int], [Config] [nvarchar](max) ) WITH EXECUTE AS OWNER AS BEGIN INSERT INTO @Transitions SELECT [TransitionID],[FromID],[ToID],[RangeID],[TranType],[Config] FROM [Transitions] where FromID in (Select ContentID from vefn_ChildItems(@PreviousID)) AND (ToID = @ItemID OR RangeID = @ItemID) RETURN END GO /****** Object: StoredProcedure [dbo].[vesp_GetFormatFieldsByStepType] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* vesp_GetFormatFieldsByStepType 'PrintNoTitle' vesp_GetFormatFieldsByStepType 'Sep' vesp_GetFormatFieldsByStepType 'TabFormat' vesp_GetFormatFieldsByStepType 'ShowSectionTitles' vesp_GetFormatFieldsByStepType 'Caution' vesp_GetFormatFieldsByStepType 'Ident' vesp_GetFormatFieldsByStepType 'Off' */ CREATE PROCEDURE [vesp_GetFormatFieldsByStepType] ( @find varchar(255) ) WITH EXECUTE AS OWNER AS BEGIN declare @pivotlist varchar(max) select @pivotlist = stuff((select distinct ',[' + [Name] + ']' from vefn_GetFormatField(@find) order by ',[' + [Name] + ']' for xml path('')),1,1,'') DECLARE @query VARCHAR(max) SET @query = 'SELECT * FROM (Select Name,''Format Description'' Path,'''' StepType, '''' Value, Description From Formats) T1 PIVOT ( Max(Description) FOR [Name] IN (' + @pivotlist + ') ) As Pivot2' EXECUTE(@query) SET @query = 'SELECT * FROM (Select Name,''FormatID'' Path, '''' StepType,'''' Value, FormatID From Formats) T1 PIVOT ( Max(FormatID) FOR [Name] IN (' + @pivotlist + ') ) As Pivot2' EXECUTE(@query) SET @query = 'SELECT * FROM (Select Name,Path,StepType,Value From vefn_GetFormatFieldByStepType(''' + @find + ''')) T1 PIVOT ( Count(Name) FOR [Name] IN (' + @pivotlist + ') ) AS Pivot1 ORDER BY PATH,StepType,VALUE' print @Query EXECUTE(@query) END GO /****** Object: StoredProcedure [dbo].[vesp_GetFormatFields] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* vesp_GetFormatFields 'PrintNoTitle' vesp_GetFormatFields 'Sep' vesp_GetFormatFields 'TabFormat' vesp_GetFormatFields 'ShowSectionTitles' vesp_GetFormatFields 'Caution' vesp_GetFormatFields 'Ident' */ CREATE PROCEDURE [vesp_GetFormatFields] ( @find varchar(255) ) WITH EXECUTE AS OWNER AS BEGIN declare @pivotlist varchar(max) select @pivotlist = stuff((select distinct ',[' + [Name] + ']' from vefn_GetFormatField(@find) order by ',[' + [Name] + ']' for xml path('')),1,1,'') DECLARE @query VARCHAR(max) SET @query = 'SELECT * FROM (Select Name,''Format Description'' Path,'''' Value, Description From Formats) T1 PIVOT ( Max(Description) FOR [Name] IN (' + @pivotlist + ') ) As Pivot2' EXECUTE(@query) SET @query = 'SELECT * FROM (Select Name,''FormatID'' Path,'''' Value, FormatID From Formats) T1 PIVOT ( Max(FormatID) FOR [Name] IN (' + @pivotlist + ') ) As Pivot2' EXECUTE(@query) SET @query = 'SELECT * FROM (Select Name,Path,Value From vefn_GetFormatField(''' + @find + ''')) T1 PIVOT ( Count(Name) FOR [Name] IN (' + @pivotlist + ') ) AS Pivot1 ORDER BY PATH,VALUE' print @Query EXECUTE(@query) END GO /****** Object: StoredProcedure [dbo].[vesp_GetFormatFieldsNoValue] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* vesp_GetFormatFieldsNoValue 'PrintNoTitle' vesp_GetFormatFieldsNoValue 'Sep' vesp_GetFormatFieldsNoValue 'TabFormat' vesp_GetFormatFieldsNoValue 'ShowSectionTitles' vesp_GetFormatFieldsNoValue 'Caution' vesp_GetFormatFieldsNoValue 'Ident' vesp_GetFormatFieldsNoValue 'Off' */ CREATE PROCEDURE [vesp_GetFormatFieldsNoValue] ( @find varchar(255) ) WITH EXECUTE AS OWNER AS BEGIN declare @pivotlist varchar(max) select @pivotlist = stuff((select distinct ',[' + [Name] + ']' from vefn_GetFormatField(@find) order by ',[' + [Name] + ']' for xml path('')),1,1,'') DECLARE @query VARCHAR(max) SET @query = 'SELECT * FROM (Select Name,''Format Description'' Path, Description From Formats) T1 PIVOT ( Max(Description) FOR [Name] IN (' + @pivotlist + ') ) As Pivot2' EXECUTE(@query) SET @query = 'SELECT * FROM (Select Name,''FormatID'' Path, FormatID From Formats) T1 PIVOT ( Max(FormatID) FOR [Name] IN (' + @pivotlist + ') ) As Pivot2' EXECUTE(@query) SET @query = 'SELECT * FROM (Select Name,Path From vefn_GetFormatFieldNoValue(''' + @find + ''')) T1 PIVOT ( Count(Name) FOR [Name] IN (' + @pivotlist + ') ) AS Pivot1 ORDER BY PATH' print @Query EXECUTE(@query) END GO /****** Object: StoredProcedure [dbo].[vesp_GetFormatGroupFieldsByStepType] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* vesp_GetFormatGroupFieldsByStepType 'PrintNoTitle' vesp_GetFormatGroupFieldsByStepType 'Sep' vesp_GetFormatGroupFieldsByStepType 'TabFormat' vesp_GetFormatGroupFieldsByStepType 'ShowSectionTitles' vesp_GetFormatGroupFieldsByStepType 'Caution' vesp_GetFormatGroupFieldsByStepType 'Ident' vesp_GetFormatGroupFieldsByStepType 'SectionTitleLen' vesp_GetFormatGroupFieldsByStepType 'Off' */ CREATE PROCEDURE [vesp_GetFormatGroupFieldsByStepType] ( @find varchar(255) ) WITH EXECUTE AS OWNER AS BEGIN declare @pivotlist varchar(max) select @pivotlist = stuff((select distinct ',[' + substring([Name],1,3) + ']' from vefn_GetFormatField(@find) order by ',[' + substring([Name],1,3) + ']' for xml path('')),1,1,'') DECLARE @query VARCHAR(max) SET @query = 'SELECT * FROM (Select substring([Name],1,3) FormatGroup,Path,StepType,Value From vefn_GetFormatFieldByStepType(''' + @find + ''')) T1 PIVOT ( Count(FormatGroup) FOR FormatGroup IN (' + @pivotlist + ') ) AS Pivot1 ORDER BY PATH, StepType,VALUE' print @Query EXECUTE(@query) END GO /****** Object: StoredProcedure [dbo].[vesp_GetFormatGroupFields] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* vesp_GetFormatGroupFields 'PrintNoTitle' vesp_GetFormatGroupFields 'Sep' vesp_GetFormatGroupFields 'TabFormat' vesp_GetFormatGroupFields 'ShowSectionTitles' vesp_GetFormatGroupFields 'Caution' vesp_GetFormatGroupFields 'Ident' vesp_GetFormatGroupFields 'SectionTitleLen' */ CREATE PROCEDURE [vesp_GetFormatGroupFields] ( @find varchar(255) ) WITH EXECUTE AS OWNER AS BEGIN declare @pivotlist varchar(max) select @pivotlist = stuff((select distinct ',[' + substring([Name],1,3) + ']' from vefn_GetFormatField(@find) order by ',[' + substring([Name],1,3) + ']' for xml path('')),1,1,'') DECLARE @query VARCHAR(max) SET @query = 'SELECT * FROM (Select substring([Name],1,3) FormatGroup,Path,Value From vefn_GetFormatField(''' + @find + ''')) T1 PIVOT ( Count(FormatGroup) FOR FormatGroup IN (' + @pivotlist + ') ) AS Pivot1 ORDER BY PATH,VALUE' print @Query EXECUTE(@query) END GO /****** Object: StoredProcedure [dbo].[vesp_GetFormatFieldsByStepType2] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* vesp_GetFormatFieldsByStepType2 'PrintNoTitle' vesp_GetFormatFieldsByStepType2 'Sep' vesp_GetFormatFieldsByStepType2 'TabFormat' vesp_GetFormatFieldsByStepType2 'ShowSectionTitles' vesp_GetFormatFieldsByStepType2 'Caution' vesp_GetFormatFieldsByStepType2 'Ident' vesp_GetFormatFieldsByStepType2 'Off' */ Create PROCEDURE [vesp_GetFormatFieldsByStepType2] ( @find varchar(255) ) WITH EXECUTE AS OWNER AS BEGIN declare @pivotlist varchar(max) select @pivotlist = stuff((select distinct ',[' + [Name] + ']' from vefn_GetFormatFieldByStepType2(@find) order by ',[' + [Name] + ']' for xml path('')),1,1,'') DECLARE @query VARCHAR(max) SET @query = 'SELECT * FROM (Select Name,''Format Description'' Path,'''' StepType, '''' Value, Description From Formats) T1 PIVOT ( Max(Description) FOR [Name] IN (' + @pivotlist + ') ) As Pivot2' EXECUTE(@query) SET @query = 'SELECT * FROM (Select Name,''FormatID'' Path, '''' StepType,'''' Value, FormatID From Formats) T1 PIVOT ( Max(FormatID) FOR [Name] IN (' + @pivotlist + ') ) As Pivot2' EXECUTE(@query) SET @query = 'SELECT * FROM (Select Name,Path,StepType,Value From vefn_GetFormatFieldByStepType2(''' + @find + ''')) T1 PIVOT ( Count(Name) FOR [Name] IN (' + @pivotlist + ') ) AS Pivot1 ORDER BY PATH,StepType,VALUE' print @Query EXECUTE(@query) END GO /****** Object: StoredProcedure [dbo].[vesp_GetFormatGroupFieldsNoValues] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* vesp_GetFormatGroupFieldsNoValues 'PrintNoTitle' vesp_GetFormatGroupFieldsNoValues 'Sep' vesp_GetFormatGroupFieldsNoValues 'TabFormat' vesp_GetFormatGroupFieldsNoValues 'ShowSectionTitles' vesp_GetFormatGroupFieldsNoValues 'Caution' vesp_GetFormatGroupFieldsNoValues 'Ident' vesp_GetFormatGroupFieldsNoValues 'SectionTitleLen' vesp_GetFormatGroupFieldsNoValues 'Off' */ CREATE PROCEDURE [vesp_GetFormatGroupFieldsNoValues] ( @find varchar(255) ) WITH EXECUTE AS OWNER AS BEGIN declare @pivotlist varchar(max) select @pivotlist = stuff((select distinct ',[' + substring([Name],1,3) + ']' from vefn_GetFormatFieldNoValue(@find) order by ',[' + substring([Name],1,3) + ']' for xml path('')),1,1,'') DECLARE @query VARCHAR(max) SET @query = 'SELECT * FROM (Select substring([Name],1,3) FormatGroup,Path From vefn_GetFormatFieldNoValue(''' + @find + ''')) T1 PIVOT ( Count(FormatGroup) FOR FormatGroup IN (' + @pivotlist + ') ) AS Pivot1 ORDER BY PATH' print @Query EXECUTE(@query) END GO /****** Object: StoredProcedure [dbo].[vesp_SearchItemAndChildren] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* exec vesp_SearchItemAndChildren '1,2,4','20007','#Link:Transition',1,0,0,0 exec vesp_SearchItemAndChildren '1,2,4','20007','#Link:Transition',1,1,0,0 exec vesp_SearchItemAndChildren '1,2,4','20007','#Link:Transition',1,2,0,0 exec vesp_SearchItemAndChildren '4','','#Link:Refer',1,2,0,0 exec vesp_SearchItemAndChildren '4','','200`F',0,1,0,0 exec vesp_SearchItemAndChildren '4','10000','',0,0,0,0 exec vesp_SearchItemAndChildren '4','','[0-9]`F',0,1,0,0 exec vesp_SearchItemAndChildren '','','RCP',0,0,0,0 exec vesp_SearchItemAndChildren '','','%',0,0,0,0 exec vesp_SearchItemAndChildren '','20040','',0,0,0,0 exec vesp_SearchItemAndChildren '','10000','XYZZY',0,0,0,0 exec vesp_SearchItemAndChildren '','10000','XYZZY',1,0,0,0 exec vesp_SearchItemAndChildren '','','%IF%',0,0,0,0 exec vesp_SearchItemAndChildren '','','%IF%',1,0,0,0 exec vesp_SearchItemAndChildren '','','%47%',1,0,0,0 exec vesp_SearchItemAndChildren '','','%47%',1,0,0,1 exec vesp_SearchItemAndChildren '','','condenser not av',0,0,0,0 exec vesp_SearchItemAndChildren '','','(SG OR LHSI) AND DISPATCH',2,0,0,0 exec vesp_SearchItemAndChildren '','','DISPATCH NEAR SG',2,0,0,0 exec vesp_SearchItemAndChildren '','','PORV NEAR SG',2,0,0,0 exec vesp_SearchItemAndChildren '','','CHECK NORMAL',0,0,0,0 exec vesp_SearchItemAndChildren '','','turbine-driven',0,0,0,0 */ CREATE PROCEDURE [vesp_SearchItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @SearchString varchar(MAX), @CaseSensitive as int, @IncludeLinks as int, @IncludeRtfFormatting as int, @IncludeSpecialCharacters as int) WITH EXECUTE AS OWNER AS BEGIN Declare @Delim char(1) Set @Delim=char(7) Declare @DelimNumber char(1) Set @DelimNumber=char(17) Declare @DelimStep char(1) Set @DelimStep='.' Set @SearchString = .dbo.vefn_FixSearchString(@SearchString) begin with Itemz(DVPath, [Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged],PPath, Path, IsRNO, POrdinalPath, OrdinalPath) as ( Select DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [I].[ItemID], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID],[I].[LastChanged] ,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID], [I].[LastChanged] [pLastChanged], Cast('' as nvarchar(max)) PPath, Cast(Case when C.Type < 20000 then @Delim + C.Number + @DelimNumber + C.Text else '1' end as nvarchar(max)) Path, 0 IsRNO, Cast('' as nvarchar(max)) POrdinalPath, Cast('0001' as nvarchar(max)) OrdinalPath FROM [Items] I Join Contents C on C.ContentID=I.ContentID JOIN vefn_DocVersionSplit(@DocVersionList) DV ON I.[ItemID] = DV.[ItemID] Union All -- Children select DVPath, [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID],P.[LastChanged] [pLastChanged] ,PATH + --'' case C.Type/10000 when 2 then case P.FromType when 3 then @DelimStep + 'Caution' when 4 then @DelimStep + 'Note' else '' end else '' end PPath, Path + case C.Type/10000 when 0 then @Delim +C.Number + @DelimNumber + C.Text when 1 then @Delim +C.Number + @DelimNumber + C.Text else case P.FromType --when 1 then 'PRC' + @Delim + cast(1 as varchar(3)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(3)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(3)) end end Path, case when P.FromType = 5 then -1 else 0 end IsRNO, OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-' , OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-0001' from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID join Contents C on C.ContentID = I.ContentID Union All -- Siblings select DVPath, [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null ,PPath, --'1' + PPath + case C.Type/10000 when 0 then @Delim + C.Number + @DelimNumber + C.Text when 1 then @Delim + C.Number + @DelimNumber + C.Text else case when Path like '%.%' then @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(3)) end Path, 0, POrdinalPath, POrdinalPath + right('0000' + cast(Z.[Ordinal] + 2 as varchar(4)), 4) from Itemz Z join Items I on I.PreviousID = Z.ItemID join Contents C on C.ContentID = I.ContentID --where Z.[Level] > 0 ) select DvPath, Path, I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], [pContentID],[pDTS],[pUserID],[pLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[I].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount] from ItemZ I join Contents C on C.ContentID = I.ContentID left join Entries E on C.ContentID = E.ContentID left join Documents D on E.DocID = D.DocID where (isnull(@SearchString,'')='' OR (@CaseSensitive = 1 AND .dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) like @SearchString Collate SQL_Latin1_General_CP1_CS_AS) OR (@CaseSensitive = 0 AND .dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) like @SearchString Collate SQL_Latin1_General_CP1_CI_AS) OR (@CaseSensitive = 1 AND D.DocAscii like @SearchString Collate SQL_Latin1_General_CP1_CS_AS) OR (@CaseSensitive = 0 AND D.DocAscii like @SearchString Collate SQL_Latin1_General_CP1_CI_AS) ) AND ((isnull(@StepTypeList,'') = '' and dbo.vefn_AllSections(C.Type)>=10000) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))) or (@StepTypeList like '%20040%' AND IsRNO = -1))) order by DvPath,OrdinalPath OPTION (MAXRECURSION 10000) END END GO /****** Object: StoredProcedure [dbo].[vesp_SearchAnnotationItemAndChildren] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* exec vesp_SearchAnnotationItemAndChildren Null,Null,'1',Null,0 exec vesp_SearchAnnotationItemAndChildren Null,Null,'2',Null,0 exec vesp_SearchAnnotationItemAndChildren Null,Null,'3',Null,0 exec vesp_SearchAnnotationItemAndChildren Null,Null,'4',Null,0 exec vesp_SearchAnnotationItemAndChildren Null,Null,'5',Null,0 exec vesp_SearchAnnotationItemAndChildren Null,Null,'',Null,0 */ CREATE PROCEDURE [vesp_SearchAnnotationItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @AnnotationTypeList varchar(MAX), @SearchString nvarchar(MAX), @CaseSensitive as int) WITH EXECUTE AS OWNER AS BEGIN Declare @Delim char(1) Set @Delim=char(7) Declare @DelimNumber char(1) Set @DelimNumber=char(17) Declare @DelimStep char(1) Set @DelimStep='.' Set @SearchString = .dbo.vefn_FixSearchString(@SearchString) begin with Itemz(DVPath, [Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged],PPath, Path, IsRNO, POrdinalPath, OrdinalPath) as ( Select DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [I].[ItemID], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID],[I].[LastChanged] ,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID], [I].[LastChanged] [pLastChanged], Cast('' as nvarchar(max)) PPath, Cast(Case when C.Type < 20000 then @Delim + C.Number + @DelimNumber + C.Text else '1' end as nvarchar(max)) Path, 0 IsRNO, Cast('' as nvarchar(max)) POrdinalPath, Cast('0001' as nvarchar(max)) OrdinalPath FROM [Items] I Join Contents C on C.ContentID=I.ContentID JOIN vefn_DocVersionSplit(@DocVersionList) DV ON I.[ItemID] = DV.[ItemID] Union All -- Children select DVPath, [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID],P.[LastChanged] [pLastChanged] ,PATH + --'' case C.Type/10000 when 2 then case P.FromType when 3 then @DelimStep + 'Caution' when 4 then @DelimStep + 'Note' else '' end else '' end PPath, Path + case C.Type/10000 when 0 then @Delim +C.Number + @DelimNumber + C.Text when 1 then @Delim +C.Number + @DelimNumber + C.Text else case P.FromType --when 1 then 'PRC' + @Delim + cast(1 as varchar(3)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(3)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(3)) end end Path, case when P.FromType = 5 then -1 else 0 end IsRNO, OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-' , OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-0001' from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID join Contents C on C.ContentID = I.ContentID Union All -- Siblings select DVPath, [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null ,PPath, --'1' + PPath + case C.Type/10000 when 0 then @Delim + C.Number + @DelimNumber + C.Text when 1 then @Delim + C.Number + @DelimNumber + C.Text else case when Path like '%.%' then @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(3)) end Path, 0, POrdinalPath, POrdinalPath + right('0000' + cast(Z.[Ordinal] + 2 as varchar(4)), 4) from Itemz Z join Items I on I.PreviousID = Z.ItemID join Contents C on C.ContentID = I.ContentID --where Z.[Level] > 0 ) select DvPath, Path, I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], [pContentID],[pDTS],[pUserID],[pLastChanged],AnnotationID SearchAnnotationID, SearchText, TT.Name AnnotationType, (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[I].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount] from ItemZ I join Contents C on C.ContentID = I.ContentID left join Entries E on C.ContentID = E.ContentID left join Documents D on E.DocID = D.DocID join Annotations A on A.ItemID = I.ItemID join vefn_AnnotationTypeSplit(@AnnotationTypeList) TT on TT.TypeID=A.TypeID where (isnull(@SearchString,'')='' OR (@CaseSensitive = 1 AND A.SearchText like @SearchString Collate SQL_Latin1_General_CP1_CS_AS) OR (@CaseSensitive = 0 AND A.SearchText like @SearchString Collate SQL_Latin1_General_CP1_CI_AS)) AND ((isnull(@StepTypeList,'') = '' and dbo.vefn_AllSections(C.Type)>=10000) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))) or (@StepTypeList like '%20040%' AND IsRNO = -1))) order by DvPath,OrdinalPath OPTION (MAXRECURSION 10000) END END GO /****** Object: StoredProcedure [dbo].[vesp_SearchROItemAndChildren] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* exec vesp_SearchROItemAndChildren '1,2,4','20007','1:00010000019C,0001000002AE' exec vesp_SearchROItemAndChildren '1,2,4','','1:00010000019C,0001000002AE' exec vesp_SearchROItemAndChildren '1,2,4','20007','1:0001' exec vesp_SearchROItemAndChildren '1,2,4','20006','1' exec vesp_SearchROItemAndChildren '1,2,4','20006','' exec vesp_SearchROItemAndChildren '1,2,4',Null,Null */ CREATE PROCEDURE [vesp_SearchROItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @ROSearchString varchar(MAX)) WITH EXECUTE AS OWNER AS BEGIN Declare @Delim char(1) Set @Delim=char(7) Declare @DelimNumber char(1) Set @DelimNumber=char(17) Declare @DelimStep char(1) Set @DelimStep='.' begin with Itemz(DVPath, [Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged],PPath, Path, IsRNO, POrdinalPath, OrdinalPath) as ( Select DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [I].[ItemID], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID],[I].[LastChanged] ,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID], [I].[LastChanged] [pLastChanged], Cast('' as nvarchar(max)) PPath, Cast(Case when C.Type < 20000 then @Delim + C.Number + @DelimNumber + C.Text else '1' end as nvarchar(max)) Path, 0 IsRNO, Cast('' as nvarchar(max)) POrdinalPath, Cast('0001' as nvarchar(max)) OrdinalPath FROM [Items] I Join Contents C on C.ContentID=I.ContentID JOIN vefn_DocVersionSplit(@DocVersionList) DV ON I.[ItemID] = DV.[ItemID] Union All -- Children select DVPath, [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID],P.[LastChanged] [pLastChanged] ,PATH + --'' case C.Type/10000 when 2 then case P.FromType when 3 then @DelimStep + 'Caution' when 4 then @DelimStep + 'Note' else '' end else '' end PPath, --Path + case when Z.FromType < 3 then @Delim else @DelimStep end + case C.Type/10000 Path + case C.Type/10000 when 0 then @Delim +C.Number + @DelimNumber + C.Text when 1 then @Delim +C.Number + @DelimNumber + C.Text else case P.FromType --when 1 then 'PRC' + @Delim + cast(1 as varchar(3)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(3)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(3)) end end Path, case when P.FromType = 5 then -1 else 0 end IsRNO, OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-' , OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-0001' from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID join Contents C on C.ContentID = I.ContentID Union All -- Siblings select DVPath, [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null ,PPath, --'1' + PPath + case C.Type/10000 when 0 then @Delim + C.Number + @DelimNumber + C.Text when 1 then @Delim + C.Number + @DelimNumber + C.Text else case when Path like '%.%' then @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(3)) end Path, 0, POrdinalPath, POrdinalPath + right('0000' + cast(Z.[Ordinal] + 2 as varchar(4)), 4) from Itemz Z join Items I on I.PreviousID = Z.ItemID join Contents C on C.ContentID = I.ContentID --where Z.[Level] > 0 ) select DvPath, Path, I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], [pContentID],[pDTS],[pUserID],[pLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[I].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount] from ItemZ I join Contents C on C.ContentID = I.ContentID left join Entries E on C.ContentID = E.ContentID left join Documents D on E.DocID = D.DocID where I.ContentID in(select ContentID from ROUsages RU join vefn_SplitROSearch(@ROSearchString) RR ON RR.RODBID = RU.RODBID and RU.ROID like RR.ROID + '%' Collate SQL_Latin1_General_CP1_CI_AS UNION select Distinct ContentID from Entries EE Join DROUsages RU on RU.DocID = EE.DocID join vefn_SplitROSearch(@ROSearchString) RR ON RR.RODBID = RU.RODBID and RU.ROID = RR.ROID) AND ((isnull(@StepTypeList,'') = '' and dbo.vefn_AllSections(C.Type)>=10000) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))) or (@StepTypeList like '%20040%' AND IsRNO = -1))) order by DvPath,OrdinalPath OPTION (MAXRECURSION 10000) END END GO /****** Object: UserDefinedFunction [dbo].[vefn_SiblingAndChildrenItems] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select * from vefn_SiblingAndChildrenItems('3') II join */ CREATE FUNCTION [vefn_SiblingAndChildrenItems](@DocVersionList varchar(10)) RETURNS @SiblingAndChildren TABLE ( [ItemID] int PRIMARY KEY , [DVPath] nvarchar(max) , [Path] nvarchar(max) , [Level] int , [FromType] int , [Ordinal] int , [ParentID] int , [PreviousID] int , [ContentID] int , [DTS] datetime , [UserID] nvarchar(100) , [pContentID] int , [pDTS] datetime , [pUserID] nvarchar(100) , [IsRNO] int -- , [PPath] nvarchar(max) -- , [POrdinalPath] nvarchar(max) , [OrdinalPath] nvarchar(max) ) WITH EXECUTE AS OWNER AS BEGIN Declare @Delim char(1) Set @Delim=char(7) Declare @DelimNumber char(1) Set @DelimNumber=char(17) Declare @DelimStep char(1) Set @DelimStep='.' BEGIN with Itemz([ItemID], [DVPath], [Level], [ParentID], [Ordinal], [PreviousID], [FromType], [ContentID], [DTS], [UserID],[pContentID], [pDTS],[pUserID],PPath, [Path], [IsRNO], [POrdinalPath], [OrdinalPath]) as ( Select [I].[ItemID], DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID] ,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID], Cast('' as nvarchar(max)) [PPath], Cast(Case when C.Type < 20000 then @Delim + C.Number + @DelimNumber + C.Text else '1' end as nvarchar(max)) [Path], 0 IsRNO, Cast('' as nvarchar(max)) [POrdinalPath], Cast('0001' as nvarchar(max)) [OrdinalPath] FROM [Items] I Join Contents C on C.ContentID=I.ContentID JOIN vefn_DocVersionSplit(@DocVersionList) DV ON I.[ItemID] = DV.[ItemID] Union All -- Children select I.[ItemID], DVPath, [Level] + 1,Z.ItemID,0, I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID], P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID] ,PATH + --'' case C.Type/10000 when 2 then case P.FromType when 3 then @DelimStep + 'Caution' when 4 then @DelimStep + 'Note' else '' end else '' end PPath, Path + case C.Type/10000 when 0 then @Delim +C.Number + @DelimNumber + C.Text when 1 then @Delim +C.Number + @DelimNumber + C.Text else case P.FromType --when 1 then 'PRC' + @Delim + cast(1 as varchar(3)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(3)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(3)) end end Path, case when P.FromType = 5 then -1 else 0 end IsRNO, OrdinalPath + '.' + Right('000' + Cast(P.FromType as varchar(4)), 4) + '-' , OrdinalPath + '.' + Right('000' + Cast(P.FromType as varchar(4)), 4) + '-00001' from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID join Contents C on C.ContentID = I.ContentID Union All -- Siblings select I.[ItemID], DVPath, [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID] ,null,null,null, PPath, --'1' + PPath + case C.Type/10000 when 0 then @Delim + C.Number + @DelimNumber + C.Text when 1 then @Delim + C.Number + @DelimNumber + C.Text else case when Path like '%.%' then @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(3)) end Path, 0, POrdinalPath, POrdinalPath + right('00000' + cast(Z.[Ordinal] + 2 as varchar(5)), 5) from Itemz Z join Items I on I.PreviousID = Z.ItemID join Contents C on C.ContentID = I.ContentID --where Z.[Level] > 0 ) insert into @SiblingAndChildren select I.[ItemID], [DvPath], [Path], I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID], [pContentID],[pDTS],[pUserID],[IsRNO]/*,[PPath],[POrdinalPath]*/,[OrdinalPath] from ItemZ I OPTION (MAXRECURSION 10000) END RETURN END GO /****** Object: UserDefinedFunction [dbo].[vefn_DVContent] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select contentID from vefn_DVContent('1') */ CREATE FUNCTION [vefn_DVContent](@DocVersionList varchar(MAX)) RETURNS @DVContents TABLE ( ContentID int PRIMARY KEY ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], 0 [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 [pContentID],[DTS] [pDTS], [UserID] [pUserID], [LastChanged] [pLastChanged] FROM [Items] where [ItemID] in (select [ItemID] from vefn_DocVersionSplit(@DocVersionList)) Union All -- Children select [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID],P.[LastChanged] [pLastChanged] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID -- Siblings Union All select [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null from Itemz Z join Items I on I.PreviousID = Z.ItemID ) insert into @DVContents select distinct ContentID from Itemz OPTION (MAXRECURSION 10000) RETURN END GO /****** Object: UserDefinedFunction [dbo].[vefn_FindContentText] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* SELECT * From vefn_FindContentText('1','%RCP%') */ CREATE FUNCTION [vefn_FindContentText]( @DocVersionList nvarchar(MAX) ,@SearchString varchar(MAX)) RETURNS @FoundContents TABLE ( ContentID int PRIMARY KEY ,Type int ,Text varchar(max) ) WITH EXECUTE AS OWNER AS BEGIN IF(ISNULL(@DocVersionList,'')='') BEGIN INSERT INTO @FoundContents -- Do a case insensitive search select ContentID,Type,Text from contents where [Text] like @SearchString Collate SQL_Latin1_General_CP1_CI_AS END ELSE BEGIN INSERT INTO @FoundContents -- Do a case insensitive search select ContentID,Type,Text from contents where [ContentID] in (select [ContentID] from vefn_DVContent(@DocVersionList)) AND [Text] like @SearchString Collate SQL_Latin1_General_CP1_CI_AS END RETURN END GO /****** Object: UserDefinedFunction [dbo].[vefn_FindText] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* SELECT * From vefn_FindText('1','turbine-driven',0,0,0,1,'') SELECT * From vefn_FindText('1','turbine\u8209?driven',0,0,0,0,'') SELECT * From vefn_FindText('1','trip',0,0,0,0,'') */ CREATE FUNCTION [vefn_FindText]( @DocVersionList nvarchar(MAX) ,@SearchString varchar(MAX) ,@CaseSensitive as int ,@IncludeLinks as int ,@IncludeRtfFormatting as int ,@IncludeSpecialCharacters as int ,@StepTypeList varchar(MAX)) RETURNS @FoundContents TABLE ( ContentID int PRIMARY KEY ) WITH EXECUTE AS OWNER AS BEGIN Set @SearchString = .dbo.vefn_FixSearchString(@SearchString) IF isnull(@SearchString,'')='' BEGIN insert into @FoundContents select C.ContentID from (select * from Contents where ContentID in(select ContentID from vefn_DVContent(@DocVersionList))) C where(dbo.vefn_AllSections(C.Type)>=10000) or (dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))) END ELSE Declare @SearchStringx nvarchar(200) --kbr set @SearchStringx = replace(@SearchString,'-','\u8209?') --kbr IF @CaseSensitive = 0 -- Not Case Sensitive BEGIN insert into @FoundContents select C.ContentID from vefn_FindContentText(@DocVersionList,@SearchStringx) C where (.dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) like @SearchStringx Collate SQL_Latin1_General_CP1_CI_AS) AND ((isnull(@StepTypeList,'') = '' and dbo.vefn_AllSections(C.Type)>=10000) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))))) UNION select C.ContentID from (select * from Contents where ContentID in(select ContentID from vefn_DVContent(@DocVersionList))) C join Entries E on C.ContentID = E.ContentID join Documents D on E.DocID = D.DocID where (D.DocAscii like @SearchString Collate SQL_Latin1_General_CP1_CI_AS) AND ((isnull(@StepTypeList,'') = '' and dbo.vefn_AllSections(C.Type)>=10000) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))))) END ELSE BEGIN IF @CaseSensitive = 1 -- Case Sensitive BEGIN insert into @FoundContents select C.ContentID from vefn_FindContentText(@DocVersionList,@SearchStringx) C where (.dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) like @SearchStringx Collate SQL_Latin1_General_CP1_CS_AS) AND ((isnull(@StepTypeList,'') = '' and dbo.vefn_AllSections(C.Type)>=10000) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))))) UNION select C.ContentID from (select * from Contents where ContentID in(select ContentID from vefn_DVContent(@DocVersionList))) C join Entries E on C.ContentID = E.ContentID join Documents D on E.DocID = D.DocID where (D.DocAscii like @SearchString Collate SQL_Latin1_General_CP1_CS_AS) AND ((isnull(@StepTypeList,'') = '' and dbo.vefn_AllSections(C.Type)>=10000) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))))) END END RETURN END GO /****** Object: StoredProcedure [dbo].[vesp_SearchItemAndChildrenNew] Script Date: 01/06/2012 15:02:56 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* exec vesp_SearchItemAndChildrenNew '1,2,4','20007','#Link:Transition',1,0,0,0 exec vesp_SearchItemAndChildrenNew '1,2,4','20007','#Link:Transition',1,1,0,0 exec vesp_SearchItemAndChildrenNew '1,2,4','20007','#Link:Transition',1,2,0,0 exec vesp_SearchItemAndChildrenNew '4','','#Link:Refer',1,2,0,0 exec vesp_SearchItemAndChildrenNew '4','','200`F',0,1,0,0 exec vesp_SearchItemAndChildrenNew '4','10000','',0,0,0,0 exec vesp_SearchItemAndChildrenNew '4','','[0-9]`F',0,1,0,0 exec vesp_SearchItemAndChildrenNew '1','','"RCP"',2,0,0,0 exec vesp_SearchItemAndChildrenNew '','','"RCP"',2,0,0,0 exec vesp_SearchItemAndChildrenNew '','','%',0,0,0,0 exec vesp_SearchItemAndChildrenNew '','20040','',0,0,0,0 exec vesp_SearchItemAndChildrenNew '','10000','XYZZY',0,0,0,0 exec vesp_SearchItemAndChildrenNew '','10000','XYZZY',1,0,0,0 exec vesp_SearchItemAndChildrenNew '','','%IF%',0,0,0,0 exec vesp_SearchItemAndChildrenNew '','','%IF%',1,0,0,0 exec vesp_SearchItemAndChildrenNew '','','%47%',1,0,0,0 exec vesp_SearchItemAndChildrenNew '','','%47%',1,0,0,1 exec vesp_SearchItemAndChildrenNew '','','condenser not av',0,0,0,0 exec vesp_SearchItemAndChildrenNew '','','(SG OR LHSI) AND DISPATCH',2,0,0,0 exec vesp_SearchItemAndChildrenNew '','','DISPATCH NEAR SG',2,0,0,0 exec vesp_SearchItemAndChildrenNew '','','PORV NEAR SG',2,0,0,0 exec vesp_SearchItemAndChildrenNew '','','CHECK NORMAL',0,0,0,0 exec vesp_SearchItemAndChildrenNew '','','(Resolved Transition Text)',0,0,0,0 exec vesp_SearchItemAndChildrenNew '','','%turbine-driven%',0,0,0,0 */ CREATE PROCEDURE [vesp_SearchItemAndChildrenNew] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @SearchString varchar(MAX), @CaseSensitive as int, @IncludeLinks as int, @IncludeRtfFormatting as int, @IncludeSpecialCharacters as int) WITH EXECUTE AS OWNER AS select ZZ.DvPath, ZZ.Path, ZZ.[Level],ZZ.[FromType],ZZ.[Ordinal], ZZ.[ParentID], ZZ.[ItemID],ZZ.[PreviousID],ZZ.[ContentID],ZZ.[DTS],ZZ.[UserID] ,II.[LastChanged] ,CC.[Number],CC.[Text],CC.[Type],CC.[FormatID],CC.[Config],CC.[DTS] [cDTS],CC.[UserID] [cUserID] ,CC.[LastChanged] [cLastChanged], PP.[ContentID] [pContentID], PP.[DTS] [pDTS],PP.[UserID] [pUserID], PP.[LastChanged] [pLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=ZZ.[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=ZZ.[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=ZZ.[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=ZZ.[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=ZZ.[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=ZZ.[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=CC.[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=CC.[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=CC.[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=CC.[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=CC.[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=CC.[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=CC.[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=CC.[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=CC.[ContentID]) [ZContentCount] from vefn_SiblingAndChildrenItems(@DocVersionList) ZZ Join Items II on ZZ.ItemID=II.ItemID Left Join Parts PP on ZZ.PContentID=PP.ContentID and ZZ.FromType = PP.FromType Join Contents CC on CC.ContentID=ZZ.ContentID where ZZ.ContentID in (select ContentID from vefn_FindText(@DocVersionList,@SearchString,@CaseSensitive,@IncludeLinks,@IncludeRtfFormatting,@IncludeSpecialCharacters,@StepTypeList)) order by DvPath,OrdinalPath GO /****** Object: ForeignKey [FK_Formats_ParentID] Script Date: 01/06/2012 15:02:52 ******/ ALTER TABLE [Formats] WITH CHECK ADD CONSTRAINT [FK_Formats_ParentID] FOREIGN KEY([ParentID]) REFERENCES [Formats] ([FormatID]) GO ALTER TABLE [Formats] CHECK CONSTRAINT [FK_Formats_ParentID] GO /****** Object: ForeignKey [FK_Associations_DocVersions] Script Date: 01/06/2012 15:02:52 ******/ ALTER TABLE [Associations] WITH CHECK ADD CONSTRAINT [FK_Associations_DocVersions] FOREIGN KEY([VersionID]) REFERENCES [DocVersions] ([VersionID]) GO ALTER TABLE [Associations] CHECK CONSTRAINT [FK_Associations_DocVersions] GO /****** Object: ForeignKey [FK_Associations_ROFsts] Script Date: 01/06/2012 15:02:52 ******/ ALTER TABLE [Associations] WITH CHECK ADD CONSTRAINT [FK_Associations_ROFsts] FOREIGN KEY([ROFstID]) REFERENCES [ROFsts] ([ROFstID]) GO ALTER TABLE [Associations] CHECK CONSTRAINT [FK_Associations_ROFsts] GO /****** Object: ForeignKey [FK__Folders__ParentID] Script Date: 01/06/2012 15:02:52 ******/ ALTER TABLE [Folders] WITH CHECK ADD CONSTRAINT [FK__Folders__ParentID] FOREIGN KEY([ParentID]) REFERENCES [Folders] ([FolderID]) GO ALTER TABLE [Folders] CHECK CONSTRAINT [FK__Folders__ParentID] GO /****** Object: ForeignKey [FK_Folders_Connections] Script Date: 01/06/2012 15:02:52 ******/ ALTER TABLE [Folders] WITH CHECK ADD CONSTRAINT [FK_Folders_Connections] FOREIGN KEY([DBID]) REFERENCES [Connections] ([DBID]) GO ALTER TABLE [Folders] CHECK CONSTRAINT [FK_Folders_Connections] GO /****** Object: ForeignKey [FK_Folders_Formats] Script Date: 01/06/2012 15:02:52 ******/ ALTER TABLE [Folders] WITH CHECK ADD CONSTRAINT [FK_Folders_Formats] FOREIGN KEY([FormatID]) REFERENCES [Formats] ([FormatID]) GO ALTER TABLE [Folders] CHECK CONSTRAINT [FK_Folders_Formats] GO /****** Object: ForeignKey [FK_DROUsages_Documents] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [DROUsages] WITH CHECK ADD CONSTRAINT [FK_DROUsages_Documents] FOREIGN KEY([DocID]) REFERENCES [Documents] ([DocID]) GO ALTER TABLE [DROUsages] CHECK CONSTRAINT [FK_DROUsages_Documents] GO /****** Object: ForeignKey [FK_DROUsages_RODbs] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [DROUsages] WITH CHECK ADD CONSTRAINT [FK_DROUsages_RODbs] FOREIGN KEY([RODbID]) REFERENCES [RODbs] ([RODbID]) GO ALTER TABLE [DROUsages] CHECK CONSTRAINT [FK_DROUsages_RODbs] GO /****** Object: ForeignKey [FK_Figures_RODbs] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [ROImages] WITH CHECK ADD CONSTRAINT [FK_Figures_RODbs] FOREIGN KEY([RODbID]) REFERENCES [RODbs] ([RODbID]) GO ALTER TABLE [ROImages] CHECK CONSTRAINT [FK_Figures_RODbs] GO /****** Object: ForeignKey [FK_ROFsts_RODbs] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [ROFsts] WITH CHECK ADD CONSTRAINT [FK_ROFsts_RODbs] FOREIGN KEY([RODbID]) REFERENCES [RODbs] ([RODbID]) GO ALTER TABLE [ROFsts] CHECK CONSTRAINT [FK_ROFsts_RODbs] GO /****** Object: ForeignKey [FK_RoUsages_Contents] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [RoUsages] WITH CHECK ADD CONSTRAINT [FK_RoUsages_Contents] FOREIGN KEY([ContentID]) REFERENCES [Contents] ([ContentID]) GO ALTER TABLE [RoUsages] CHECK CONSTRAINT [FK_RoUsages_Contents] GO /****** Object: ForeignKey [FK_ROUsages_RODbs] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [RoUsages] WITH CHECK ADD CONSTRAINT [FK_ROUsages_RODbs] FOREIGN KEY([RODbID]) REFERENCES [RODbs] ([RODbID]) GO ALTER TABLE [RoUsages] CHECK CONSTRAINT [FK_ROUsages_RODbs] GO /****** Object: ForeignKey [FK_Figures_ROFsts] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Figures] WITH CHECK ADD CONSTRAINT [FK_Figures_ROFsts] FOREIGN KEY([ROFstID]) REFERENCES [ROFsts] ([ROFstID]) GO ALTER TABLE [Figures] CHECK CONSTRAINT [FK_Figures_ROFsts] GO /****** Object: ForeignKey [FK_Figures_ROImages] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Figures] WITH CHECK ADD CONSTRAINT [FK_Figures_ROImages] FOREIGN KEY([ImageID]) REFERENCES [ROImages] ([ImageID]) GO ALTER TABLE [Figures] CHECK CONSTRAINT [FK_Figures_ROImages] GO /****** Object: ForeignKey [FK_Entries_Contents] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Entries] WITH CHECK ADD CONSTRAINT [FK_Entries_Contents] FOREIGN KEY([ContentID]) REFERENCES [Contents] ([ContentID]) GO ALTER TABLE [Entries] CHECK CONSTRAINT [FK_Entries_Contents] GO /****** Object: ForeignKey [FK_Entries_Documents] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Entries] WITH CHECK ADD CONSTRAINT [FK_Entries_Documents] FOREIGN KEY([DocID]) REFERENCES [Documents] ([DocID]) GO ALTER TABLE [Entries] CHECK CONSTRAINT [FK_Entries_Documents] GO /****** Object: ForeignKey [FK_Pdfs_Documents] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Pdfs] WITH CHECK ADD CONSTRAINT [FK_Pdfs_Documents] FOREIGN KEY([DocID]) REFERENCES [Documents] ([DocID]) GO ALTER TABLE [Pdfs] CHECK CONSTRAINT [FK_Pdfs_Documents] GO /****** Object: ForeignKey [FK_Memberships_Groups] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Memberships] WITH CHECK ADD CONSTRAINT [FK_Memberships_Groups] FOREIGN KEY([GID]) REFERENCES [Groups] ([GID]) GO ALTER TABLE [Memberships] CHECK CONSTRAINT [FK_Memberships_Groups] GO /****** Object: ForeignKey [FK_Memberships_Users] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Memberships] WITH CHECK ADD CONSTRAINT [FK_Memberships_Users] FOREIGN KEY([UID]) REFERENCES [Users] ([UID]) GO ALTER TABLE [Memberships] CHECK CONSTRAINT [FK_Memberships_Users] GO /****** Object: ForeignKey [FK_Assignments_Folders] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Assignments] WITH CHECK ADD CONSTRAINT [FK_Assignments_Folders] FOREIGN KEY([FolderID]) REFERENCES [Folders] ([FolderID]) GO ALTER TABLE [Assignments] CHECK CONSTRAINT [FK_Assignments_Folders] GO /****** Object: ForeignKey [FK_Assignments_Groups] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Assignments] WITH CHECK ADD CONSTRAINT [FK_Assignments_Groups] FOREIGN KEY([GID]) REFERENCES [Groups] ([GID]) GO ALTER TABLE [Assignments] CHECK CONSTRAINT [FK_Assignments_Groups] GO /****** Object: ForeignKey [FK_Assignments_Roles] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Assignments] WITH CHECK ADD CONSTRAINT [FK_Assignments_Roles] FOREIGN KEY([RID]) REFERENCES [Roles] ([RID]) GO ALTER TABLE [Assignments] CHECK CONSTRAINT [FK_Assignments_Roles] GO /****** Object: ForeignKey [FK_Parts_Contents] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Parts] WITH CHECK ADD CONSTRAINT [FK_Parts_Contents] FOREIGN KEY([ContentID]) REFERENCES [Contents] ([ContentID]) GO ALTER TABLE [Parts] CHECK CONSTRAINT [FK_Parts_Contents] GO /****** Object: ForeignKey [FK_Parts_Items] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Parts] WITH CHECK ADD CONSTRAINT [FK_Parts_Items] FOREIGN KEY([ItemID]) REFERENCES [Items] ([ItemID]) GO ALTER TABLE [Parts] CHECK CONSTRAINT [FK_Parts_Items] GO /****** Object: ForeignKey [FK_DocVersions_Formats] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [DocVersions] WITH CHECK ADD CONSTRAINT [FK_DocVersions_Formats] FOREIGN KEY([FormatID]) REFERENCES [Formats] ([FormatID]) GO ALTER TABLE [DocVersions] CHECK CONSTRAINT [FK_DocVersions_Formats] GO /****** Object: ForeignKey [FK_DocVersions_Items] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [DocVersions] WITH CHECK ADD CONSTRAINT [FK_DocVersions_Items] FOREIGN KEY([ItemID]) REFERENCES [Items] ([ItemID]) GO ALTER TABLE [DocVersions] CHECK CONSTRAINT [FK_DocVersions_Items] GO /****** Object: ForeignKey [FK_Versions_Folders] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [DocVersions] WITH CHECK ADD CONSTRAINT [FK_Versions_Folders] FOREIGN KEY([FolderID]) REFERENCES [Folders] ([FolderID]) GO ALTER TABLE [DocVersions] CHECK CONSTRAINT [FK_Versions_Folders] GO /****** Object: ForeignKey [FK_TransitionsFromID_Contents] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Transitions] WITH CHECK ADD CONSTRAINT [FK_TransitionsFromID_Contents] FOREIGN KEY([FromID]) REFERENCES [Contents] ([ContentID]) GO ALTER TABLE [Transitions] CHECK CONSTRAINT [FK_TransitionsFromID_Contents] GO /****** Object: ForeignKey [FK_TransitionsRangeId_Items] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Transitions] WITH CHECK ADD CONSTRAINT [FK_TransitionsRangeId_Items] FOREIGN KEY([RangeID]) REFERENCES [Items] ([ItemID]) GO ALTER TABLE [Transitions] CHECK CONSTRAINT [FK_TransitionsRangeId_Items] GO /****** Object: ForeignKey [FK_TransitionsToId_Items] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Transitions] WITH CHECK ADD CONSTRAINT [FK_TransitionsToId_Items] FOREIGN KEY([ToID]) REFERENCES [Items] ([ItemID]) GO ALTER TABLE [Transitions] CHECK CONSTRAINT [FK_TransitionsToId_Items] GO /****** Object: ForeignKey [FK_Annotations_AnnotationTypes] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Annotations] WITH CHECK ADD CONSTRAINT [FK_Annotations_AnnotationTypes] FOREIGN KEY([TypeID]) REFERENCES [AnnotationTypes] ([TypeID]) GO ALTER TABLE [Annotations] CHECK CONSTRAINT [FK_Annotations_AnnotationTypes] GO /****** Object: ForeignKey [FK_Annotations_Items] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Annotations] WITH CHECK ADD CONSTRAINT [FK_Annotations_Items] FOREIGN KEY([ItemID]) REFERENCES [Items] ([ItemID]) GO ALTER TABLE [Annotations] CHECK CONSTRAINT [FK_Annotations_Items] GO /****** Object: ForeignKey [FK_Contents_Formats] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Contents] WITH CHECK ADD CONSTRAINT [FK_Contents_Formats] FOREIGN KEY([FormatID]) REFERENCES [Formats] ([FormatID]) GO ALTER TABLE [Contents] CHECK CONSTRAINT [FK_Contents_Formats] GO /****** Object: ForeignKey [FK_Items_Contents] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Items] WITH CHECK ADD CONSTRAINT [FK_Items_Contents] FOREIGN KEY([ContentID]) REFERENCES [Contents] ([ContentID]) GO ALTER TABLE [Items] CHECK CONSTRAINT [FK_Items_Contents] GO /****** Object: ForeignKey [FK_Items_Items] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Items] WITH CHECK ADD CONSTRAINT [FK_Items_Items] FOREIGN KEY([PreviousID]) REFERENCES [Items] ([ItemID]) GO ALTER TABLE [Items] CHECK CONSTRAINT [FK_Items_Items] GO /****** Object: ForeignKey [FK_Details_Contents] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Details] WITH CHECK ADD CONSTRAINT [FK_Details_Contents] FOREIGN KEY([ContentID]) REFERENCES [Contents] ([ContentID]) GO ALTER TABLE [Details] CHECK CONSTRAINT [FK_Details_Contents] GO /****** Object: ForeignKey [FK_ZContents_Contents] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [ZContents] WITH CHECK ADD CONSTRAINT [FK_ZContents_Contents] FOREIGN KEY([ContentID]) REFERENCES [Contents] ([ContentID]) GO ALTER TABLE [ZContents] CHECK CONSTRAINT [FK_ZContents_Contents] GO /****** Object: ForeignKey [FK_Grids_Contents] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Grids] WITH CHECK ADD CONSTRAINT [FK_Grids_Contents] FOREIGN KEY([ContentID]) REFERENCES [Contents] ([ContentID]) GO ALTER TABLE [Grids] CHECK CONSTRAINT [FK_Grids_Contents] GO /****** Object: ForeignKey [FK_Images_Contents] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Images] WITH CHECK ADD CONSTRAINT [FK_Images_Contents] FOREIGN KEY([ContentID]) REFERENCES [Contents] ([ContentID]) GO ALTER TABLE [Images] CHECK CONSTRAINT [FK_Images_Contents] GO /****** Object: ForeignKey [FK_ZTransitions_Transitions] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [ZTransitions] WITH CHECK ADD CONSTRAINT [FK_ZTransitions_Transitions] FOREIGN KEY([TransitionID]) REFERENCES [Transitions] ([TransitionID]) GO ALTER TABLE [ZTransitions] CHECK CONSTRAINT [FK_ZTransitions_Transitions] GO /****** Object: ForeignKey [FK_Permissions_Roles] Script Date: 01/06/2012 15:02:53 ******/ ALTER TABLE [Permissions] WITH CHECK ADD CONSTRAINT [FK_Permissions_Roles] FOREIGN KEY([RID]) REFERENCES [Roles] ([RID]) GO ALTER TABLE [Permissions] CHECK CONSTRAINT [FK_Permissions_Roles] GO INSERT INTO [Connections] ([Name]) VALUES ('Bozo') INSERT INTO [Formats] ([Name],[Data]) VALUES ('Bozo',cast('' as xml)) INSERT INTO [Folders] ([Name],[ShortName],[ManualOrder]) VALUES ('Bozo','Bozo',1) INSERT INTO [DocVersions] ([FolderID],[Name]) VALUES (1,'Bozo') INSERT INTO [Contents]([Number]) VALUES('Bozo') INSERT INTO [Items] ([ContentID]) VALUES (1) INSERT INTO [RODbs] ([ROName],[FolderPath],[DBConnectionString]) VALUES ('Bozo','Bozo','Bozo') INSERT INTO [ROFsts] ([RODbID],[ROLookup]) VALUES(1,Cast('Bozo' as varbinary)) Insert Into [Transitions] ([FromID],[ToID],[RangeID]) VALUES (1,1,1) Insert Into [AnnotationTypes] ([Name]) VALUES ('Bozo') Insert Into [Annotations] ([ItemID],[TypeID]) VALUES (1,1) Insert Into [Groups] ([GroupName]) VALUES ('Bozo') Insert Into [Details] ([ContentID],[ItemType],[Text]) VALUES (1,1,'Bozo') Insert Into [Roles] ([Name],[Title]) VALUES ('Bozo','Bozo') Insert Into [Permissions] ([RID],[PermLevel],[VersionType],[PermValue]) VALUES (1,1,1,1) Insert Into [Applicabilities] ([Name]) VALUES ('Bozo') Insert Into [Associations] ([VersionID],[ROFstID]) VALUES (1,1) INSERT INTO [Documents] ([LibTitle]) VALUES ('Bozo') Insert Into [DROUsages] ([DocID],[ROID],[RODbID]) VALUES (1,'Bozo',1) Insert Into [ROImages] ([RODbID],[FileName],[Content]) VALUES (1,'Bozo',cast ('Bozo' as varbinary)) Insert Into [RoUsages] ([ContentID],[ROID],[RODbID]) VALUES (1,1,1) Insert Into [Figures] ([ROFstID],[ImageID]) VALUES (1,1) INSERT INTO [Users] ([UserID]) VALUES ('Bozo') Insert Into [Memberships] ([UID],[GID]) VALUES (1,1) Insert Into [Assignments] ([GID],[RID],[FolderID]) VALUES (1,1,1) GO sp_changedbowner sa GO USE MASTER GO