RelationalDesign: schema_creation.sql

File schema_creation.sql, 5.2 KB (added by 221181, 2 weeks ago)
Line 
1CREATE SCHEMA IF NOT EXISTS stock_management;
2SET search_path TO stock_management;
3
4DROP TABLE IF EXISTS warehouse_stock CASCADE;
5DROP TABLE IF EXISTS purchase_order_item CASCADE;
6DROP TABLE IF EXISTS sale_item CASCADE;
7DROP TABLE IF EXISTS purchase_order CASCADE;
8DROP TABLE IF EXISTS sale CASCADE;
9DROP TABLE IF EXISTS warehouse CASCADE;
10DROP TABLE IF EXISTS product CASCADE;
11DROP TABLE IF EXISTS supplier CASCADE;
12DROP TABLE IF EXISTS category CASCADE;
13DROP TABLE IF EXISTS customer CASCADE;
14DROP TABLE IF EXISTS users CASCADE;
15
16CREATE TABLE users (
17 user_id SERIAL PRIMARY KEY,
18 username VARCHAR(50) NOT NULL UNIQUE,
19 password VARCHAR(255) NOT NULL,
20 full_name VARCHAR(100) NOT NULL,
21 email VARCHAR(100) NOT NULL UNIQUE,
22 role VARCHAR(20) NOT NULL,
23 is_active BOOLEAN NOT NULL DEFAULT TRUE,
24 created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
25);
26
27CREATE TABLE customer (
28 customer_id SERIAL PRIMARY KEY,
29 name VARCHAR(100) NOT NULL,
30 email VARCHAR(100) NOT NULL,
31 phone VARCHAR(20) NOT NULL,
32 address TEXT NOT NULL,
33 created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
34);
35
36CREATE TABLE category (
37 category_id SERIAL PRIMARY KEY,
38 name VARCHAR(50) NOT NULL,
39 description TEXT,
40 created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
41);
42
43CREATE TABLE supplier (
44 supplier_id SERIAL PRIMARY KEY,
45 name VARCHAR(100) NOT NULL,
46 contact_person VARCHAR(100) NOT NULL,
47 phone VARCHAR(20) NOT NULL,
48 email VARCHAR(100) NOT NULL,
49 address TEXT NOT NULL,
50 created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
51);
52
53CREATE TABLE product (
54 product_id SERIAL PRIMARY KEY,
55 name VARCHAR(100) NOT NULL,
56 description TEXT,
57 sku VARCHAR(50) NOT NULL UNIQUE,
58 unit_price DECIMAL(12, 2) NOT NULL,
59 reorder_level INT NOT NULL DEFAULT 10,
60 category_id INT,
61 supplier_id INT,
62 is_active BOOLEAN NOT NULL DEFAULT TRUE,
63 created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
64 CONSTRAINT fk_product_category FOREIGN KEY (category_id)
65 REFERENCES category(category_id)
66 ON DELETE SET NULL
67 ON UPDATE CASCADE,
68 CONSTRAINT fk_product_supplier FOREIGN KEY (supplier_id)
69 REFERENCES supplier(supplier_id)
70 ON DELETE SET NULL
71 ON UPDATE CASCADE
72);
73
74CREATE TABLE warehouse (
75 warehouse_id SERIAL PRIMARY KEY,
76 name VARCHAR(100) NOT NULL,
77 location VARCHAR(255) NOT NULL,
78 capacity INT NOT NULL,
79 created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
80);
81
82CREATE TABLE sale (
83 sale_id SERIAL PRIMARY KEY,
84 date_time TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
85 total_amount DECIMAL(15, 2) NOT NULL,
86 user_id INT,
87 customer_id INT,
88 warehouse_id INT NOT NULL,
89 CONSTRAINT fk_sale_user FOREIGN KEY (user_id)
90 REFERENCES users(user_id)
91 ON DELETE SET NULL,
92 CONSTRAINT fk_sale_customer FOREIGN KEY (customer_id)
93 REFERENCES customer(customer_id)
94 ON DELETE SET NULL,
95 CONSTRAINT fk_sale_warehouse FOREIGN KEY (warehouse_id)
96 REFERENCES warehouse(warehouse_id)
97 ON DELETE RESTRICT
98);
99
100CREATE TABLE purchase_order (
101 po_id SERIAL PRIMARY KEY,
102 order_date DATE NOT NULL DEFAULT CURRENT_DATE,
103 expected_delivery_date DATE NOT NULL,
104 actual_delivery_date DATE,
105 status VARCHAR(20) NOT NULL,
106 supplier_id INT,
107 warehouse_id INT NOT NULL,
108 created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
109 CONSTRAINT fk_po_supplier FOREIGN KEY (supplier_id)
110 REFERENCES supplier(supplier_id)
111 ON DELETE SET NULL,
112 CONSTRAINT fk_po_warehouse FOREIGN KEY (warehouse_id)
113 REFERENCES warehouse(warehouse_id)
114 ON DELETE RESTRICT
115);
116
117CREATE TABLE sale_item (
118 sale_id INT NOT NULL,
119 product_id INT NOT NULL,
120 quantity INT NOT NULL CHECK (quantity > 0),
121 unit_price_at_sale DECIMAL(12, 2) NOT NULL,
122 PRIMARY KEY (sale_id, product_id),
123 CONSTRAINT fk_saleitem_sale FOREIGN KEY (sale_id)
124 REFERENCES sale(sale_id)
125 ON DELETE CASCADE,
126 CONSTRAINT fk_saleitem_product FOREIGN KEY (product_id)
127 REFERENCES product(product_id)
128 ON DELETE RESTRICT
129);
130
131CREATE TABLE purchase_order_item (
132 po_id INT NOT NULL,
133 product_id INT NOT NULL,
134 quantity INT NOT NULL CHECK (quantity > 0),
135 unit_cost DECIMAL(12, 2) NOT NULL,
136 received_quantity INT DEFAULT 0,
137 PRIMARY KEY (po_id, product_id),
138 CONSTRAINT fk_poitem_order FOREIGN KEY (po_id)
139 REFERENCES purchase_order(po_id)
140 ON DELETE CASCADE,
141 CONSTRAINT fk_poitem_product FOREIGN KEY (product_id)
142 REFERENCES product(product_id)
143 ON DELETE RESTRICT
144);
145
146CREATE TABLE warehouse_stock (
147 warehouse_id INT NOT NULL,
148 product_id INT NOT NULL,
149 quantity_on_hand INT NOT NULL DEFAULT 0,
150 last_updated TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
151 PRIMARY KEY (warehouse_id, product_id),
152 CONSTRAINT fk_stock_warehouse FOREIGN KEY (warehouse_id)
153 REFERENCES warehouse(warehouse_id)
154 ON DELETE CASCADE,
155 CONSTRAINT fk_stock_product FOREIGN KEY (product_id)
156 REFERENCES product(product_id)
157 ON DELETE CASCADE
158);