Everything works except callproc. Nothing gets saved on callproc. Why?
This commit is contained in:
parent
4c5d5bdea2
commit
d03fa41da3
|
@ -0,0 +1,30 @@
|
|||
Re-learning how to install Postgres (*Sigh)
|
||||
|
||||
CREATE DATABASE officehours;
|
||||
CREATE USER officehours;
|
||||
ALTER USER officehours WITH UNENCRYPTED PASSWORD '<password>';
|
||||
ALTER USER officehours LOGIN;
|
||||
GRANT ALL PRIVILEGES ON DATABASE officehours TO officehours;
|
||||
|
||||
-- Been a while since I used Postgres. I'd forgotten that Postgres
|
||||
-- thinks in terms of privileged connections. It makes sense, certainly
|
||||
-- better than MySQL.
|
||||
\CONNECT officehours;
|
||||
|
||||
-- Enable case-insensitive matches on some text columns, good for email
|
||||
CREATE EXTENSION citext;
|
||||
|
||||
#
|
||||
|
||||
What can I do?
|
||||
1) Add users and make them clients.
|
||||
2) Add users and make them staff.
|
||||
3) Allocate a block of time as "office hours"
|
||||
4) Allocate a block of time as an "appointment."
|
||||
|
||||
NEXT: Psycopg2
|
||||
|
||||
** Progress: Everything works in psycopg2 EXCEPT add_appointment, which
|
||||
is very distressing. Really, _really_ don't want to take that
|
||||
functionality and put it into the middle tier. It's rock-solid business
|
||||
logic; it belongs in the database as a constraint.
|
180
officehours.sql
180
officehours.sql
|
@ -1,24 +1,44 @@
|
|||
-- Users known by the application. "Nickname" is a misnomer. Nom de
|
||||
-- user was too pretentious. It's how the customer wishes to be
|
||||
↓-- addressed, but "address" would be confusing.
|
||||
-- addressed, but "address" would be confusing.
|
||||
|
||||
-- requires extensions citex, btree_gist
|
||||
|
||||
--DROP VIEW IF EXISTS staff_members;
|
||||
--DROP VIEW IF EXISTS client_members;
|
||||
--DROP VIEW IF EXISTS usernames;
|
||||
|
||||
DROP VIEW IF EXISTS staff_appointments;
|
||||
DROP TABLE IF EXISTS appointments;
|
||||
DROP TABLE IF EXISTS officehours;
|
||||
DROP VIEW IF EXISTS staff_client_relationships;
|
||||
DROP TABLE IF EXISTS relationship;
|
||||
DROP VIEW IF EXISTS staff_members;
|
||||
DROP TABLE IF EXISTS staff;
|
||||
DROP VIEW IF EXISTS client_members;
|
||||
DROP TABLE IF EXISTS clients;
|
||||
DROP VIEW IF EXISTS usernames;
|
||||
DROP TABLE IF EXISTS users CASCADE;
|
||||
|
||||
-- DROP VIEW IF EXISTS relationships;
|
||||
|
||||
CREATE TABLE users (
|
||||
id SERIAL,
|
||||
email CITEX UNIQUE NOT NULL,
|
||||
id SERIAL PRIMARY KEY UNIQUE,
|
||||
email CITEXT UNIQUE NOT NULL,
|
||||
nickname TEXT NOT NULL
|
||||
);
|
||||
|
||||
-- Users who are currently staff
|
||||
|
||||
CREATE TABLE staff (
|
||||
staff_id INTEGER UNIQUE NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||||
staff_id INTEGER UNIQUE REFERENCES users(id) ON DELETE CASCADE,
|
||||
active BOOLEAN
|
||||
);
|
||||
|
||||
-- Users who are currently clients
|
||||
|
||||
CREATE TABLE clients (
|
||||
client_id INTEGER UNIQUE NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||||
client_id INTEGER UNIQUE REFERENCES users(id) ON DELETE CASCADE,
|
||||
active BOOLEAN
|
||||
);
|
||||
|
||||
|
@ -28,14 +48,148 @@ CREATE TABLE clients (
|
|||
-- An appointment can then be made my a client, and there's only one
|
||||
-- staff person who it could apply to, so the query is straightforward
|
||||
-- then.
|
||||
--
|
||||
-- To extend this into a M:M relationship, you'd have to remove the
|
||||
-- "UNIQUE" setting from the staff_id field and use the
|
||||
-- relationship.id field instead for appointments.
|
||||
--
|
||||
-- If we wanted a client to have more than one coach, we'd have to
|
||||
-- remove the UNIQUE constraint and let there be more than one
|
||||
-- client-staff relationships.
|
||||
|
||||
CREATE TABLE relationship (
|
||||
id SERIAL,
|
||||
client_id INTEGER NOT NULL REFERENCES clients(client_id) ON DELETE CASCADE,
|
||||
staff_id INTEGER UNIQUE NOT NULL REFERENCES staff(staff_id) ON DELETE CASCADE
|
||||
id SERIAL PRIMARY KEY UNIQUE,
|
||||
client_id INTEGER UNIQUE NOT NULL REFERENCES clients(client_id) ON DELETE CASCADE,
|
||||
staff_id INTEGER NOT NULL REFERENCES staff(staff_id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
|
||||
-- Staff members may create office hours, but to prevent confusion we
|
||||
-- should not allow a single staff-member's officehour entries to
|
||||
-- overlap. The && is the "overlaps" (has points in common) operator
|
||||
-- for ranges.
|
||||
|
||||
CREATE TABLE officehours (
|
||||
id SERIAL PRIMARY KEY UNIQUE,
|
||||
staff_id INTEGER NOT NULL REFERENCES staff(staff_id) ON DELETE CASCADE,
|
||||
during TSRANGE,
|
||||
EXCLUDE USING gist (staff_id WITH =, during WITH &&)
|
||||
);
|
||||
|
||||
-- This one is tricky. We're basically saying that the client has an
|
||||
-- appointment, and that's all we care about. BUT the INSERT must
|
||||
-- find the staff member with whom this client has a relationship, and
|
||||
-- assert that the staff member has office hours at that time, and
|
||||
-- that no other client off that staff member has already chosen an
|
||||
-- overlapping appointment.
|
||||
|
||||
CREATE TABLE appointments (
|
||||
id SERIAL PRIMARY KEY UNIQUE,
|
||||
during TSRANGE,
|
||||
client_id INTEGER NOT NULL REFERENCES clients(client_id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE VIEW usernames AS SELECT id, nickname FROM users;
|
||||
|
||||
CREATE VIEW staff_members AS
|
||||
(SELECT users.nickname AS staff_name, users.id AS staff_id
|
||||
FROM users WHERE users.id IN (SELECT staff_id FROM staff WHERE active=true));
|
||||
|
||||
CREATE VIEW client_members AS
|
||||
(SELECT users.nickname AS client_name, users.id AS client_id
|
||||
FROM users WHERE users.id IN (SELECT client_id FROM clients WHERE active=true));
|
||||
|
||||
CREATE VIEW staff_client_relationships AS
|
||||
(SELECT staff_name, staff_members.staff_id AS staff_id,
|
||||
client_name, client_members.client_id AS client_id FROM relationship
|
||||
INNER JOIN staff_members ON relationship.staff_id = staff_members.staff_id
|
||||
INNER JOIN client_members ON relationship.client_id = client_members.client_id);
|
||||
|
||||
CREATE VIEW staff_appointments AS
|
||||
(SELECT staff_name, staff_client_relationships.staff_id AS staff_id,
|
||||
client_name, staff_client_relationships.client_id AS client_id, during
|
||||
FROM appointments INNER JOIN staff_client_relationships
|
||||
ON appointments.client_id = staff_client_relationships.client_id);
|
||||
|
||||
DROP FUNCTION IF EXISTS add_appointment(INT, TSRANGE);
|
||||
CREATE OR REPLACE FUNCTION add_appointment(q_client_id INT, q_timerange TSRANGE) RETURNS VOID as $$
|
||||
BEGIN
|
||||
IF NOT EXISTS (SELECT officehours.id FROM officehours INNER JOIN relationship
|
||||
ON relationship.staff_id = officehours.staff_id
|
||||
WHERE relationship.client_id = q_client_id
|
||||
AND (q_timerange <@ officehours.during)) THEN
|
||||
RAISE EXCEPTION 'There are no office hours for your coach at that time.';
|
||||
END IF;
|
||||
IF EXISTS (SELECT appointments.id FROM appointments WHERE client_id IN (
|
||||
SELECT client_id FROM relationship WHERE staff_id IN (
|
||||
SELECT staff_id FROM relationship WHERE client_id = q_client_id))
|
||||
AND (q_timerange && appointments.during)) THEN
|
||||
RAISE EXCEPTION 'That appointment slot is already taken.';
|
||||
INSERT INTO appointments (client_id, during) SELECT q_client_id, q_timerange;
|
||||
END IF;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Some basic testing starts below:
|
||||
|
||||
-- INSERT INTO users (nickname, email) VALUES ('Alice', 'alice@example.com');
|
||||
-- INSERT INTO users (nickname, email) VALUES ('Bob', 'bob@example.com');
|
||||
-- INSERT INTO users (nickname, email) VALUES ('Carol', 'carol@example.com');
|
||||
-- INSERT INTO users (nickname, email) VALUES ('Doug', 'doug@example.com');
|
||||
|
||||
-- SELECT * from usernames;
|
||||
|
||||
-- INSERT INTO users (nickname, email) VALUES ('Ellen', 'ellen@example.com');
|
||||
-- INSERT INTO users (nickname, email) VALUES ('Fred', 'fred@example.com');
|
||||
|
||||
-- SELECT * from usernames;
|
||||
|
||||
-- INSERT INTO staff (staff_id) SELECT id from users where email IN ('alice@example.com', 'bob@example.com');
|
||||
-- INSERT INTO clients (client_id) SELECT id from users where email NOT IN ('alice@example.com', 'bob@example.com');
|
||||
-- UPDATE staff SET active = True;
|
||||
-- UPDATE clients SET active = True;
|
||||
|
||||
-- INSERT INTO relationship (staff_id, client_id) VALUES (1, 3);
|
||||
-- INSERT INTO relationship (staff_id, client_id) VALUES (1, 4);
|
||||
-- INSERT INTO relationship (staff_id, client_id) VALUES (2, 5);
|
||||
-- INSERT INTO relationship (staff_id, client_id) VALUES (2, 6);
|
||||
|
||||
-- Note the plural:
|
||||
|
||||
-- WITH staff_members AS (SELECT users.nickname AS staff_name, users.id AS staff_id FROM users WHERE users.id IN (SELECT staff_id FROM staff WHERE active=true))
|
||||
|
||||
|
||||
-- SELECT staff_name from staff_members;
|
||||
-- SELECT client_name from client_members;
|
||||
|
||||
-- INSERT INTO officehours (staff_id, during) VALUES (1, '[2015-02-07 10:00, 2015-02-07 17:00)');
|
||||
-- INSERT INTO officehours (staff_id, during) VALUES (2, '[2015-02-07 12:00, 2015-02-07 15:00)');
|
||||
|
||||
-- Insert an appointment with a client
|
||||
-- WHERE the client's staffer has those office hours (DOES OVERLAP)
|
||||
|
||||
-- SELECT * FROM officehours INNER JOIN relationship
|
||||
-- ON relationship.staff_id = officehours.staff_id
|
||||
-- WHERE relationship.client_id = 3;
|
||||
|
||||
|
||||
|
||||
|
||||
-- SELECT add_appointment(3, '[2015-02-07 10:00, 2015-02-07 10:30)');
|
||||
-- SELECT add_appointment(4, '[2015-02-07 10:30, 2015-02-07 11:00)');
|
||||
-- SELECT add_appointment(5, '[2015-02-07 13:00, 2015-02-07 13:30)');
|
||||
-- SELECT add_appointment(6, '[2015-02-07 13:30, 2015-02-07 14:00)');
|
||||
|
||||
-- INSERT INTO appointments (client_id, during)
|
||||
-- SELECT 3, '[2015-02-07 10:00, 2015-02-07 10:30)'
|
||||
-- WHERE EXISTS (SELECT * FROM officehours INNER JOIN relationship
|
||||
-- ON relationship.staff_id = officehours.staff_id
|
||||
-- WHERE relationship.client_id = 3
|
||||
-- AND (officehours.during && '[2015-02-07 10:00, 2015-02-07 10:30)'))
|
||||
-- AND NOT EXISTS (SELECT * from appointments INNER JOIN
|
||||
--
|
||||
-- SELECT * FROM officehours INNER JOIN relationship
|
||||
-- ON relationship.staff_id = officehours.staff_id
|
||||
-- WHERE relationship.client_id = 3
|
||||
-- AND (officehours.during && '[2015-02-07 10:00, 2015-02-07 10:30)');
|
||||
--
|
||||
|
||||
-- SELECT client_id, during FROM appointments WHERE client_id IN (
|
||||
-- SELECT client_id FROM relationship WHERE staff_id IN (
|
||||
-- SELECT staff_id FROM relationship WHERE client_id = 3));
|
||||
--
|
||||
|
|
|
@ -0,0 +1,82 @@
|
|||
#!/usr/local/bin/hy
|
||||
|
||||
(def *version* "0.0.2")
|
||||
(import psycopg2)
|
||||
(require hy.contrib.anaphoric)
|
||||
|
||||
(defn connect []
|
||||
(psycopg2.connect "host='localhost' dbname='officehours' user='officehours' password='eatabug'"))
|
||||
|
||||
|
||||
(def users [
|
||||
(, "Alice" "alice@example.com")
|
||||
(, "Bob" "bob@example.com")
|
||||
(, "Carol" "carol@example.com")
|
||||
(, "Doug" "doug@example.com")
|
||||
(, "Ellen" "ellen@example.com")
|
||||
(, "Fred" "fred@example.com")])
|
||||
|
||||
(defn insert-user [user conn]
|
||||
(let [[curs (.cursor conn)]]
|
||||
(.execute curs "INSERT INTO users (nickname, email) values (%s, %s)" user)))
|
||||
|
||||
(let [[conn (connect)]]
|
||||
(for [user users] (insert-user user conn))
|
||||
(.commit conn))
|
||||
|
||||
(let [[conn (connect)]
|
||||
[curs (.cursor conn)]]
|
||||
(.execute curs "INSERT INTO staff (staff_id) SELECT id from users where email IN ('alice@example.com', 'bob@example.com');")
|
||||
(.execute curs "INSERT INTO clients (client_id) SELECT id from users where email NOT IN ('alice@example.com', 'bob@example.com');")
|
||||
(.execute curs "UPDATE staff SET active = True;")
|
||||
(.execute curs "UPDATE clients SET active = True;")
|
||||
(.commit conn))
|
||||
|
||||
(let [[conn (connect)]
|
||||
[curs (.cursor conn)]]
|
||||
(for [pair [(, 1 3) (, 1 4) (, 2 5) (, 2 6)]]
|
||||
(.execute curs "INSERT INTO relationship (staff_id, client_id) VALUES (%s, %s)" pair))
|
||||
(.commit conn))
|
||||
|
||||
(let [[conn (connect)]
|
||||
[curs (.cursor conn)]]
|
||||
(print "\nStaff Members:")
|
||||
(.execute curs "SELECT staff_name from staff_members")
|
||||
(for [staff (.fetchall curs)]
|
||||
(print (+ " " (get staff 0)))))
|
||||
|
||||
(let [[conn (connect)]
|
||||
[curs (.cursor conn)]]
|
||||
(print "\nClients:")
|
||||
(.execute curs "SELECT client_name from client_members")
|
||||
(for [staff (.fetchall curs)]
|
||||
(print (+ " " (get staff 0)))))
|
||||
|
||||
(let [[conn (connect)]
|
||||
[curs (.cursor conn)]]
|
||||
(.execute curs "INSERT INTO officehours (staff_id, during) VALUES (1, '[2015-02-07 10:00, 2015-02-07 17:00)');")
|
||||
(.execute curs "INSERT INTO officehours (staff_id, during) VALUES (2, '[2015-02-07 12:00, 2015-02-07 15:00)');")
|
||||
(.commit conn))
|
||||
|
||||
(let [[conn (connect)]
|
||||
[curs (.cursor conn)]
|
||||
[ops ["PERFORM add_appointment(3, '[2015-02-07 10:00, 2015-02-07 10:30)');"
|
||||
"PERFORM add_appointment(4, '[2015-02-07 10:30, 2015-02-07 11:00)');"
|
||||
"PERFORM add_appointment(5, '[2015-02-07 13:00, 2015-02-07 13:30)');"
|
||||
"PERFORM add_appointment(6, '[2015-02-07 13:30, 2015-02-07 14:00)');"]]]
|
||||
|
||||
(for [op ops]
|
||||
(print op)
|
||||
(.execute curs op)
|
||||
(.commit conn)))
|
||||
|
||||
(let [[conn (connect)]
|
||||
[curs (.cursor conn)]]
|
||||
(.execute curs "SELECT * FROM staff_appointments WHERE staff_id = 1")
|
||||
(for [meeting (.fetchall curs)]
|
||||
(print meeting)))
|
||||
|
||||
|
||||
|
||||
|
||||
|
Loading…
Reference in New Issue