Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Browse files
Browse the repository at this point in the history
SHIBUI-2510
Added the documentation for upgrading sql server backends
- Loading branch information
Showing
2 changed files
with
155 additions
and
0 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,104 @@ | ||
DECLARE @dropAndCreateConstraintsTable TABLE | ||
( | ||
DropStmt VARCHAR(MAX) | ||
,CreateStmt VARCHAR(MAX) | ||
) | ||
/* Gather information to drop and then recreate the current foreign key constraints */ | ||
INSERT @dropAndCreateConstraintsTable | ||
SELECT DropStmt = 'ALTER TABLE [' + ForeignKeys.ForeignTableSchema | ||
+ '].[' + ForeignKeys.ForeignTableName + '] DROP CONSTRAINT [' | ||
+ ForeignKeys.ForeignKeyName + ']; ' | ||
,CreateStmt = 'ALTER TABLE [' + ForeignKeys.ForeignTableSchema | ||
+ '].[' + ForeignKeys.ForeignTableName | ||
+ '] WITH CHECK ADD CONSTRAINT [' + ForeignKeys.ForeignKeyName | ||
+ '] FOREIGN KEY([' + ForeignKeys.ForeignTableColumn | ||
+ ']) REFERENCES [' + SCHEMA_NAME(sys.objects.schema_id) | ||
+ '].[' + sys.objects.[name] + ']([' + sys.columns.[name] | ||
+ ']); ' | ||
FROM sys.objects | ||
INNER JOIN sys.columns | ||
ON ( sys.columns.[object_id] = sys.objects.[object_id] ) | ||
INNER JOIN ( SELECT sys.foreign_keys.[name] AS ForeignKeyName | ||
,SCHEMA_NAME(sys.objects.schema_id) AS ForeignTableSchema | ||
,sys.objects.[name] AS ForeignTableName | ||
,sys.columns.[name] AS ForeignTableColumn | ||
,sys.foreign_keys.referenced_object_id AS referenced_object_id | ||
,sys.foreign_key_columns.referenced_column_id AS referenced_column_id | ||
FROM sys.foreign_keys | ||
INNER JOIN sys.foreign_key_columns | ||
ON ( sys.foreign_key_columns.constraint_object_id = sys.foreign_keys.[object_id] ) | ||
INNER JOIN sys.objects | ||
ON ( sys.objects.[object_id] = sys.foreign_keys.parent_object_id ) | ||
INNER JOIN sys.columns | ||
ON ( sys.columns.[object_id] = sys.objects.[object_id] ) | ||
AND ( sys.columns.column_id = sys.foreign_key_columns.parent_column_id ) | ||
) ForeignKeys | ||
ON ( ForeignKeys.referenced_object_id = sys.objects.[object_id] ) | ||
AND ( ForeignKeys.referenced_column_id = sys.columns.column_id ) | ||
WHERE ( sys.objects.[type] = 'U' ) | ||
AND ( sys.objects.[name] NOT IN ( 'sysdiagrams' ) ) | ||
|
||
/* SELECT * FROM @dropAndCreateConstraintsTable AS DACCT */ | ||
|
||
DECLARE @DropStatement NVARCHAR(MAX) | ||
DECLARE @RecreateStatement NVARCHAR(MAX) | ||
|
||
/* Drop Constraints */ | ||
DECLARE C1 CURSOR READ_ONLY | ||
FOR | ||
SELECT DropStmt | ||
FROM @dropAndCreateConstraintsTable | ||
OPEN C1 | ||
|
||
FETCH NEXT FROM C1 INTO @DropStatement | ||
|
||
WHILE @@FETCH_STATUS = 0 | ||
BEGIN | ||
PRINT 'Executing ' + @DropStatement | ||
EXECUTE sp_executesql @DropStatement | ||
FETCH NEXT FROM C1 INTO @DropStatement | ||
END | ||
CLOSE C1 | ||
DEALLOCATE C1 | ||
|
||
/* Truncate all tables in the database in the dbo schema */ | ||
DECLARE @DeleteTableStatement NVARCHAR(MAX) | ||
DECLARE C2 CURSOR READ_ONLY | ||
FOR | ||
SELECT 'TRUNCATE TABLE [dbo].[' + TABLE_NAME + ']' | ||
FROM INFORMATION_SCHEMA.TABLES | ||
WHERE TABLE_SCHEMA = 'dbo' | ||
AND TABLE_TYPE = 'BASE TABLE' | ||
/* Change your schema appropriately if you don't want to use dbo */ | ||
OPEN C2 | ||
|
||
FETCH NEXT FROM C2 INTO @DeleteTableStatement | ||
|
||
WHILE @@FETCH_STATUS = 0 | ||
BEGIN | ||
PRINT 'Executing ' + @DeleteTableStatement | ||
EXECUTE sp_executesql @DeleteTableStatement | ||
FETCH NEXT FROM C2 INTO @DeleteTableStatement | ||
END | ||
CLOSE C2 | ||
DEALLOCATE C2 | ||
|
||
/* Recreate foreign key constraints */ | ||
DECLARE C3 CURSOR READ_ONLY | ||
FOR | ||
SELECT CreateStmt | ||
FROM @dropAndCreateConstraintsTable | ||
OPEN C3 | ||
|
||
FETCH NEXT FROM C3 INTO @RecreateStatement | ||
|
||
WHILE @@FETCH_STATUS = 0 | ||
BEGIN | ||
PRINT 'Executing ' + @RecreateStatement | ||
EXECUTE sp_executesql @RecreateStatement | ||
FETCH NEXT FROM C3 INTO @RecreateStatement | ||
END | ||
CLOSE C3 | ||
DEALLOCATE C3 | ||
|
||
GO |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,51 @@ | ||
# Upgrade v1.x.x to v2.x.x for MS SQL SERVER only | ||
The following instruction for migrating the database changes need only be performed for those clients using MS SQL Server | ||
as the backing database for the SHIBUI. Please be sure to make a backup of the existing database before begining. | ||
|
||
## Notes | ||
* Please be sure to make a backup of the existing database before begining. | ||
* For the example below, we reference using a tool called DBeaver - this tool is free for use and can connect to databases to perform various functions - https://dbeaver.com | ||
* DB savy users should use whatever tools they prefer | ||
|
||
## Outline of steps | ||
* Stop v1 Shibui application | ||
* Export shibui database data - the underlying database structure is going to be modified, so a binary export is unlikey to work when restoring the data, we reccomend an export as SQL insert statements | ||
* Remove the single reference from the export to the **hibernate_sequence** table, making note of the current sequence value. | ||
* Drop all tables from the existing database. | ||
* Configure and start Shibui v2.x.x - it will create all the needed tables in their new form as well as a new database sequence named **hibernate_sequence** | ||
* After the application has fully started up, shut down the application. | ||
* Update the new database sequence to start with the old value taken from the old version of the database | ||
* Disable all foreign key constraints in the database | ||
* Truncate all the tables (there will be a few entries from the new database setup that need to be removed) | ||
* Load the original v1 data | ||
* Re-enable the foreign key constraints | ||
* Re-start v2 SHIBUI | ||
|
||
## Step-by-Step guide using DBeaver | ||
This assumes that you have installed DBeaver, pre-configured the database connections, and tested the connection. The connected user | ||
will need rights to modify the **shibui** database and tables. | ||
|
||
1. Start DBeaver application and connect to the database | ||
2. From the left side UI, navigate to the **tables** section and then HIGHLIGHT/SELECT all the tables | ||
3. Right click on the selected tables and choose the - **EXPORT DATA** option | ||
* From the options choose: Export to SQL Insert statements (click NEXT) | ||
* (click NEXT) Extract settings | ||
* (click NEXT) Format Settings | ||
* Output (determine where you want the output file): Check the option to **Write to single file** (click NEXT) | ||
* (click PROCEED) | ||
4. Edit the result file | ||
* Remove the line like: INSERT INTO hibernate_sequence (next_val) VALUES (56); (your value will likely not be 56 - it will vary based on how much data you have. You will need to record this value for use later). | ||
5. Drop all the tables from the database (there are a number oif different ways to do this, either through the DBeaver interface, or through SQL) | ||
6. Start a clean v2 instance of SHIBUI - you will end up with a new and “mostly” empty db. | ||
7. Once SHIBUI has full started, stop just the SHIBUI application. | ||
8. Reconnect (or refresh) your DBeaver connection to the database. Use DBeaver to create a script for the database and execute : | ||
_**ALTER SEQUENCE hibernate_sequence RESTART WITH 56 INCREMENT by 1;**_ The “restart” value in your statement should match whatever was in the line from step 4 above | ||
9. Copy and paste the contents of the **dropAndCreateConstraints.sql** into dbeaver’s script console and execute it. | ||
10. Copy the OUTPUT of the dropAndCreateConstraints.sql execution to any simple text editor | ||
11. Remove all the **“Executing “** from the start of each line | ||
12. The results should be 3 “blocks” of statements: alter table, truncate, and then another alter table block | ||
13. Copy all of the first block of **alter table** statements into DBeaver and execute them - this will disable the foreign key references | ||
14. Open your exported script file (from step 3) and copy all the inserts to your DBeaver script - run them into the database | ||
15. From the output “drop and create constraints script” (step 10 above) copy only the last block of "alter table" lines | ||
16. Paste them into a DBeaver script and execute them to restore constraints | ||
17. Restart the v2 SHIBUI application |