-
Notifications
You must be signed in to change notification settings - Fork 3
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
Sqitch integration #386
Open
Expressionless-Ball-Thing
wants to merge
5
commits into
main
Choose a base branch
from
sqlitch
base: main
Could not load branches
Branch not found: {{ refName }}
Loading
Could not load tags
Nothing to show
Loading
Are you sure you want to change the base?
Some commits from the old base branch may be removed from the timeline,
and old review comments may become outdated.
Open
Sqitch integration #386
Changes from 4 commits
Commits
Show all changes
5 commits
Select commit
Hold shift + click to select a range
ed98602
Attempted to integrate sqitch into the dockerfiles and ported our sql…
Expressionless-Ball-Thing b8cda7f
Fixed the SQL scripts
Expressionless-Ball-Thing 802281f
Merge branch 'main' into sqlitch
Expressionless-Ball-Thing a04c13a
Attempted reverting some changes
Expressionless-Ball-Thing 2fd9884
Added a README.md for the sqitch folder
Expressionless-Ball-Thing File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
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
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 @@ | ||
FROM sqitch/sqitch:latest |
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,18 @@ | ||
-- Deploy website:01-create_migration_table to pg | ||
|
||
BEGIN; | ||
|
||
-- XXX Add DDLs here. | ||
CREATE TABLE IF NOT EXISTS migrations ( | ||
MigrationID SERIAL PRIMARY KEY, | ||
VersionID INTEGER default 0 | ||
); | ||
|
||
DO LANGUAGE plpgsql $$ | ||
BEGIN | ||
IF NOT EXISTS (SELECT FROM migrations WHERE MigrationID = 1) THEN | ||
INSERT INTO migrations (MigrationID, VersionID) VALUES (1, 0); | ||
END IF; | ||
END $$; | ||
|
||
COMMIT; |
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,12 @@ | ||
-- Deploy website:02-create_frontend_table to pg | ||
-- requires: 01-create_migration_table | ||
|
||
BEGIN; | ||
|
||
CREATE TABLE IF NOT EXISTS frontend ( | ||
FrontendID SERIAL PRIMARY KEY, | ||
FrontendURL VARCHAR(100) | ||
); | ||
-- XXX Add DDLs here. | ||
|
||
COMMIT; |
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,19 @@ | ||
-- Deploy website:03-create_groups_table to pg | ||
-- requires: 02-create_frontend_table | ||
|
||
BEGIN; | ||
|
||
-- XXX Add DDLs here. | ||
CREATE EXTENSION IF NOT EXISTS hstore; | ||
SET timezone = 'Australia/Sydney'; | ||
|
||
DROP TYPE IF EXISTS permissions_enum CASCADE; | ||
CREATE TYPE permissions_enum as ENUM ('read', 'write', 'delete'); | ||
|
||
CREATE TABLE IF NOT EXISTS groups ( | ||
UID SERIAL PRIMARY KEY, | ||
Name VARCHAR(50) NOT NULL, | ||
Permission permissions_enum UNIQUE NOT NULL | ||
); | ||
|
||
COMMIT; |
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,38 @@ | ||
-- Deploy website:04-create_person_table to pg | ||
-- requires: 03-create_groups_table | ||
|
||
BEGIN; | ||
|
||
-- XXX Add DDLs here. | ||
CREATE TABLE IF NOT EXISTS person ( | ||
UID SERIAL PRIMARY KEY, | ||
Email VARCHAR(50) UNIQUE NOT NULL, | ||
First_name VARCHAR(50) NOT NULL, | ||
Password CHAR(64) NOT NULL, | ||
|
||
isOfGroup INT, | ||
frontendid INT, | ||
|
||
CONSTRAINT fk_AccessLevel FOREIGN KEY (isOfGroup) | ||
REFERENCES groups(UID), | ||
|
||
CONSTRAINT fk_AccessFrontend FOREIGN KEY (frontendid) | ||
REFERENCES frontend(FrontendID), | ||
|
||
/* non duplicate email and password constraints */ | ||
CONSTRAINT no_dupes UNIQUE (Email, Password) | ||
); | ||
|
||
/* create user function plpgsql */ | ||
CREATE OR REPLACE FUNCTION create_normal_user (email VARCHAR, name VARCHAR, password VARCHAR, frontendID INT) RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
DECLARE | ||
BEGIN | ||
INSERT INTO person (Email, First_name, Password, isOfGroup, frontendID) | ||
VALUES (email, name, encode(sha256(password::BYTEA), 'hex'), 2, 1); | ||
END $$; | ||
|
||
|
||
|
||
COMMIT; |
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,93 @@ | ||
-- Deploy website:05-create_filesystem_table to pg | ||
-- requires: 04-create_person_table | ||
|
||
BEGIN; | ||
|
||
-- XXX Add DDLs here. | ||
SET timezone = 'Australia/Sydney'; | ||
CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; | ||
|
||
/* MetaData */ | ||
CREATE TABLE IF NOT EXISTS metadata ( | ||
MetadataID uuid PRIMARY KEY DEFAULT uuid_generate_v4(), | ||
CreatedAt TIMESTAMP NOT NULL DEFAULT NOW() | ||
); | ||
|
||
/** | ||
The filesystem table models all file heirachies in our system | ||
**/ | ||
CREATE TABLE IF NOT EXISTS filesystem ( | ||
EntityID uuid PRIMARY KEY DEFAULT uuid_generate_v4(), | ||
LogicalName VARCHAR(50) NOT NULL, | ||
|
||
IsDocument BOOLEAN DEFAULT false, | ||
IsPublished BOOLEAN DEFAULT false, | ||
CreatedAt TIMESTAMP NOT NULL DEFAULT NOW(), | ||
|
||
/* MetaData */ | ||
-- MetadataID uuid NOT NULL, | ||
|
||
OwnedBy INT, | ||
/* Pain */ | ||
Parent uuid REFERENCES filesystem(EntityID) DEFAULT NULL, | ||
|
||
/* FK Constraint */ | ||
CONSTRAINT fk_owner FOREIGN KEY (OwnedBy) | ||
REFERENCES groups(UID), | ||
|
||
-- CONSTRAINT fk_meta FOREIGN KEY (MetadataID) REFERENCES metadata(MetadataID), | ||
|
||
/* Unique name constraint: there should not exist an entity of the same type with the | ||
same parent and logical name. */ | ||
CONSTRAINT unique_name UNIQUE (Parent, LogicalName, IsDocument) | ||
); | ||
|
||
/* Utility procedure :) */ | ||
CREATE OR REPLACE FUNCTION new_entity (parentP uuid, logicalNameP VARCHAR, ownedByP INT, isDocumentP BOOLEAN DEFAULT false) RETURNS uuid | ||
LANGUAGE plpgsql | ||
AS $$ | ||
DECLARE | ||
newEntityID filesystem.EntityID%type; | ||
parentIsDocument BOOLEAN := (SELECT IsDocument FROM filesystem WHERE EntityID = parentP LIMIT 1); | ||
BEGIN | ||
IF parentIsDocument THEN | ||
/* We shouldnt be delcaring that a document is our parent */ | ||
RAISE EXCEPTION SQLSTATE '90001' USING MESSAGE = 'cannot make parent a document'; | ||
END If; | ||
WITH newEntity AS ( | ||
INSERT INTO filesystem (LogicalName, IsDocument, OwnedBy, Parent) | ||
VALUES (logicalNameP, isDocumentP, ownedByP, parentP) | ||
RETURNING EntityID | ||
) | ||
|
||
SELECT newEntity.EntityID INTO newEntityID FROM newEntity; | ||
RETURN newEntityID; | ||
END $$; | ||
|
||
/* Another utility procedure */ | ||
CREATE OR REPLACE FUNCTION delete_entity (entityIDP uuid) RETURNS void | ||
LANGUAGE plpgsql | ||
AS $$ | ||
DECLARE | ||
numKids INT := (SELECT COUNT(EntityID) FROM filesystem WHERE Parent = entityIDP); | ||
isRoot BOOLEAN := ((SELECT Parent FROM filesystem WHERE EntityID = entityIDP) IS NULL); | ||
BEGIN | ||
/* If this is a directory and has kids raise an error */ | ||
IF numKids > 0 | ||
THEN | ||
/* entity has children (please dont orphan them O_O ) */ | ||
RAISE EXCEPTION SQLSTATE '90001' USING MESSAGE = 'entity has children (please dont orphan them O_O )'; | ||
END IF; | ||
|
||
IF isRoot THEN | ||
/* stop trying to delete root >:( */ | ||
RAISE EXCEPTION SQLSTATE '90001' USING MESSAGE = 'stop trying to delete root >:('; | ||
END IF; | ||
|
||
DELETE FROM filesystem WHERE EntityID = entityIDP; | ||
END $$; | ||
|
||
|
||
|
||
|
||
COMMIT; |
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,68 @@ | ||
-- Deploy website:06-create_dummy_data to pg | ||
-- requires: 05-create_filesystem_table | ||
|
||
BEGIN; | ||
|
||
-- XXX Add DDLs here. | ||
SET timezone = 'Australia/Sydney'; | ||
|
||
/* Create default groups */ | ||
INSERT INTO groups (Name, Permission) VALUES ('admin', 'delete'); | ||
INSERT INTO groups (name, Permission) VALUES ('user', 'write'); | ||
|
||
/* Setup FS table and modify constraints */ | ||
/* Insert root directory and then add our constraints */ | ||
DO $$ | ||
DECLARE | ||
randomGroup groups.UID%type; | ||
rootID filesystem.EntityID%type; | ||
BEGIN | ||
SELECT groups.UID INTO randomGroup FROM groups WHERE Name = 'admin'::VARCHAR; | ||
/* Insert the root directory */ | ||
INSERT INTO filesystem (EntityID, LogicalName, OwnedBy) | ||
VALUES (uuid_nil(), 'root', randomGroup); | ||
SELECT filesystem.EntityID INTO rootID FROM filesystem WHERE LogicalName = 'root'::VARCHAR; | ||
/* Set parent to uuid_nil() because postgres driver has issue supporting NULL values */ | ||
UPDATE filesystem SET Parent = uuid_nil() WHERE EntityID = rootID; | ||
|
||
/* insert "has parent" constraint*/ | ||
EXECUTE 'ALTER TABLE filesystem | ||
ADD CONSTRAINT has_parent CHECK (Parent != NULL)'; | ||
END $$; | ||
|
||
|
||
|
||
/* create a dummy frontend */ | ||
INSERT INTO frontend (FrontendURL) VALUES ('http://localhost:8080'::VARCHAR); | ||
|
||
/* Insert dummy data */ | ||
DO $$ | ||
DECLARE | ||
rootID filesystem.EntityID%type; | ||
newEntity filesystem.EntityID%type; | ||
wasPopping filesystem.EntityID%type; | ||
oldEntity filesystem.EntityID%type; | ||
BEGIN | ||
SELECT filesystem.EntityID INTO rootID FROM filesystem WHERE EntityID = uuid_nil(); | ||
|
||
newEntity := (SELECT new_entity(rootID, 'downloads'::VARCHAR, 1, false)); | ||
oldEntity := (SELECT new_entity(rootID, 'documents'::VARCHAR, 1, false)); | ||
|
||
wasPopping := (SELECT new_entity(oldEntity, 'cool_document'::VARCHAR, 1, true)); | ||
wasPopping := (SELECT new_entity(oldEntity, 'cool_document_round_2'::VARCHAR, 1, true)); | ||
PERFORM delete_entity(wasPopping); | ||
wasPopping := (SELECT new_entity(oldEntity, 'cool_document_round_2'::VARCHAR, 1, true)); | ||
END $$; | ||
|
||
|
||
/* inserting two accounts into db */ | ||
DO LANGUAGE plpgsql $$ | ||
BEGIN | ||
EXECUTE create_normal_user('[email protected]', 'adam', 'password', 1); | ||
EXECUTE create_normal_user('[email protected]', 'john', 'password', 1); | ||
EXECUTE create_normal_user('[email protected]', 'jane', 'password', 1); | ||
END $$; | ||
|
||
|
||
|
||
COMMIT; |
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,8 @@ | ||
-- Revert website:01-create_migration_table from pg | ||
|
||
BEGIN; | ||
|
||
-- XXX Add DDLs here. | ||
DROP TABLE IF EXISTS migrations CASCADE; | ||
|
||
COMMIT; |
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,8 @@ | ||
-- Revert website:02-create_frontend_table from pg | ||
|
||
BEGIN; | ||
|
||
-- XXX Add DDLs here. | ||
DROP TABLE IF EXISTS frontend; | ||
|
||
COMMIT; |
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,9 @@ | ||
-- Revert website:03-create_groups_table from pg | ||
|
||
BEGIN; | ||
|
||
-- XXX Add DDLs here. | ||
DROP TYPE IF EXISTS permissions_enum CASCADE; | ||
|
||
DROP TABLE IF EXISTS groups CASCADE; | ||
COMMIT; |
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,11 @@ | ||
-- Revert website:04-create_person_table from pg | ||
|
||
BEGIN; | ||
|
||
-- XXX Add DDLs here. | ||
DROP TABLE IF EXISTS person; | ||
|
||
DROP FUNCTION IF EXISTS create_normal_user; | ||
|
||
|
||
COMMIT; |
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,11 @@ | ||
-- Revert website:05-create_filesystem_table from pg | ||
|
||
BEGIN; | ||
|
||
-- XXX Add DDLs here. | ||
DROP TABLE IF EXISTS metadata; | ||
DROP TABLE IF EXISTS filesystem; | ||
DROP FUNCTION IF EXISTS new_entity; | ||
DROP FUNCTION IF EXISTS delete_entity; | ||
|
||
COMMIT; |
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,7 @@ | ||
-- Revert website:06-create_dummy_data from pg | ||
|
||
BEGIN; | ||
|
||
-- XXX Add DDLs here. | ||
|
||
COMMIT; |
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 @@ | ||
@echo off & setlocal enableextensions enabledelayedexpansion | ||
REM # Determine which Docker image to run. | ||
IF NOT DEFINED SQITCH_IMAGE ( | ||
set SQITCH_IMAGE=website-sqitch:latest | ||
) | ||
REM set SQITCH_IMAGE=website-sqitch:latest | ||
|
||
REM # Set up required pass-through variables. | ||
FOR /F "tokens=*" %%g IN ('whoami') do (SET user=%%g) | ||
set passopt= -e SQITCH_ORIG_SYSUSER="%username%" | ||
FOR /F "tokens=*" %%g IN ('hostname') do (SET machinehostname=%%g) | ||
set passopt=%passopt% -e SQITCH_ORIG_EMAIL="%username%@%machinehostname%" | ||
FOR /F "tokens=*" %%g IN ('tzutil /g') do (SET TZ=%%g) | ||
set passopt=%passopt% -e TZ="%TZ%" | ||
if NOT DEFINED LESS ( | ||
set LESS=-R | ||
) | ||
set passopt=%passopt% -e LESS=%LESS% | ||
|
||
for %%i in ( | ||
SQITCH_CONFIG SQITCH_USERNAME SQITCH_PASSWORD SQITCH_FULLNAME SQITCH_EMAIL SQITCH_TARGET | ||
DBI_TRACE | ||
PGUSER PGPASSWORD PGHOST PGHOSTADDR PGPORT PGDATABASE PGSERVICE PGOPTIONS PGSSLMODE PGREQUIRESSL PGSSLCOMPRESSION PGREQUIREPEER PGKRBSRVNAME PGKRBSRVNAME PGGSSLIB PGCONNECT_TIMEOUT PGCLIENTENCODING PGTARGETSESSIONATTRS | ||
MYSQL_PWD MYSQL_HOST MYSQL_TCP_PORT | ||
TNS_ADMIN TWO_TASK ORACLE_SID | ||
ISC_USER ISC_PASSWORD | ||
VSQL_HOST VSQL_PORT VSQL_USER VSQL_PASSWORD VSQL_SSLMODE | ||
SNOWSQL_ACCOUNT SNOWSQL_USER SNOWSQL_PWD SNOWSQL_HOST SNOWSQL_PORT SNOWSQL_DATABASE SNOWSQL_REGION SNOWSQL_WAREHOUSE SNOWSQL_PRIVATE_KEY_PASSPHRASE | ||
) do if defined %%i ( | ||
echo %%i is defined as !%%i! | ||
SET passopt=!passopt! -e !%%i! | ||
) | ||
|
||
REM # Determine the name of the container home directory. | ||
set homedst=/home | ||
REM if [ $(id -u ${user}) -eq 0 ]; then | ||
REM homedst=/root | ||
REM fi | ||
REM # Set HOME, since the user ID likely won't be the same as for the sqitch user. | ||
set passopt=%passopt% -e HOME="%homedst%" | ||
|
||
echo %passopt% | ||
|
||
REM # Run the container with the current and home directories mounted. | ||
@echo on | ||
docker run -it --rm --network host ^ | ||
--mount "type=bind,src=%cd%,dst=/repo" ^ | ||
--mount "type=bind,src=%UserProfile%,dst=%homedst%" ^ | ||
%passopt% %SQITCH_IMAGE% %* | ||
|
||
@endlocal |
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,10 @@ | ||
[core] | ||
engine = pg | ||
# plan_file = sqitch.plan | ||
# top_dir = . | ||
# [engine "pg"] | ||
# target = db:pg: | ||
# registry = sqitch | ||
# client = psql | ||
[target "test"] | ||
uri = db:pg://postgres:postgres@localhost:5432/test_db |
Oops, something went wrong.
Oops, something went wrong.
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
do we need this anymore? now that we're using sqitch for migrations we dont need that python migration system