-
Notifications
You must be signed in to change notification settings - Fork 3
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Fix missed change of AccessibleThing -> Tool
- Loading branch information
Showing
3 changed files
with
315 additions
and
1 deletion.
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,93 @@ | ||
-- Convert schema 'sqlt/AccessSystem-Schema-6.0-PostgreSQL.sql' to 'sqlt/AccessSystem-Schema-7.0-PostgreSQL.sql':; | ||
|
||
BEGIN; | ||
|
||
CREATE TABLE "tool_status" ( | ||
"id" serial NOT NULL, | ||
"tool_id" character varying(40) NOT NULL, | ||
"when" timestamp NOT NULL, | ||
"who_id" integer NOT NULL, | ||
"status" character varying(20) NOT NULL, | ||
"description" character varying(1024) NOT NULL, | ||
PRIMARY KEY ("id") | ||
); | ||
CREATE INDEX "tool_status_idx_tool_id" on "tool_status" ("tool_id"); | ||
CREATE INDEX "tool_status_idx_who_id" on "tool_status" ("who_id"); | ||
|
||
CREATE TABLE "tools" ( | ||
"id" character varying(40) NOT NULL, | ||
"name" character varying(255) NOT NULL, | ||
"assigned_ip" character varying(15), | ||
"requires_induction" boolean NOT NULL, | ||
"team" character varying(50) NOT NULL, | ||
PRIMARY KEY ("id"), | ||
CONSTRAINT "name" UNIQUE ("name") | ||
); | ||
|
||
ALTER TABLE "tool_status" ADD CONSTRAINT "tool_status_fk_tool_id" FOREIGN KEY ("tool_id") | ||
REFERENCES "tools" ("id") ON DELETE cascade ON UPDATE cascade DEFERRABLE; | ||
|
||
ALTER TABLE "tool_status" ADD CONSTRAINT "tool_status_fk_who_id" FOREIGN KEY ("who_id") | ||
REFERENCES "people" ("id") DEFERRABLE; | ||
|
||
ALTER TABLE allowed DROP CONSTRAINT ; | ||
|
||
ALTER TABLE allowed DROP CONSTRAINT allowed_pkey; | ||
|
||
ALTER TABLE allowed DROP CONSTRAINT allowed_fk_accessible_thing_id; | ||
|
||
DROP INDEX allowed_idx_accessible_thing_id; | ||
|
||
ALTER TABLE allowed DROP COLUMN accessible_thing_id; | ||
|
||
ALTER TABLE allowed ADD COLUMN tool_id character varying(40) DEFAULT '' NOT NULL; | ||
|
||
CREATE INDEX allowed_idx_tool_id on allowed (tool_id); | ||
|
||
ALTER TABLE allowed ADD PRIMARY KEY (person_id, tool_id); | ||
|
||
ALTER TABLE allowed ADD CONSTRAINT allowed_fk_tool_id FOREIGN KEY (tool_id) | ||
REFERENCES tools (id) ON DELETE cascade ON UPDATE cascade DEFERRABLE; | ||
|
||
ALTER TABLE communications ADD COLUMN status character varying(10) NOT NULL; | ||
|
||
ALTER TABLE message_log DROP CONSTRAINT ; | ||
|
||
ALTER TABLE message_log DROP CONSTRAINT message_log_pkey; | ||
|
||
ALTER TABLE message_log DROP CONSTRAINT message_log_fk_accessible_thing_id; | ||
|
||
DROP INDEX message_log_idx_accessible_thing_id; | ||
|
||
ALTER TABLE message_log RENAME COLUMN accessible_thing_id TO tool_id; | ||
|
||
CREATE INDEX message_log_idx_tool_id on message_log (tool_id); | ||
|
||
ALTER TABLE message_log ADD PRIMARY KEY (tool_id, written_date); | ||
|
||
ALTER TABLE message_log ADD CONSTRAINT message_log_fk_tool_id FOREIGN KEY (tool_id) | ||
REFERENCES tools (id) ON DELETE cascade ON UPDATE cascade DEFERRABLE; | ||
|
||
ALTER TABLE usage_log DROP CONSTRAINT ; | ||
|
||
ALTER TABLE usage_log DROP CONSTRAINT usage_log_pkey; | ||
|
||
ALTER TABLE usage_log DROP CONSTRAINT usage_log_fk_accessible_thing_id; | ||
|
||
DROP INDEX usage_log_idx_accessible_thing_id; | ||
|
||
ALTER TABLE usage_log RENAME COLUMN accessible_thing_id TO tool_id; | ||
|
||
CREATE INDEX usage_log_idx_tool_id on usage_log (tool_id); | ||
|
||
ALTER TABLE usage_log ADD PRIMARY KEY (tool_id, accessed_date); | ||
|
||
ALTER TABLE usage_log ADD CONSTRAINT usage_log_fk_tool_id FOREIGN KEY (tool_id) | ||
REFERENCES tools (id) DEFERRABLE; | ||
|
||
DROP TABLE accessible_things 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,221 @@ | ||
-- | ||
-- Created by SQL::Translator::Producer::PostgreSQL | ||
-- Created on Sun Nov 15 12:50:48 2020 | ||
-- | ||
-- | ||
-- Table: membership_register | ||
-- | ||
DROP TABLE membership_register CASCADE; | ||
CREATE TABLE membership_register ( | ||
name character varying(255) NOT NULL, | ||
address character varying(1024) NOT NULL, | ||
started_date date NOT NULL, | ||
ended_date date, | ||
updated_date timestamp, | ||
updated_reason character varying(1024) NOT NULL, | ||
PRIMARY KEY (name, started_date) | ||
); | ||
|
||
-- | ||
-- Table: tool_status | ||
-- | ||
DROP TABLE tool_status CASCADE; | ||
CREATE TABLE tool_status ( | ||
id serial NOT NULL, | ||
tool_id integer NOT NULL, | ||
when timestamp NOT NULL, | ||
who_id integer NOT NULL, | ||
status character varying(20) NOT NULL, | ||
description character varying(1024) NOT NULL, | ||
PRIMARY KEY (id) | ||
); | ||
CREATE INDEX tool_status_idx_tool_id on tool_status (tool_id); | ||
CREATE INDEX tool_status_idx_who_id on tool_status (who_id); | ||
|
||
-- | ||
-- Table: tools | ||
-- | ||
DROP TABLE tools CASCADE; | ||
CREATE TABLE tools ( | ||
id character varying(40) NOT NULL, | ||
name character varying(255) NOT NULL, | ||
assigned_ip character varying(15), | ||
requires_induction boolean NOT NULL, | ||
team character varying(50) NOT NULL, | ||
PRIMARY KEY (id), | ||
CONSTRAINT name UNIQUE (name) | ||
); | ||
|
||
-- | ||
-- Table: people | ||
-- | ||
DROP TABLE people CASCADE; | ||
CREATE TABLE people ( | ||
id serial NOT NULL, | ||
parent_id integer, | ||
name character varying(255) NOT NULL, | ||
email character varying(255), | ||
opt_in boolean DEFAULT '0' NOT NULL, | ||
dob character varying(7) NOT NULL, | ||
address character varying(1024) NOT NULL, | ||
github_user character varying(255), | ||
google_id character varying(255), | ||
concessionary_rate_override character varying(255) DEFAULT '', | ||
payment_override float, | ||
member_of_other_hackspace boolean DEFAULT '0' NOT NULL, | ||
created_date timestamp NOT NULL, | ||
end_date timestamp, | ||
PRIMARY KEY (id) | ||
); | ||
CREATE INDEX people_idx_parent_id on people (parent_id); | ||
|
||
-- | ||
-- Table: access_tokens | ||
-- | ||
DROP TABLE access_tokens CASCADE; | ||
CREATE TABLE access_tokens ( | ||
id character varying(255) NOT NULL, | ||
person_id integer NOT NULL, | ||
type character varying(20) NOT NULL, | ||
PRIMARY KEY (person_id, id) | ||
); | ||
CREATE INDEX access_tokens_idx_person_id on access_tokens (person_id); | ||
|
||
-- | ||
-- Table: communications | ||
-- | ||
DROP TABLE communications CASCADE; | ||
CREATE TABLE communications ( | ||
person_id integer NOT NULL, | ||
sent_on timestamp NOT NULL, | ||
type character varying(50) NOT NULL, | ||
status character varying(10) NOT NULL, | ||
content character varying(10240) NOT NULL, | ||
PRIMARY KEY (person_id, sent_on) | ||
); | ||
CREATE INDEX communications_idx_person_id on communications (person_id); | ||
|
||
-- | ||
-- Table: dues | ||
-- | ||
DROP TABLE dues CASCADE; | ||
CREATE TABLE dues ( | ||
person_id integer NOT NULL, | ||
paid_on_date timestamp NOT NULL, | ||
expires_on_date timestamp NOT NULL, | ||
amount_p integer NOT NULL, | ||
added_on timestamp NOT NULL, | ||
PRIMARY KEY (person_id, paid_on_date) | ||
); | ||
CREATE INDEX dues_idx_person_id on dues (person_id); | ||
|
||
-- | ||
-- Table: login_tokens | ||
-- | ||
DROP TABLE login_tokens CASCADE; | ||
CREATE TABLE login_tokens ( | ||
person_id integer NOT NULL, | ||
login_token character varying(36) NOT NULL, | ||
PRIMARY KEY (person_id, login_token) | ||
); | ||
CREATE INDEX login_tokens_idx_person_id on login_tokens (person_id); | ||
|
||
-- | ||
-- Table: message_log | ||
-- | ||
DROP TABLE message_log CASCADE; | ||
CREATE TABLE message_log ( | ||
tool_id character varying(40) NOT NULL, | ||
message character varying(2048) NOT NULL, | ||
from_ip character varying(15) NOT NULL, | ||
written_date timestamp NOT NULL, | ||
PRIMARY KEY (tool_id, written_date) | ||
); | ||
CREATE INDEX message_log_idx_tool_id on message_log (tool_id); | ||
|
||
-- | ||
-- Table: transactions | ||
-- | ||
DROP TABLE transactions CASCADE; | ||
CREATE TABLE transactions ( | ||
person_id integer NOT NULL, | ||
added_on timestamp NOT NULL, | ||
amount_p integer NOT NULL, | ||
reason character varying(255) NOT NULL, | ||
PRIMARY KEY (person_id, added_on) | ||
); | ||
CREATE INDEX transactions_idx_person_id on transactions (person_id); | ||
|
||
-- | ||
-- Table: allowed | ||
-- | ||
DROP TABLE allowed CASCADE; | ||
CREATE TABLE allowed ( | ||
person_id integer NOT NULL, | ||
tool_id character varying(40) NOT NULL, | ||
is_admin integer NOT NULL, | ||
added_on timestamp NOT NULL, | ||
PRIMARY KEY (person_id, tool_id) | ||
); | ||
CREATE INDEX allowed_idx_person_id on allowed (person_id); | ||
CREATE INDEX allowed_idx_tool_id on allowed (tool_id); | ||
|
||
-- | ||
-- Table: usage_log | ||
-- | ||
DROP TABLE usage_log CASCADE; | ||
CREATE TABLE usage_log ( | ||
person_id integer, | ||
tool_id character varying(40) NOT NULL, | ||
token_id character varying(255) NOT NULL, | ||
status character varying(20) NOT NULL, | ||
accessed_date timestamp NOT NULL, | ||
PRIMARY KEY (tool_id, accessed_date) | ||
); | ||
CREATE INDEX usage_log_idx_person_id on usage_log (person_id); | ||
CREATE INDEX usage_log_idx_tool_id on usage_log (tool_id); | ||
|
||
-- | ||
-- Foreign Key Definitions | ||
-- | ||
|
||
ALTER TABLE tool_status ADD CONSTRAINT tool_status_fk_tool_id FOREIGN KEY (tool_id) | ||
REFERENCES tools (id) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE; | ||
|
||
ALTER TABLE tool_status ADD CONSTRAINT tool_status_fk_who_id FOREIGN KEY (who_id) | ||
REFERENCES people (id) DEFERRABLE; | ||
|
||
ALTER TABLE people ADD CONSTRAINT people_fk_parent_id FOREIGN KEY (parent_id) | ||
REFERENCES people (id) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE; | ||
|
||
ALTER TABLE access_tokens ADD CONSTRAINT access_tokens_fk_person_id FOREIGN KEY (person_id) | ||
REFERENCES people (id) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE; | ||
|
||
ALTER TABLE communications ADD CONSTRAINT communications_fk_person_id FOREIGN KEY (person_id) | ||
REFERENCES people (id) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE; | ||
|
||
ALTER TABLE dues ADD CONSTRAINT dues_fk_person_id FOREIGN KEY (person_id) | ||
REFERENCES people (id) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE; | ||
|
||
ALTER TABLE login_tokens ADD CONSTRAINT login_tokens_fk_person_id FOREIGN KEY (person_id) | ||
REFERENCES people (id) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE; | ||
|
||
ALTER TABLE message_log ADD CONSTRAINT message_log_fk_tool_id FOREIGN KEY (tool_id) | ||
REFERENCES tools (id) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE; | ||
|
||
ALTER TABLE transactions ADD CONSTRAINT transactions_fk_person_id FOREIGN KEY (person_id) | ||
REFERENCES people (id) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE; | ||
|
||
ALTER TABLE allowed ADD CONSTRAINT allowed_fk_person_id FOREIGN KEY (person_id) | ||
REFERENCES people (id) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE; | ||
|
||
ALTER TABLE allowed ADD CONSTRAINT allowed_fk_tool_id FOREIGN KEY (tool_id) | ||
REFERENCES tools (id) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE; | ||
|
||
ALTER TABLE usage_log ADD CONSTRAINT usage_log_fk_person_id FOREIGN KEY (person_id) | ||
REFERENCES people (id) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE; | ||
|
||
ALTER TABLE usage_log ADD CONSTRAINT usage_log_fk_tool_id FOREIGN KEY (tool_id) | ||
REFERENCES tools (id) DEFERRABLE; | ||
|
||
|