Commit 1613efdf authored by dwentzel's avatar dwentzel
Browse files

added DatabaseBuildProcess

parent 81b1f8fb
--2Tables
include if not
script create
script extended props
script owner
then run alter_fixerfortables.sql
--5functions
script cretae
script extended props
script owner
--6views
same
--7procs
same
--
2triggers
create
extended props
owner
triggers
--3Constraints
run the following and save to a file under 3Constraints called "all_primary_keys.sql"
-----------------------
-----------------------
--build scripts for primary keys
set nocount on
declare @tbIdxInfo TABLE
(
IndexName varchar(1000) NOT NULL,
StatusCode int,
IsPrimaryKey char(1),
IsClustered char(1),
IsUnique char(1),
IndexKeys varchar(4000)
)
declare @pkname varchar(2000)
,@tblname varchar(2000)
,@schname varchar(2000)
,@exec_str varchar(max)
,@key varchar(2000)
,@clus varchar(1)
declare pk cursor for
select so.name, object_name(so.parent_object_id), schema_name(so.schema_id)
from sys.objects so
where so.type = 'PK'
order by object_name(so.parent_object_id);
open pk
fetch next from pk into @pkname, @tblname,@schname
while @@fetch_status = 0
begin
delete from @tbIdxInfo
INSERT INTO @tbIdxInfo SELECT * FROM dba_helpindex(@tblname, @schname)
select @key = IndexKeys, @clus = IsClustered FROM @tbIdxInfo WHERE IsPrimaryKey = 'Y'
select @exec_str = '-------------------------------------------------' + char(10) + char(13)
select @exec_str = @exec_str + '--Table.Index: ' +@tblname + '.' + @pkname + char(10) + char(13)
select @exec_str = @exec_str + 'EXEC DBA_CreatePrimaryKey ' + char(10) + char(13)
select @exec_str = @exec_str + ' @pvcTableName = ''' + @tblname + '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@pvcSchemaname = ''' + @schname + '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@pvcPrimaryKeyName = ''' + @pkname+ '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@pvcIndexKey = ''' + @key + '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@pvcIndexIsClustered = ''' + @clus + '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@FileGroup = ''' + CASE @clus WHEN 'Y' THEN 'PRIMARY' ELSE 'IDX' END + '''' + char(10) + char(13)
select @exec_str = @exec_str + 'GO'
select @exec_str
fetch next from pk into @pkname, @tblname,@schname
end
close pk
deallocate pk
go
set nocount off
go
--------------------------
--------------------------
then run pk_fixer.vbs
then run pk_fixer2.vbs
then run pk_fixer3.vbs
--3Defaults
run the following and save to a file under 3Defaults
search for '('00000000-0000-0000-0000-000000000000')' and replace with
'(''00000000-0000-0000-0000-000000000000'')'
---------------------------------------------------------------------
set nocount on
SELECT
'EXEC DBA_CreateDefaultConstraint @pvcTableName = ''' + convert(varchar(4000),object_name(dc.parent_object_id)) + ''',' + char(10) + char(13) +
'@pvcSchemaName = ''' + convert(varchar(4000),schema_name(dc.schema_id)) + ''',' + char(10) + char(13) +
'@pvcColumnName = ''' + convert(varchar(4000),c.name) + ''',' + char(10) + char(13) +
'@pvcDefaultValue = ''' +
case dc.definition
when '(''12/31/9999'')' THEN '12/31/9999'
when '(''00000000-0000-0000-0000-000000000000'')' THEN '(''00000000-0000-0000-0000-000000000000'')'
else convert(varchar(4000),dc.definition)
end
+ ''',' + char(10) + char(13) +
'@pvcConstraintName = ''' + convert(varchar(4000),dc.name) + '''' + char(10) + char(13) +
'GO' + char(10) + char(13)
FROM sys.default_constraints dc
JOIN sys.columns c ON dc.parent_object_id = c.object_id AND dc.parent_column_id = c.column_id
order by object_name(dc.parent_object_id)
set nocount off
-------------------------------------------
--3ForeignKeys
run the following and save to a file under 3ForeignKeys called all_fks.sql
replace NO_ACTION with NO ACTION
delete constraint named FK_EmployeeTimeCardDetail_GLAccount1 in EmployeeTimeCardDetail
in EmployeeTimeCardOverride , search for PayrollElementID, replace with other col
same in PayrollCheckEntityElement.sql
delete constraint named FK_PurchaseOrderHeader_AccountingCompany1 from PurchaseOrderHeader.sql
---------------------------------------------------------
-----------------------
--build scripts for foreign keys
set nocount on
declare
@parent_object_id int
,@pkkey varchar(1000)
,@fkkey varchar(1000)
,@schemaid int
,@constname varchar(1000)
,@reftablename varchar(1000)
,@fkname varchar(2000)
,@tblname varchar(2000)
,@schname varchar(2000)
,@exec_str varchar(max)
,@key varchar(2000)
,@clus varchar(1)
,@delete_referential_action_desc varchar(100)
,@update_referential_action_desc varchar(100)
,@holding_object_name varchar(100)
select @holding_object_name = ''
declare fk cursor for
select sfk.parent_object_id
,sfk.schema_id
,sfk.name
,object_name(sfk.referenced_object_id)
,delete_referential_action_desc
,update_referential_action_desc
from sys.foreign_keys sfk
order by object_name(sfk.parent_object_id)
open fk
fetch next from fk into @parent_object_id, @schemaid,@constname, @reftablename ,@delete_referential_action_desc ,@update_referential_action_desc
while @@fetch_status = 0
begin
--do file splitter stuff up front if needed
if object_name(@parent_object_id) <> @holding_object_name
BEGIN
SELECT @exec_str = '--NextObject: ' + object_name(@parent_object_id) + char(10) + char(13)
select @exec_str
select @holding_object_name = object_name(@parent_object_id)
END
select @pkkey = PKCols from dba_helpfk (object_name(@parent_object_id),schema_name( @schemaid)) where ForeignKeyName = @constname
select @fkkey = FKCols from dba_helpfk (object_name(@parent_object_id),schema_name( @schemaid)) where ForeignKeyName = @constname
select @exec_str = '-------------------------------------------------' + char(10) + char(13)
select @exec_str = @exec_str + 'EXEC DBA_CreateForeignKey ' + char(10) + char(13)
select @exec_str = @exec_str + ' @pvcTableName = ''' + object_name(@parent_object_id) + '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@pvcSchemaName = ''' + schema_name( @schemaid) + '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@pvcColumnName = ''' + @fkkey + '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@pvcConstraintName = ''' + @constname + '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@pvcParentTableName = ''' + @reftablename + '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@pvcParentSchemaName = ''' + schema_name( @schemaid) + '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@pvcParentKey = ''' + @pkkey + '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@pvcDeleteAction = ''' + @delete_referential_action_desc + '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@pvcUpdateAction = ''' + @update_referential_action_desc + '''' + char(10) + char(13)
select @exec_str = @exec_str + 'GO'
select @exec_str
fetch next from fk into @parent_object_id, @schemaid,@constname, @reftablename ,@delete_referential_action_desc ,@update_referential_action_desc
end
close fk
deallocate fk
go
set nocount off
go
--------------------------
then fk_fixer
indexes
run the following and save to 4Indexes as all_indexes.sql
then run idx_fixer.vbs
then arrevenuetype.sql delete IX_ARRevenueType
codedisplay.sql delete IX_CodeDef_Language_UNQ
codexcodegroup.sql
tblLocks.sql add []
and tblTakeOffCostItems
-------------------------------------------------------------------------------------
--------------------------------------------------------------------------------
set nocount on
declare @tbIndexInfo TABLE
(
IndexName varchar(1000) NOT NULL,
StatusCode int,
IsPrimaryKey char(1),
IsClustered char(1),
IsUnique char(1),
IndexKeys varchar(4000)
)
declare @IndexName varchar(2000)
,@IsClustered varchar(1)
,@IsUnique varchar(1)
,@IndexKeys varchar(2000)
,@exec_str varchar(max)
declare @schema_name varchar(2000)
,@table_name varchar(2000)
declare idx cursor for
select
schema_name(st.schema_id)
,st.name as table_name
from sys.tables st
order by schema_name(st.schema_id) , st.name;
open idx
fetch next from idx into @schema_name, @table_name
while @@fetch_status = 0
begin
delete from @tbIndexInfo
INSERT INTO @tbIndexInfo SELECT * FROM dba_helpindex(@table_name,@schema_name) WHERE IsPrimaryKey = 'N';
--put the breaks in the file
SELECT @exec_str = '--NEXT TABLE: ' + @table_name + char(10) + char(13)
SELECT @exec_str
--now need an inner cursor
declare inn cursor for
select IndexName
,IsClustered
,IsUnique
,IndexKeys
from @tbIndexInfo
open inn
fetch next from inn INTO @IndexName, @IsClustered, @IsUnique, @IndexKeys
while @@fetch_status = 0
begin
select @exec_str = '------------------------' + char(10) + char(13)
select @exec_str = @exec_str + 'EXEC DBA_CreateIndex ' + char(10) + char(13)
select @exec_str = @exec_str + ' @pvcTableName = ''' + @table_name + '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@pvcSchemaName = ''' + @schema_name + '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@pvcIndexName = ''' + @IndexName + '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@pvcIndexKey = ''' + @indexKeys + '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@pvcIndexIsClustered = ''' + @IsClustered + '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@pvcIndexIsUnique = ''' + @IsUnique + '''' + char(10) + char(13)
select @exec_str = @exec_str + ' ,@FileGroup = ''' + CASE @IsClustered WHEN 'Y' THEN 'PRIMARY' ELSE 'IDX' END + '''' + char(10) + char(13)
select @exec_str = @exec_str + 'GO'
select @exec_str
fetch next from inn INTO @IndexName, @IsClustered, @IsUnique, @IndexKeys
end
close inn
deallocate inn
--end inner cursor
fetch next from idx into @schema_name, @table_name
end
close idx
deallocate idx
go
set nocount off
--------------------------------------------------------------------------------------
run existence checker for functions, views, procs
delete all table scripts for 2Triggers
then triggers existence checker
run order_objects.vbs TWICE (change folders)
change 4642MXW.Report_APCheckStubView.View.sql
MXW.Report_PR_TimeCard_Check_Tax_List.View.sql to 65MXW.Report_PR_TimeCard_Check_Tax_List.View.sql
in views rename 42 to 47
copy tblWBSClarification.txt to 3ForeignKeys...ensure no new changes.
Now script data...GOTO script data
----------------------------------------------------------------------------------------------------
Scriptdata:
script differences using sql data compare to synchronization.sql to 8SystemData
remove alters from the top and bottom of the script
data_splitfiles.vbs
save tbldata, reportdefinition, codexcodegroup to orig files.
data_rerunnable.vbs
tblProperties...fix the set identity_insert off at the bottom
tblTemplates...DECLARE @pv binary(16)
tblData...need a delete
move 6 total Report files and 5 object files to 8ReportData
report_definition to RDL folder
create 00Header.sql and zzFooter.sql from 1PortingObjects
report_splitfiles.vbs
ren codexcodegroup back
data_rerunnable1.vbs (handles codexcodegroup = custom routine)
move all files in 8SystemData to 8ModelData, delete 8SystemData
codedefinition.sql replace ? with - (instead, try saving as unicode)
codedisplay.sql
copy stateprovince.sql from 1PortingObjects...ensure first nothing has changed. this is unicode
backup maxdemodb and copy backups to 99DemoData
run everything and do diffs!!!
--------------------------------------------------------------------------------------------------------
-------------
building databases process
--run 1 6 2 0 6 \\stp\build
--run 1 6 2 0 7 s:\stpqa\mx prod builds this is currently for maxappdb. also backed up to c:\data
have \maxwell_db_install setup to maxappdb for 16207. backed up to zip file
run against a more recent build
----------------------------------------------------------------------------------------------------------------
db list
MaxAppDB_CreateObjectsONLY will only contain objects from Create folder (get latest of 7/14). done and backedup to c:\data
MaxAppDB 16207
MaxDemDB 16207
TEST 16207 using my process, no errors and backedup
' VBScript source code
msgbox "starting script"
Const ForReading = 1, ForWriting = 2, ForAppending = 8
Set fso = CreateObject("Scripting.FileSystemObject")
'procs section
folder = "C:\Documents and Settings\dwentzel\My Documents\personal\HIT\Scripts\2Tables"
Set f = fso.GetFolder(folder)
Set fc = f.Files
'now fix each file
For Each f1 in fc
CurrentFile = f1.name
CurrentExtension = Right(CurrentFile,3)
If UCASE(CurrentExtension) = "SQL" Then
'msgbox CurrentFile
'find the object name
ObjName = mid(CurrentFile,1,instr(5,CurrentFile,".")-1)
'msgbox ObjName
FileToOpen = folder & "\" & CurrentFile
'determine number of lines in file
Set FileToFix = fso.OpenTextFile(FileToOpen, ForReading)
iLineCounter = 0
do while FileToFix.AtEndofStream <> True
LineContents = FileToFix.ReadLine
iLineCounter = iLineCounter + 1
loop
FileToFix.Close
Set FileToFix = Nothing
Linecontents = ""
'new file
NewFileName = replace(CurrentFile,".Table","")
FileToCreate = folder & "\" & NewFileName
Set NewFile = fso.CreateTextFile(FileToCreate,ForWriting)
'add some stuff to the top
NewFile.WriteLine "---------------------------------------------------------------------- "
NewFile.WriteLine "--Whenever adding a column to a table ensure it is added to the CREATE "
NewFile.WriteLine "--and ALTER sections (for net new vs ported databases) "
NewFile.WriteLine "---------------------------------------------------------------------- "
'Open the file again, read it, begin sending output to a new file, but dont output the last two lines
iNewFileLineCounter = 0
Set FileToFix = fso.OpenTextFile(FileToOpen, ForReading)
do while (FileToFix.AtEndofStream <> True) AND (iNewFileLineCounter <= iLineCounter -2)
iNewFileLineCounter = iNewFileLineCounter + 1
LineContents = ""
LineContents = FileToFix.ReadLine
NewFile.WriteLine (LineContents)
loop
FileToFix.Close
Set FileToFix = Nothing
'now add the new "alter text"
NewFile.WriteBlankLines(1)
NewFile.WriteLine "---------------------------------------------------------------------- "
NewFile.WriteLine "-- Alter Statements begin here "
NewFile.WriteLine "-- All SQL MUST be rerunnable "
NewFile.WriteLine "---------------------------------------------------------------------- "
NewFile.WriteLine "ELSE BEGIN "
NewFile.WriteBlankLines(1)
strLine = " Print 'Table " & ObjName & " already exists, performing Alters (if required)...'"
NewFile.WriteLine strLine
NewFile.WriteBlankLines(1)
NewFile.WriteLine "END --ALTERS "
NewFile.WriteLine "GO "
NewFile.WriteBlankLines(1)
NewFile.Close
Set NewFile = Nothing
end if
Next
set fc = nothing
set f = nothing
'now look for all files with .Table in their name...delete them.
Set f = fso.GetFolder(folder)
Set fc = f.Files
'now fix each file
For Each f1 in fc
CurrentFile = f1.name
If instr(1,CurrentFile,".Table.") <> 0 Then
FileToDelete = folder & "\" & CurrentFile
set MyFile = fso.GetFile(FileToDelete)
MyFile.Delete
Set MyFile = Nothing
End if
Next
set fc = nothing
set f = nothing
msgbox "done"
' VBScript source code
msgbox "starting script"
Const ForReading = 1, ForWriting = 2, ForAppending = 8
Set fso = CreateObject("Scripting.FileSystemObject")
folder = "C:\scripts\scripts\maxwell_db_install\8SystemData"
Set f = fso.GetFolder(folder)
Set fc = f.Files
'create a dummy file
Set NewFile = fso.CreateTextFile(folder & "\dummy.txt")
'now fix each file
For Each f1 in fc
CurrentFile = f1.name
CurrentExtension = Right(CurrentFile,3)
If UCASE(CurrentExtension) = UCASE("sql") Then
if NOT (UCASE(CurrentFile) = UCASE("dbo.tblData.sql") OR UCASE(CurrentFile) = UCASE("MXW.CodeXCodeGroup.sql") OR UCASE(CurrentFile) = UCASE("MXW.ReportDefinition.sql")) then
'found a file to process, open it
FileToOpen = folder & "\" & CurrentFile
Set FileToFix = fso.OpenTextFile(FileToOpen, ForReading)
'create a new file with .new as extension
FileNameToCreate = folder & "\" & replace(CurrentFile,".sql",".new")
Set FileToCreate = fso.CreateTextFile (FileNameToCreate)
'mark for first INSERT statement in file
IsFirstInsert = 1
GoCounter = 0
'for each line in FileToFix...
do while FileToFix.AtEndofStream <> True
'read in the line
LineContents = FileToFix.ReadLine
'if line starts INSERT INTO then add the existence check
if left(LineContents,12) = "INSERT INTO " Then
'determine schema and tablename
schma = mid(LineContents,14,3)
tblname = mid(LineContents,20)
tblname = left(tblname,instr(1,tblname,"]")-1)
'get key col
keycol = mid(LineContents,(instr(1,LineContents,"([")+2))
keycol = left(keycol,instr(1,keycol,"]")-1)
'get keycolvalue
strKeycolvalue = cstr(mid(LineContents,(instr(1,LineContents,"VALUES (")+8)))
keycolvalue = left(strKeycolvalue,instr(1,strKeycolvalue,",")-1)
'if not the first insert then add the closing END
if IsFirstInsert = 0 Then
FileToCreate.WriteLine "END"
FileToCreate.WriteLine "ELSE"
FileToCreate.WriteLine "BEGIN"
FileToCreate.WriteLine " --code UPDATE statement HERE when model data is being changed. Example:"
FileToCreate.WriteLine " --UPDATE " & schma & "." & tblname & " SET ... WHERE " & keycol & " = <id>"
FileToCreate.WriteLine " PRINT 'No UPDATE needed.'"
FileToCreate.WriteLine "END"
FileToCreate.WriteLine "-------------------------------------------------------------------------------------------"
end if
FileToCreate.WriteLine "--Table: " & tblname & " ID: " & keycolvalue
FileToCreate.WriteLine "IF NOT EXISTS (SELECT * FROM " & schma & "." & tblname & " WHERE " & keycol & " = " & keycolvalue & ")"
FileToCreate.WriteLine "BEGIN "
FileToCreate.Write " "
'set the marker
IsFirstInsert = 0
'when we hit the 2nd GO in the file then we need another END
elseif left(LineContents,2) = "GO" Then
'increment the counter
GoCounter = GoCounter + 1
If GoCounter = 2 Then
FileToCreate.WriteLine "END"
End if
End if
'now just add the line to the new file
FileToCreate.WriteLine (LineContents)
loop
FileToFix.close
Set FileToFix = Nothing
FileToCreate.close
Set FileToCreate = Nothing
'this is an exception file, no work to do
else
i = 1
end if
end if
Next
set fc = nothing
set f = nothing
'now look for all files with .sql in their name...delete them.
Set f = fso.GetFolder(folder)
Set fc = f.Files
'delete all .sql
For Each f1 in fc
CurrentFile = f1.name
CurrentExtension = Right(CurrentFile,3)
If CurrentExtension = "sql" Then
FileToDelete = folder & "\" & CurrentFile
set MyFile = fso.GetFile(FileToDelete)
MyFile.Delete
Set MyFile = Nothing
End if
Next
set fc = nothing
set f = nothing
'rename all .new to .sql
Set f = fso.GetFolder(folder)
Set fc = f.Files
For Each f1 in fc
CurrentFile = f1.name
CurrentExtension = Right(CurrentFile,3)
If CurrentExtension = "new" Then
FileToRen = folder & "\" & CurrentFile
set MyFile = fso.GetFile(FileToRen)
MyFile.Name = left (CurrentFile