Skip to content

Commit

Permalink
Merge pull request #8 from ubccsss/daniel/pg-setup
Browse files Browse the repository at this point in the history
Daniel/pg setup
  • Loading branch information
PatrickhySh authored Jan 26, 2024
2 parents a568f93 + 3ebbbb5 commit 0d05947
Show file tree
Hide file tree
Showing 29 changed files with 1,884 additions and 2 deletions.
5 changes: 5 additions & 0 deletions .env.test
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
POSTGRES_USER=admin
POSTGRES_PASSWORD=root
POSTGRES_DB=test_data
POSTGRES_DATA_PATH="database/test_data" # Relative path to directory holding DB data
POSTGRES_INIT_PATH="database/init_test" # Relative path to directory containing init files
3 changes: 2 additions & 1 deletion .eslintrc.js
Original file line number Diff line number Diff line change
Expand Up @@ -163,7 +163,8 @@ module.exports = {
}
],
"radix": "error",
"semi": "error",
"semi": "off",
"@typescript-eslint/semi": ["error"],
"space-before-function-paren": [
"error",
{
Expand Down
6 changes: 5 additions & 1 deletion .gitignore
Original file line number Diff line number Diff line change
Expand Up @@ -38,4 +38,8 @@ typings/
lib/*.js
test/*.js
*.map
node_modules
node_modules

database/data/
database/test_data/
.env
68 changes: 68 additions & 0 deletions .kanelrc.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,68 @@
const path = require("path");
const { recase } = require('@kristiandupont/recase');
const resolveType = require('kanel/build/generators/resolveType').default;


const toPascalCase = recase('snake', 'pascal');

const fixImportFormatting = (path, lines, instantiatedConfig) => {
return lines.map((line) => {
if (line.includes("import ")) {
return line.replace("{ ", "{").replace(" }", "}").replaceAll("'", "\"")
}
return line
})
}

const newlineAtEnd = (path, lines, instantiatedConfig) => {
return [...lines, "\n"]
}

/** @type {import('kanel').Config} */
module.exports = {
connection: {
host: "localhost",
user: "admin",
password: "root",
database: "test_data",
},

preDeleteOutputFolder: true,
outputPath: "./src/types",

customTypeMap: {
"pg_catalog.tsvector": "string",
"pg_catalog.bpchar": "string",
},

// This implementation will generate flavored instead of branded types.
// See: https://spin.atomicobject.com/2018/01/15/typescript-flexible-nominal-typing/
generateIdentifierType: (c, d, config) => {
// Id columns are already prefixed with the table name, so we don't need to add it here
const name = toPascalCase(c.name);
const innerType = resolveType(c, d, {
...config,
// Explicitly disable identifier resolution so we get the actual inner type here
generateIdentifierType: undefined,
});
const imports = [];

let type = innerType;
if (typeof innerType === "object") {
// Handle non-primitives
type = innerType.name;
imports.push(...innerType.typeImports);
}

return {
declarationType: 'typeDeclaration',
name,
exportAs: 'named',
typeDefinition: [`${type} & {__flavor?: "${name}"}`],
typeImports: imports,
comment: [`Identifier type for ${d.name}`],
};
},

postRenderHooks: [fixImportFormatting, newlineAtEnd]
};
19 changes: 19 additions & 0 deletions database/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
# Database Documentation
We are using PostgreSQL with Docker for our database. Scripts for the initial database setup are located in the `database/init*` directories.

# Setup Configuration
The database can be set up either for production or for testing. The database names used are as follows:
- Production: `cube_data`
- Testing: `test_data`

When setting up the `.env` file, take care to use the correct database names since they are hardcoded into the initialization files (there isn't a great way to use environment variables in .sql files). The following environment variables are required:

```
POSTGRES_USER=<username>
POSTGRES_PASSWORD=<password>
POSTGRES_DB=[cube_data|test_data]
POSTGRES_DATA_PATH=["database/data"|"database/test_data"]
POSTGRES_INIT_PATH=["database/init"|"database/init_test"]
```

If this is the first time running the Docker container, `POSTGRES_DATA_PATH` can be any empty directory since it is bound by Docker to the data directory inside the container. However, if there is already existing data take care to set the right value.
65 changes: 65 additions & 0 deletions database/init/0_init_tables.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,65 @@
\c cube_data;

CREATE TABLE valid_category (
category TEXT PRIMARY KEY
);

CREATE TABLE item_individual (
item_id INT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
name TEXT NOT NULL UNIQUE,
description TEXT NOT NULL,
price DECIMAL(10, 2) NOT NULL CONSTRAINT nonneg_price CHECK (price >= 0),
category TEXT NOT NULL REFERENCES valid_category ON UPDATE CASCADE ON DELETE RESTRICT, -- don't allow a category row to be removed if an item references that row
img_url TEXT, -- img optional
reservable BOOL NOT NULL,
quantity_remaining INT NOT NULL CONSTRAINT nonneg_quantity CHECK (quantity_remaining >= 0),
low_stock_threshold INT NOT NULL CONSTRAINT nonneg_threshold CHECK (low_stock_threshold >= 0),
last_restocked TIMESTAMP, -- maybe non null to allow for initial setup?
max_quantity_per_transaction INT NOT NULL CONSTRAINT positive_max CHECK (max_quantity_per_transaction > 0)
);

CREATE TABLE item_box (
item_box_id INT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
item_id INT NOT NULL REFERENCES item_individual ON UPDATE CASCADE ON DELETE CASCADE, -- if we delete an item, delete all its boxes too
quantity_per_box INT NOT NULL CONSTRAINT pos_quantity CHECK (quantity_per_box > 0)
);

CREATE TABLE transaction (
transaction_id INT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
total DECIMAL(10, 2) NOT NULL CONSTRAINT nonneg_total CHECK (total >= 0),
transaction_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP, -- auto create transaction timestamp
payer_email TEXT CHECK (payer_email ~ '^[a-z0-9!.#$%&''*+/=?^_`{|}~-]+@([a-z0-9]+[.])+[a-z0-9]+$')
);

CREATE TABLE transaction_item (
transaction_id INT NOT NULL REFERENCES transaction ON UPDATE CASCADE ON DELETE CASCADE, -- if we delete a transaction, also delete its details
item_id INT NOT NULL REFERENCES item_individual ON UPDATE CASCADE ON DELETE RESTRICT, -- don't allow an item that's in a transaction to be deleted
item_quantity INT NOT NULL CONSTRAINT positive_quantity CHECK (item_quantity > 0),
CONSTRAINT transaction_item_pk PRIMARY KEY (transaction_id, item_id)
);

CREATE TABLE csss_user (
user_id INT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
email TEXT NOT NULL UNIQUE CHECK (email ~ '^[a-z0-9!.#$%&''*+/=?^_`{|}~-]+@([a-z0-9]+[.])+[a-z0-9]+$'),
password TEXT NOT NULL, -- should be a hash
first_name TEXT NOT NULL,
last_name TEXT NOT NULL,
phone_number VARCHAR(10) CHECK (phone_number ~ '^[0-9]{10}$'),
is_treasurer BOOL DEFAULT FALSE
);

CREATE TABLE reimbursement (
reimbursement_id INT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
receipt_img_url TEXT NOT NULL,
purchase_total DECIMAL(10, 2) NOT NULL CONSTRAINT positive_purchase_total CHECK (purchase_total > 0),
purchase_date DATE NOT NULL,
reimbursed BOOL DEFAULT FALSE,
user_id INT NOT NULL REFERENCES csss_user ON UPDATE CASCADE ON DELETE RESTRICT -- don't allow an officer to be deleted if they have reimbursements
);

CREATE TABLE reimbursement_item_box (
reimbursement_id INT NOT NULL REFERENCES reimbursement ON UPDATE CASCADE ON DELETE CASCADE, -- if we delete a reimbursement, also delete its details
item_box_id INT NOT NULL REFERENCES item_box ON UPDATE CASCADE ON DELETE RESTRICT, -- don't allow an item box that's in a transaction to be deleted
item_quantity INT NOT NULL CONSTRAINT positive_quantity CHECK (item_quantity > 0),
CONSTRAINT reimbursement_item_box_pk PRIMARY KEY (reimbursement_id, item_box_id)
);
65 changes: 65 additions & 0 deletions database/init_test/0_init_test_tables.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,65 @@
\c test_data;

CREATE TABLE valid_category (
category TEXT PRIMARY KEY
);

CREATE TABLE item_individual (
item_id INT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
name TEXT NOT NULL UNIQUE,
description TEXT NOT NULL,
price DECIMAL(10, 2) NOT NULL CONSTRAINT nonneg_price CHECK (price >= 0),
category TEXT NOT NULL REFERENCES valid_category ON UPDATE CASCADE ON DELETE RESTRICT, -- don't allow a category row to be removed if an item references that row
img_url TEXT, -- img optional
reservable BOOL NOT NULL,
quantity_remaining INT NOT NULL CONSTRAINT nonneg_quantity CHECK (quantity_remaining >= 0),
low_stock_threshold INT NOT NULL CONSTRAINT nonneg_threshold CHECK (low_stock_threshold >= 0),
last_restocked TIMESTAMP, -- maybe non null to allow for initial setup?
max_quantity_per_transaction INT NOT NULL CONSTRAINT positive_max CHECK (max_quantity_per_transaction > 0)
);

CREATE TABLE item_box (
item_box_id INT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
item_id INT NOT NULL REFERENCES item_individual ON UPDATE CASCADE ON DELETE CASCADE, -- if we delete an item, delete all its boxes too
quantity_per_box INT NOT NULL CONSTRAINT pos_quantity CHECK (quantity_per_box > 0)
);

CREATE TABLE transaction (
transaction_id INT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
total DECIMAL(10, 2) NOT NULL CONSTRAINT nonneg_total CHECK (total >= 0),
transaction_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP, -- auto create transaction timestamp
payer_email TEXT CHECK (payer_email ~ '^[a-z0-9!.#$%&''*+/=?^_`{|}~-]+@([a-z0-9]+[.])+[a-z0-9]+$')
);

CREATE TABLE transaction_item (
transaction_id INT NOT NULL REFERENCES transaction ON UPDATE CASCADE ON DELETE CASCADE, -- if we delete a transaction, also delete its details
item_id INT NOT NULL REFERENCES item_individual ON UPDATE CASCADE ON DELETE RESTRICT, -- don't allow an item that's in a transaction to be deleted
item_quantity INT NOT NULL CONSTRAINT positive_quantity CHECK (item_quantity > 0),
CONSTRAINT transaction_item_pk PRIMARY KEY (transaction_id, item_id)
);

CREATE TABLE csss_user (
user_id INT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
email TEXT NOT NULL UNIQUE CHECK (email ~ '^[a-z0-9!.#$%&''*+/=?^_`{|}~-]+@([a-z0-9]+[.])+[a-z0-9]+$'),
password TEXT NOT NULL, -- should be a hash
first_name TEXT NOT NULL,
last_name TEXT NOT NULL,
phone_number VARCHAR(10) CHECK (phone_number ~ '^[0-9]{10}$'),
is_treasurer BOOL DEFAULT FALSE
);

CREATE TABLE reimbursement (
reimbursement_id INT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
receipt_img_url TEXT NOT NULL,
purchase_total DECIMAL(10, 2) NOT NULL CONSTRAINT positive_purchase_total CHECK (purchase_total > 0),
purchase_date DATE NOT NULL,
reimbursed BOOL DEFAULT FALSE,
user_id INT NOT NULL REFERENCES csss_user ON UPDATE CASCADE ON DELETE RESTRICT -- don't allow an officer to be deleted if they have reimbursements
);

CREATE TABLE reimbursement_item_box (
reimbursement_id INT NOT NULL REFERENCES reimbursement ON UPDATE CASCADE ON DELETE CASCADE, -- if we delete a reimbursement, also delete its details
item_box_id INT NOT NULL REFERENCES item_box ON UPDATE CASCADE ON DELETE RESTRICT, -- don't allow an item box that's in a transaction to be deleted
item_quantity INT NOT NULL CONSTRAINT positive_quantity CHECK (item_quantity > 0),
CONSTRAINT reimbursement_item_box_pk PRIMARY KEY (reimbursement_id, item_box_id)
);
Loading

0 comments on commit 0d05947

Please sign in to comment.