Commit 9ab76abb authored by dwentzel's avatar dwentzel

MD3 upload

parent a8d63a95
/*
--this is a special file in MD3
--this will always run from the context of master and is the FIRST FILE run.
--this will always attempt to create the database you specify, if it does not already exist.
--sometimes this is a desired functionality, and sometimes it isn't. If you don't like this behavior then simply DELETE
the file.
--if you decide to use this file then you will need to modify it to fit the unique requirements of your project (drive layouts,
recovery mode, filegroups, etc)
--You can always build the database yourself, in which case this script does nothing.
DO NOT RENAME THIS FOLDER OR FILE
IF YOU DO YOU NEED TO CHANGE RunMD3.ps1
Note that this will also run as the first (or one of the first) files when MD3 runs, but in the context of the given db you call MD3 for.
So, this script runs twice. You can therefore embed master only logic and db-specific logic here, just check db_name() first
*/
SET NOCOUNT ON
--IF NOT EXISTS (SELECT 1 FROM master..sysdatabases WHERE NAME = 'NETNEW')
--BEGIN
-- PRINT 'Database was not found. Creating...'
-- DECLARE @SQL varchar(4000)
-- SELECT @SQL = 'CREATE DATABASE NETNEW;'
-- PRINT @SQL
-- EXEC(@SQL)
--END
--ELSE
--BEGIN
-- PRINT 'Database exists.'
--END;
GO
/*
Place things in this folder/file that should occur FIRST before an install/upgrade is even attempted.
Examples:
--disabling any triggers
--taking backups
--pausing distribution agents
*/
IF (SCHEMA_ID('MD3') IS NULL)
EXEC('CREATE SCHEMA MD3;');
GO
\ No newline at end of file
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'MD3.f_GetColumnDataType'))
DROP FUNCTION MD3.f_GetColumnDataType
GO
CREATE FUNCTION MD3.f_GetColumnDataType (
@SchemaName SYSNAME
,@TableName SYSNAME
,@ColumnName SYSNAME
)
RETURNS SYSNAME
WITH RETURNS NULL ON NULL INPUT
AS
BEGIN
DECLARE @ColumnDataType SYSNAME
SELECT @ColumnDataType = TYPE_NAME(c.system_type_id)
FROM sys.objects o
JOIN sys.columns c
ON o.object_id = c.object_id
JOIN sys.types t
ON c.system_type_id = t.system_type_id
WHERE o.name = @TableName
AND c.name = @ColumnName
AND o.schema_id = schema_id(@SchemaName)
AND o.type = 'U'
RETURN @ColumnDataType
END
GO
if exists (select * from dbo.sysobjects where id = object_id(N'MD3.f_GetConstraints'))
drop function MD3.f_GetConstraints
GO
CREATE function MD3.f_GetConstraints(
@SchemaName SYSNAME
,@TblName SYSNAME
)
RETURNS @Table TABLE
(
TableName varchar(255) NOT NULL,
SchemaName varchar(255) NOT NULL,
ConstraintName varchar(255) NOT NULL,
ConstraintExpression varchar(max) NOT NULL,
ColumnName varchar(255) NULL,
is_system_named BIT NOT NULL,
is_not_trusted BIT NOT NULL,
ConstraintType varchar(255) NOT NULL
)
AS
BEGIN
DECLARE @FullTblName SYSNAME
SELECT @FullTblName = @SchemaName + '.' + @TblName
INSERT INTO @Table
--column level constraints
SELECT
OBJECT_NAME(parent_object_id) AS TableName,
OBJECT_SCHEMA_NAME(parent_object_id) AS SchemaName,
OBJECT_NAME(cc.object_id) AS ConstraintName,
cc.definition AS ConstraintExpression,
cols.name AS ColumnName,
cc.is_system_named ,
cc.is_not_trusted,
'CHECK' AS ConstraintType
FROM sys.check_constraints(NOLOCK) cc
JOIN sys.columns(NOLOCK) cols
ON cc.parent_column_id = cols.column_id
AND cc.parent_object_id = cols.object_id
WHERE cc.parent_object_id = object_id(@FullTblName)
UNION ALL
--table level constraints
SELECT
OBJECT_NAME(parent_object_id) AS TableName,
OBJECT_SCHEMA_NAME(parent_object_id) AS SchemaName,
OBJECT_NAME(cc.object_id) AS ConstraintName,
cc.definition AS CheckConstraintExpression,
NULL AS ColumnName,
cc.is_system_named ,
cc.is_not_trusted,
'CHECK' AS ConstraintType
FROM sys.check_constraints(NOLOCK) cc
WHERE cc.parent_object_id = object_id(@FullTblName)
AND cc.parent_column_id = 0
UNION ALL
--default constraints
SELECT
OBJECT_NAME(parent_object_id) AS TableName,
OBJECT_SCHEMA_NAME(parent_object_id) AS SchemaName,
OBJECT_NAME(cc.object_id) AS ConstraintName,
cc.definition AS CheckConstraintExpression,
cols.name AS ColumnName,
cc.is_system_named ,
0,
'DEFAULT' AS ConstraintType
FROM sys.default_constraints(NOLOCK) cc
JOIN sys.columns(NOLOCK) cols
ON cc.parent_column_id = cols.column_id
AND cc.parent_object_id = cols.object_id
WHERE cc.parent_object_id = object_id(@FullTblName)
RETURN
END
GO
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'MD3.f_GetForeignKeys'))
DROP FUNCTION MD3.f_GetForeignKeys
GO
CREATE FUNCTION MD3.f_GetForeignKeys
(
@SchemaName SYSNAME
,@TableName SYSNAME
)
RETURNS @FK TABLE
(
ForeignKeyName SYSNAME NOT NULL,
SchemaName SYSNAME NOT NULL,
TableName SYSNAME NOT NULL,
KeyColumns VARCHAR(MAX)NOT NULL,
ParentSchemaName SYSNAME NOT NULL,
ParentTableName SYSNAME NOT NULL,
ParentKeyColumns VARCHAR(MAX)NOT NULL,
IsDisabled BIT NOT NULL,
IsNotTrusted BIT NOT NULL,
IsNotForReplication BIT NOT NULL,
IsDeleteCascade BIT NOT NULL,
IsUpdateCascade BIT NOT NULL
)
AS
BEGIN
DECLARE @FullName NVARCHAR(260)
SET @FullName = @SchemaName + '.' + @TableName
INSERT INTO @FK
SELECT fk.name,OBJECT_SCHEMA_NAME(fk.parent_object_id),
OBJECT_NAME(fk.parent_object_id),
REVERSE(SUBSTRING(REVERSE((
SELECT cp.name + ','
FROM
sys.foreign_key_columns fkc
INNER JOIN sys.columns cp
ON fkc.parent_object_id = cp.object_id
AND fkc.parent_column_id = cp.column_id
WHERE fkc.constraint_object_id = fk.object_id
FOR XML PATH('')
)), 2, 8000)) AS FKColumns,
OBJECT_SCHEMA_NAME(fk.referenced_object_id),
OBJECT_NAME(fk.referenced_object_id),
REVERSE(SUBSTRING(REVERSE((
SELECT cr.name + ','
FROM sys.foreign_key_columns fkc
INNER JOIN sys.columns cr
ON fkc.referenced_object_id = cr.object_id
AND fkc.referenced_column_id = cr.column_id
WHERE fkc.constraint_object_id = fk.object_id
FOR XML PATH('')
)), 2, 8000))AS ReferencedColumns,
fk.is_disabled,
fk.is_not_trusted,
fk.is_not_for_replication,
fk.delete_referential_action,
fk.update_referential_action
FROM sys.foreign_keys fk
WHERE fk.parent_object_id = OBJECT_ID(@FullName)
RETURN
END
GO
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'MD3.f_GetIdxCompressionInfo'))
DROP FUNCTION MD3.f_GetIdxCompressionInfo
GO
--returns filegroup and compression settings for the given index.
CREATE FUNCTION MD3.f_GetIdxCompressionInfo
(
@SchemaName SYSNAME
,@TableName SYSNAME
,@IndexName SYSNAME
)
RETURNS VARCHAR(255)
AS
BEGIN
DECLARE @Compression varchar(255);
SELECT TOP 1 @Compression =
p.data_compression_desc
FROM sys.objects o
INNER JOIN sys.indexes i
ON i.object_id = o.object_id
INNER JOIN sys.partitions p
ON p.object_id = o.object_id
AND i.index_id = p.index_id
INNER JOIN sys.allocation_units au
ON au.container_id = p.hobt_id
INNER JOIN sys.filegroups fg
ON fg.data_space_id = au.data_space_id
WHERE o.type = 'U' AND i.type > 0
AND o.name = @TableName
AND o.schema_id = schema_id(@SchemaName)
AND i.name = @IndexName
ORDER BY p.data_compression_desc, p.partition_number
RETURN @Compression
END
GO
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'MD3.f_GetIdxFileGroupOrPartition'))
DROP FUNCTION MD3.f_GetIdxFileGroupOrPartition
GO
--returns either the filegroup or partition scheme/column for a given index
CREATE FUNCTION MD3.f_GetIdxFileGroupOrPartition
(
@SchemaName SYSNAME,
@TblName SYSNAME,
@IdxName SYSNAME
)
RETURNS VARCHAR(MAX)
AS
BEGIN
DECLARE
@DataSpace VARCHAR(MAX),
@FullName SYSNAME
SELECT
@FullName = @SchemaName + '.' + @TblName
SELECT @DataSpace = CASE sds.type
WHEN 'FG' THEN sds.name
WHEN 'PS' THEN sds.name + '(' + sc.name + ')'
ELSE NULL
END
FROM sys.tables st
JOIN sys.indexes si
ON st.object_id = si.object_id
JOIN sys.index_columns sic
ON st.object_id = sic.object_id
AND si.index_id = sic.index_id
JOIN sys.data_spaces sds
ON si.data_space_id = sds.data_space_id
JOIN sys.columns sc
ON sc.object_id = sic.object_id and sc.column_id = sic.column_id
WHERE st.object_id = OBJECT_ID(@FullName)
AND si.name = @IdxName
AND ( (sds.type = 'FG' AND sic.key_ordinal = 1)
OR (sds.type = 'PS' AND sic.partition_ordinal = 1)
)
RETURN @DataSpace
END
GO
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'MD3.f_GetIdxIncludedColsCSV'))
DROP FUNCTION MD3.f_GetIdxIncludedColsCSV
GO
--returns a CSV list of included columns for the given index
CREATE FUNCTION MD3.f_GetIdxIncludedColsCSV
(
@SchemaName SYSNAME,
@TblName SYSNAME,
@IdxName SYSNAME
)
RETURNS VARCHAR(MAX)
AS
BEGIN
DECLARE
@ColList VARCHAR(MAX),
@FullName SYSNAME
SELECT @FullName = @SchemaName + '.' + @TblName
SELECT @ColList =
(SELECT CASE
WHEN sic.index_column_id = (SELECT MIN(index_column_id)
FROM sys.index_columns sic2
WHERE sic2.object_id = sic.object_id
AND sic2.index_id = sic.index_id
AND key_ordinal=0) THEN ''
WHEN sic.index_column_id > (SELECT MIN(index_column_id)
FROM sys.index_columns sic2
WHERE sic2.object_id = sic.object_id
AND sic2.index_id = sic.index_id
AND key_ordinal=0) THEN ','
WHEN sic.key_ordinal > 1 THEN ','
ELSE ''
END +
sc.name +
CASE
WHEN sic.is_descending_key = 1 THEN '(-)'
ELSE ''
END
FROM sys.tables st
JOIN sys.indexes si
ON st.object_id = si.object_id
JOIN sys.index_columns sic
ON st.object_id = sic.object_id
AND si.index_id = sic.index_id
JOIN sys.columns sc
ON st.object_id = sc.object_id
AND sic.column_id = sc.column_id
WHERE st.object_id = OBJECT_ID(@FullName)
AND si.name = @IdxName
AND sic.is_included_column = 1
ORDER BY
sic.index_column_id
FOR XML PATH(''))
RETURN @ColList
END
GO
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'MD3.f_GetIdxKeysCSV'))
DROP FUNCTION MD3.f_GetIdxKeysCSV
GO
--returns a CSV list of keys for the given index
CREATE FUNCTION MD3.f_GetIdxKeysCSV
(
@SchemaName SYSNAME,
@TblName SYSNAME,
@IdxName SYSNAME
)
RETURNS VARCHAR(MAX)
AS
BEGIN
DECLARE
@ColList VARCHAR(MAX),
@FullName SYSNAME
SELECT @FullName = @SchemaName + '.' + @TblName
SELECT @ColList =
(SELECT CASE
WHEN sic.key_ordinal > 1 THEN ','
ELSE ''
END +
sc.name +
CASE
WHEN sic.is_descending_key = 1 THEN '(-)'
ELSE ''
END
FROM sys.tables st
JOIN sys.indexes si
ON st.object_id = si.object_id
JOIN sys.index_columns sic
ON st.object_id = sic.object_id
AND si.index_id = sic.index_id
JOIN sys.columns sc
ON st.object_id = sc.object_id
AND sic.column_id = sc.column_id
WHERE st.object_id = OBJECT_ID(@FullName)
AND si.name = @IdxName
ORDER BY sic.key_ordinal
FOR XML PATH(''))
RETURN @ColList
END
GO
if exists (select * from dbo.sysobjects where id = object_id(N'MD3.[f_GetIndexes]'))
drop function MD3.f_GetIndexes
GO
--Returns a table with information about the indexes on the given table.
CREATE FUNCTION MD3.f_GetIndexes(
@SchemaName SYSNAME
,@TblName SYSNAME
)
RETURNS @IndexList TABLE
(
ObjectId INT NOT NULL,
IndexId INT NOT NULL,
IndexName SYSNAME NOT NULL,
IsPrimaryKey BIT NOT NULL,
IsClustered BIT NOT NULL,
IsUnique BIT NOT NULL,
IndexKeys VARCHAR(MAX) NOT NULL,
IncludedColumns VARCHAR(MAX) NULL,
FGorPartitionScheme VARCHAR(MAX) NULL,
IsPadded BIT NOT NULL,
IdxFillFactor int NOT NULL,
CompressionSetting varchar(255) NULL
)
AS
BEGIN
DECLARE @FullName SYSNAME
SELECT @FullName = @SchemaName + '.' + @TblName
INSERT INTO @IndexList
(ObjectId, IndexId,IndexName, IsPrimaryKey, IsClustered, IsUnique, IndexKeys, IncludedColumns, FGorPartitionScheme,IsPadded,IdxFillFactor,CompressionSetting)
SELECT
si.[object_id] AS ObjectId,
si.index_id AS IndexId,
si.name AS IndexName,
si.is_primary_key AS IsPrimaryKey,
CASE WHEN si.type = 1 THEN CAST(1 AS BIT)
ELSE CAST(0 AS BIT)
END AS IsClustered,
si.is_unique AS IsUnique,
MD3.f_GetIdxKeysCSV(@SchemaName,@TblName,si.name) as IndexKeys,
MD3.f_GetIdxIncludedColsCSV(@SchemaName,@TblName,si.name) as IncludedColumns,
MD3.f_GetIdxFileGroupOrPartition(@SchemaName,@TblName,si.name) as DataSpace,
si.is_padded AS IsPadded,
(CASE WHEN si.fill_factor = 0 THEN 100
ELSE si.fill_factor END) AS IdxFillFactor,
MD3.f_GetIdxCompressionInfo (@SchemaName,@TblName,si.name)
FROM sys.indexes si
WHERE si.object_id = OBJECT_ID(@FullName)
AND si.type > 0
AND si.type_desc <> 'XML'
ORDER BY si.index_id
RETURN
END
GO
\ No newline at end of file
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'MD3.f_RemoveBrackets'))
BEGIN
DROP FUNCTION MD3.f_RemoveBrackets;
END
GO
CREATE FUNCTION MD3.f_RemoveBrackets (@Value NVARCHAR(MAX))
RETURNS NVARCHAR(MAX)
WITH RETURNS NULL ON NULL INPUT
AS
BEGIN
SELECT @Value = REPLACE(@Value,'[','')
SELECT @Value = REPLACE(@Value,']','')
RETURN @Value
END
GO
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'MD3.f_SchemaExists'))
DROP FUNCTION MD3.f_SchemaExists
GO
-- Function to determine if the given schema exists.
CREATE FUNCTION MD3.f_SchemaExists (@SchemaName SYSNAME)
RETURNS BIT
WITH RETURNS NULL ON NULL INPUT
AS
BEGIN
-- Remove any brackets.
SELECT @SchemaName=REPLACE(@SchemaName,'[','')
SELECT @SchemaName=REPLACE(@SchemaName,']','')
-- Check to see if the schema exists.
IF EXISTS
(SELECT * FROM sys.schemas WHERE schema_id = schema_id(@SchemaName))
RETURN 1
ELSE
RETURN 0
RETURN 0
END
GO
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'MD3.f_Split'))
BEGIN
DROP FUNCTION MD3.f_Split;
END
GO
--Returns a table for the given csv string
CREATE FUNCTION MD3.[f_Split] (@csv NVARCHAR(MAX))
RETURNS @tbl TABLE (Number int identity (1,1), Position int ,Value NVARCHAR(MAX) NOT NULL)
AS
BEGIN
IF (@csv IS NULL)
BEGIN
RETURN
END
DECLARE @Position int,
@NextPosition int,
@ValueLen int
SELECT @Position = 0, @NextPosition = 1
WHILE @NextPosition > 0
BEGIN
SELECT @NextPosition = charindex(',', @csv, @Position + 1)
SELECT @ValueLen = CASE WHEN @NextPosition > 0
THEN @NextPosition
ELSE len(@csv) + 1
END - @Position - 1
INSERT @tbl (Value,Position)
VALUES (substring(@csv, @Position + 1, @ValueLen),@Position + 1)
SELECT @Position = @NextPosition
END
RETURN
END
GO
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'MD3.f_TableExists'))
DROP FUNCTION MD3.f_TableExists
GO
-- Function determines if the table exists.
CREATE FUNCTION MD3.f_TableExists (
@SchemaName SYSNAME
,@TableName SYSNAME
)
RETURNS BIT
WITH RETURNS NULL ON NULL INPUT
AS
BEGIN
-- Remove any brackets.
SELECT @SchemaName=REPLACE(@SchemaName,'[','')
SELECT @SchemaName=REPLACE(@SchemaName,']','')
SELECT @TableName=REPLACE(@TableName,'[','')
SELECT @TableName=REPLACE(@TableName,']','')
-- Check to see if the table exists.
IF EXISTS (SELECT * FROM sys.objects WHERE name = @TableName AND schema_id = schema_id(@SchemaName) AND type = 'U')
BEGIN
RETURN 1
END
ELSE
BEGIN
RETURN 0
END;
RETURN 0
END;
GO
IF NOT EXISTS (SELECT 1 FROM sys.objects
WHERE type ='u' AND object_id = OBJECT_ID('MD3.CheckConstraints'))
BEGIN
CREATE TABLE MD3.CheckConstraints
(Id BIGINT IDENTITY(1,1) NOT NULL
,TableName VARCHAR(255) NOT NULL
,SchemaName VARCHAR(255) NOT NULL
,ConstraintName VARCHAR(255) NOT NULL
,ConstraintExpression VARCHAR(4000) NOT NULL
,ColumnName VARCHAR(255) NULL
,AllowNoCheck BIT NOT NULL
,DropConstraint BIT NOT NULL
);
ALTER TABLE MD3.CheckConstraints ADD CONSTRAINT CheckConstraintsPK
PRIMARY KEY CLUSTERED (Id);
END
--drop table MD3.CheckConstraints
IF NOT EXISTS (SELECT 1 FROM sys.objects
WHERE type ='u' AND object_id = OBJECT_ID('MD3.DefaultConstraints'))
BEGIN
CREATE TABLE MD3.DefaultConstraints
(Id BIGINT IDENTITY(1,1) NOT NULL
,TableName VARCHAR(255) NOT NULL
,SchemaName VARCHAR(255) NOT NULL
,ConstraintName VARCHAR(255) NOT NULL
,ConstraintExpression VARCHAR(4000) NOT NULL
,ColumnName VARCHAR(255) NULL
,DropConstraint BIT NOT NULL
);
ALTER TABLE MD3.DefaultConstraints ADD CONSTRAINT DefaultConstraintsPK
PRIMARY KEY CLUSTERED (Id);
END
--drop table MD3.DefaultConstraints
IF NOT EXISTS (SELECT 1 FROM sys.objects
WHERE type ='u' AND object_id = OBJECT_ID('MD3.FKConstraints'))
BEGIN
CREATE TABLE MD3.FKConstraints
(Id BIGINT IDENTITY(1,1) NOT NULL,
ForeignKeyName SYSNAME NOT NULL,
SchemaName SYSNAME NOT NULL,
TableName SYSNAME NOT NULL,
KeyColumns VARCHAR(MAX)NOT NULL,
ParentSchemaName SYSNAME NOT NULL,
ParentTableName SYSNAME NOT NULL,
ParentKeyColumns VARCHAR(MAX)NOT NULL,
IsNotTrusted BIT NOT NULL,
IsDeleteCascade BIT NOT NULL,
IsUpdateCascade BIT NOT NULL,
DropFK BIT NOT NULL
);
ALTER TABLE MD3.FKConstraints ADD CONSTRAINT FKConstraintsPK
PRIMARY KEY CLUSTERED (Id);
END
--drop table MD3.FKConstraints
IF NOT EXISTS (SELECT 1 FROM sys.objects