1 ------------------------------------------------------------------------------
2 ------------------------------------------------------------------------------
4 --- DISPENSE IN POSTGRES REWRITE ---
5 --- Bernard Blackham <dagobah@ucc.gu.uwa.edu.au> ---
7 ------------------------------------------------------------------------------
8 ------------------------------------------------------------------------------
12 All the operations are done
18 DROP SEQUENCE request_id_seq;
19 DROP FUNCTION get_services(varchar);
23 DROP TABLE cokecontrollers;
24 DROP TABLE doorcontrollers;
25 DROP FUNCTION get_balance();
26 DROP FUNCTION get_balance(varchar);
29 CREATE OR REPLACE FUNCTION get_ident() RETURNS varchar AS 'pg_ident.so', 'get_ident' STRICT LANGUAGE C;
30 REVOKE ALL ON FUNCTION get_ident() FROM public;
33 user_name varchar(16) NOT NULL UNIQUE PRIMARY KEY,
34 user_balance_cents integer NOT NULL,
35 user_balance_bytes integer NOT NULL
38 CREATE TABLE cokecontrollers (
39 user_name varchar(16) UNIQUE references users(user_name),
43 CREATE TABLE sources (
44 source_name varchar(20) NOT NULL UNIQUE PRIMARY KEY
48 source_name varchar(20) REFERENCES sources(source_name),
49 item_name varchar(20) NOT NULL UNIQUE PRIMARY KEY,
50 item_cost_cents integer,
52 item_syntax varchar(80),
53 item_stock integer -- -1 for "in stock", 0 for "out of stock", > 0 for a value of stock, NULL for N/A
56 CREATE VIEW services AS
57 SELECT i.source_name as provider,
66 CREATE SEQUENCE request_id_seq START 1;
67 CREATE TABLE requests (
68 request_id integer NOT NULL DEFAULT nextval('request_id_seq'),
69 request_requestor_name varchar(16) REFERENCES users(user_name),
70 request_target_name varchar(16) REFERENCES users(user_name),
71 item_name varchar(20),
73 handled boolean NOT NULL DEFAULT false
76 -- request(target username, item_name, params)
77 CREATE OR REPLACE FUNCTION do_request(varchar(16), varchar(20), varchar[]) RETURNS boolean AS
84 RAISE EXCEPTION ''Got a null ident! Eepe!'';
86 IF NOT EXISTS(SELECT user_name FROM users WHERE user_name = $1) THEN
87 RAISE NOTICE ''Adding user %!!'', $1;
88 INSERT INTO users VALUES ($1, 0, 0);
90 INSERT INTO requests VALUES (DEFAULT, ident, $1, $2, $3);
94 LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
95 REVOKE ALL ON FUNCTION do_request(varchar(16),varchar(20),varchar[]) FROM public;
96 GRANT EXECUTE ON FUNCTION do_request(varchar(16), varchar(20), varchar[]) TO anondispense;
98 -- get_balance(target username)
99 CREATE OR REPLACE FUNCTION get_balance(varchar(16)) RETURNS users
100 AS 'SELECT * FROM users WHERE user_name = $1'
101 LANGUAGE sql EXTERNAL SECURITY DEFINER;
102 REVOKE ALL ON FUNCTION get_balance(varchar(16)) FROM public;
103 GRANT EXECUTE ON FUNCTION get_balance(varchar(16)) TO anondispense;
105 -- get_balance() ... returns everybody
106 CREATE OR REPLACE FUNCTION get_balance() RETURNS SETOF users
107 AS 'SELECT * FROM users'
108 LANGUAGE sql EXTERNAL SECURITY DEFINER;
109 REVOKE ALL ON FUNCTION get_balance() FROM public;
110 GRANT EXECUTE ON FUNCTION get_balance() TO anondispense;
112 -- internal functions follow
114 CREATE OR REPLACE FUNCTION refund(integer) RETURNS void AS
115 -- FIXME XXX DO this.
118 LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
119 REVOKE ALL ON FUNCTION refund(integer) FROM public;
121 CREATE OR REPLACE FUNCTION in_coke(varchar(16)) RETURNS boolean
122 AS 'SELECT EXISTS(SELECT * FROM cokecontrollers WHERE user_name = $1)'
123 LANGUAGE sql EXTERNAL SECURITY DEFINER;
124 REVOKE ALL ON FUNCTION in_coke(varchar(16)) FROM public;
126 CREATE OR REPLACE FUNCTION byte_to_cent_trigger() RETURNS "trigger" AS
129 bytes_per_cent INTEGER;
130 cents_per_meg INTEGER;
133 bytes_per_cent = 1024*1024/cents_per_meg;
134 IF NEW.user_balance_bytes > bytes_per_cent THEN
135 NEW.user_balance_cents = NEW.user_balance_cents - (NEW.user_balance_bytes/bytes_per_cent);
136 NEW.user_balance_bytes = NEW.user_balance_bytes % bytes_per_cent;
140 ' LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
141 REVOKE ALL ON FUNCTION byte_to_cent_trigger() FROM public;
142 CREATE TRIGGER byte_to_cent_trigger BEFORE INSERT OR UPDATE ON users FOR EACH ROW
143 EXECUTE PROCEDURE byte_to_cent_trigger();
145 CREATE OR REPLACE FUNCTION can_show(varchar(16), varchar(20)) RETURNS boolean AS
150 IF $1 NOT IN (SELECT user_name FROM users) THEN
154 IF ident = $1 OR in_coke(ident) THEN
159 ' LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
160 REVOKE ALL ON FUNCTION can_show(varchar(16), varchar(20)) FROM public;
161 CREATE OR REPLACE FUNCTION get_services(varchar(16)) RETURNS SETOF services AS
162 'SELECT * from services WHERE can_show($1, item_name)' LANGUAGE SQL EXTERNAL SECURITY DEFINER;
164 REVOKE ALL ON FUNCTION get_services(varchar(16)) FROM public;
165 GRANT EXECUTE ON FUNCTION get_services(varchar(16)) TO anondispense;
167 CREATE OR REPLACE FUNCTION first_request_handler() RETURNS "trigger" AS
174 -- Sanity check that requestor isn''t acting on somebody else''s behalf
175 -- when they''re not in coke.
176 IF NEW.request_target_name <> NEW.request_requestor_name AND NOT in_coke(NEW.request_requestor_name) THEN
177 RAISE EXCEPTION ''You are not allowed to perform operations on behalf of somebody else'';
180 -- Sanity check that the item is in the items table
181 IF NOT EXISTS (SELECT item_name FROM items where item_name = NEW.item_name) THEN
182 RAISE EXCEPTION ''We do not stock anything like that.'';
185 -- If we have a balance for the item, ensure there is sufficient money
186 SELECT INTO cost items.item_cost_cents FROM items WHERE item_name = NEW.item_name;
188 -- If the cost is null, it may vary and account keeping is done by the
190 IF cost IS NOT NULL THEN
191 SELECT INTO balance users.user_balance_cents FROM users WHERE user_name = NEW.request_target_name;
192 IF in_coke(NEW.request_requestor_name) THEN
193 IF balance - cost < -2000 THEN
194 -- They''re in coke, let them take balances to -$20.00
195 RAISE EXCEPTION ''You may not dispense below -$20.00.'';
198 -- Else simply ensure there is enough money
199 IF cost > balance THEN
200 RAISE EXCEPTION ''You do not have sufficient funds to do that.'';
204 -- Deduct money. This will be rolled back if any other triggers fail.
205 UPDATE users SET user_balance_cents = user_balance_cents - cost WHERE user_name = NEW.request_target_name;
208 -- Adjust stock levels as required
209 SELECT INTO stock item_stock FROM items WHERE item_name = NEW.item_name;
210 IF stock IS NOT NULL THEN
212 RAISE EXCEPTION ''We are out of stock of that item.'';
215 UPDATE items SET item_stock = item_stock - 1 WHERE item_name = NEW.item_name;
217 -- if item stock is -1, then stock levels are adjusted by other things
222 ' LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
223 REVOKE ALL ON FUNCTION first_request_handler() FROM public;
224 CREATE TRIGGER a00_first_request_trigger BEFORE INSERT ON requests FOR EACH ROW
225 EXECUTE PROCEDURE first_request_handler();
227 CREATE OR REPLACE FUNCTION final_request_handler() RETURNS "trigger" AS
230 IF NEW.handled = false THEN
231 RAISE EXCEPTION ''Nothing wanted to service your request!'';
235 ' LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
236 REVOKE ALL ON FUNCTION final_request_handler() FROM public;
237 CREATE TRIGGER zzz_last_request_trigger BEFORE INSERT ON requests FOR EACH ROW
238 EXECUTE PROCEDURE final_request_handler();
240 ------------------------------------------------------------------------------
241 --- Dummy Services ---
242 ------------------------------------------------------------------------------
244 INSERT INTO sources VALUES ('nothing');
246 INSERT INTO items VALUES ('nothing', 'nothing', NULL, NULL, NULL, NULL);
247 CREATE OR REPLACE FUNCTION nothing_nothing_trigger() RETURNS "trigger" AS
251 -- Check if we are to handle this request
252 IF NEW.handled OR NEW.item_name <> ''nothing'' THEN
256 -- Mark the request as having been dealt with
260 ' LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
261 REVOKE ALL ON FUNCTION nothing_nothing_trigger() FROM public;
262 CREATE TRIGGER nothing_nothing_trigger BEFORE INSERT ON requests FOR EACH ROW
263 EXECUTE PROCEDURE nothing_nothing_trigger();
265 DROP FUNCTION can_show_pre_nothing(varchar, varchar);
266 ALTER FUNCTION can_show(varchar(16), varchar(20)) RENAME TO can_show_pre_nothing;
267 CREATE FUNCTION can_show(varchar(16), varchar(20)) RETURNS boolean AS
268 'SELECT can_show_pre_nothing($1, $2) OR $2 = ''nothing'''
269 LANGUAGE SQL EXTERNAL SECURITY DEFINER;
270 REVOKE ALL ON FUNCTION can_show(varchar, varchar) FROM public;
272 ------------------------------------------------------------------------------
273 --- Coke Bank Services ---
274 ------------------------------------------------------------------------------
276 INSERT INTO sources VALUES ('cokebank');
278 INSERT INTO items VALUES ('cokebank', 'give', NULL, NULL, '<username> <cents>', NULL);
279 CREATE OR REPLACE FUNCTION cokebank_give_trigger() RETURNS "trigger" AS
284 source_user VARCHAR(8);
285 target_user VARCHAR(8);
286 source_user_balance INTEGER;
288 -- Check if we are to handle this request
289 IF NEW.handled OR NEW.item_name <> ''give'' THEN
293 -- Check for our two parameters, username, amount
294 IF NEW.params IS NULL THEN
295 RAISE EXCEPTION ''Missing parameters for give'';
297 IF array_upper(NEW.params, 1) <> 2 THEN
298 RAISE EXCEPTION ''Invalid number of parameters for give'';
300 IF NEW.params[1] NOT IN (SELECT user_name FROM users) THEN
301 RAISE EXCEPTION ''Invalid user to give to'';
303 give_amount = CAST(CAST(NEW.params[2] AS TEXT) AS INTEGER);
304 source_user = NEW.request_target_name;
305 target_user = NEW.params[1];
307 -- Can''t give to one''s self
308 IF source_user = target_user THEN
309 RAISE EXCEPTION ''You can''''t give to one''''s self'';
311 -- Can''t give negative amounts
312 IF give_amount <= 0 THEN
313 RAISE EXCEPTION ''You can only give positive balances'';
316 -- Check the appropriate balances
317 SELECT INTO source_user_balance users.user_balance_cents FROM users WHERE user_name = source_user;
319 IF source_user_balance < give_amount AND not in_coke(NEW.request_requestor_name) THEN
320 RAISE EXCEPTION ''You do not have sufficient funds to give that much!'';
323 -- Perform the request
324 UPDATE users SET user_balance_cents = user_balance_cents - give_amount WHERE user_name = source_user;
325 UPDATE users SET user_balance_cents = user_balance_cents + give_amount WHERE user_name = target_user;
326 -- Mark the request as having been dealt with
330 ' LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
331 REVOKE ALL ON FUNCTION cokebank_give_trigger() FROM public;
332 CREATE TRIGGER cokebank_give_trigger BEFORE INSERT ON requests FOR EACH ROW
333 EXECUTE PROCEDURE cokebank_give_trigger();
335 INSERT INTO items VALUES ('cokebank', 'acct', NULL, NULL, '<cents> <reason>', NULL);
336 CREATE OR REPLACE FUNCTION cokebank_acct_trigger() RETURNS "trigger" AS
340 target_user VARCHAR(8);
344 -- Check if we are to handle this request
345 IF NEW.handled OR NEW.item_name <> ''acct'' THEN
349 -- Check requestor is in coke
350 IF NOT in_coke(NEW.request_requestor_name) THEN
351 RAISE EXCEPTION ''You need to be in the coke group to use acct'';
354 -- Check for our two parameters, amount and reason
355 IF NEW.params IS NULL THEN
356 RAISE EXCEPTION ''No parameters supplied to acct'';
358 IF array_upper(NEW.params, 1) <> 2 THEN
359 RAISE EXCEPTION ''Invalid number of parameters for acct'';
361 amount = CAST(CAST(NEW.params[1] AS TEXT) AS INTEGER);
362 reason = NEW.params[2];
363 target_user = NEW.request_target_name;
365 -- Perform the request
366 UPDATE users SET user_balance_cents = user_balance_cents + amount WHERE user_name = target_user;
367 -- Mark the request as having been dealt with
371 ' LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
372 REVOKE ALL ON FUNCTION cokebank_acct_trigger() FROM public;
373 CREATE TRIGGER cokebank_acct_trigger BEFORE INSERT ON requests FOR EACH ROW
374 EXECUTE PROCEDURE cokebank_acct_trigger();
376 -- Don't show the acct function to non-coke people
377 DROP FUNCTION can_show_pre_cokebank(varchar, varchar);
378 ALTER FUNCTION can_show(varchar(16), varchar(20)) RENAME TO can_show_pre_cokebank;
379 CREATE FUNCTION can_show(varchar(16), varchar(20)) RETURNS boolean AS
380 'SELECT can_show_pre_cokebank($1, $2) AND NOT ($2 = ''acct'' AND NOT in_coke($1))'
381 LANGUAGE SQL EXTERNAL SECURITY DEFINER;
382 REVOKE ALL ON FUNCTION can_show(varchar, varchar) FROM public;
384 ------------------------------------------------------------------------------
385 --- Coke Machine Services ---
386 ------------------------------------------------------------------------------
388 INSERT INTO sources VALUES ('coke');
390 INSERT INTO items VALUES ('coke', 'passion pop', 80, array['0'], NULL, 8);
391 INSERT INTO items VALUES ('coke', 'vb', 80, array['1'], NULL, 0);
392 INSERT INTO items VALUES ('coke', 'emu export', 80, array['2'], NULL, 3);
393 INSERT INTO items VALUES ('coke', 'whiskey', 80, array['3'], NULL, 4);
394 INSERT INTO items VALUES ('coke', 'champagne', 80, array['4'], NULL, 9);
395 INSERT INTO items VALUES ('coke', 'grape juice', 80, array['5'], NULL, 1);
396 INSERT INTO items VALUES ('coke', 'coke powder', 80, array['6'], NULL, 11);
398 INSERT INTO items VALUES ('coke', 'update_coke', NULL, NULL, '<slot number> <new name> <new price> <stock count>', NULL);
400 DROP TABLE coke_requests;
401 CREATE TABLE coke_requests (
403 request_slot integer,
404 request_handled boolean NOT NULL DEFAULT false,
405 request_time timestamp DEFAULT now()
408 CREATE OR REPLACE FUNCTION update_slot_info(integer, varchar(20), integer, integer) RETURNS void AS
411 -- Check such a slot exists
412 IF NOT EXISTS(SELECT item_name FROM items WHERE item_data[1] = cast($1 as varchar) AND source_id = ''coke'') THEN
413 RAISE EXCEPTION ''There is no such slot %'', $1;
415 IF $2 IS NOT NULL THEN
416 UPDATE items SET item_name = $2 WHERE item_data[1] = cast($1 as varchar) and source_id = ''coke'';
418 IF $3 IS NOT NULL THEN
419 UPDATE items SET item_cost_cents = $3 WHERE item_data[1] = cast($1 as varchar) and source_id = ''coke'';
421 IF $4 IS NOT NULL THEN
422 UPDATE items SET item_stock = $4 WHERE item_data[1] = $1 and source_id = ''vend'';
425 ' LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
426 REVOKE ALL ON FUNCTION update_slot_info(integer, varchar, integer, integer) FROM public;
428 CREATE OR REPLACE FUNCTION dispense_slot(integer, integer) RETURNS void AS
430 elog(NOTICE, q(And out pops a drink!));
431 INSERT INTO coke_requests VALUES ($1, $2);
432 NOTIFY coke_requests;
433 ' LANGUAGE plperlu EXTERNAL SECURITY DEFINER;
434 REVOKE ALL ON FUNCTION dispense_slot(integer, integer) FROM public;
436 CREATE OR REPLACE FUNCTION coke_slot_trigger() RETURNS "trigger" AS
439 new_name VARCHAR(20);
443 -- Check if we are to handle this request
444 IF NEW.handled OR NOT EXISTS(SELECT item_name FROM items WHERE source_name = ''coke'' AND item_name = NEW.item_name) THEN
448 -- Check if we are wanted to update a slot
449 IF NEW.item_name = ''update_coke'' THEN
451 IF NEW.params IS NULL THEN
452 RAISE EXCEPTION ''Missing parameters for update_coke'';
454 IF array_upper(NEW.params, 1) <> 4 THEN
455 RAISE EXCEPTION ''Invalid number of parameters for update_coke'';
457 IF NEW.params[1] NOT IN (SELECT item_data[1] FROM items WHERE source_name = ''coke'' and item_data[1] IS NOT NULL) THEN
458 new_name = NEW.params[1];
459 RAISE EXCEPTION ''No idea what slot % is.'', new_name;
461 new_name = NEW.params[2];
462 IF NEW.params[3] <> '''' THEN
463 new_cost = CAST(CAST(NEW.params[3] AS TEXT) AS INTEGER);
464 IF new_cost <= 0 THEN
465 RAISE EXCEPTION ''Amount must be positive'';
467 UPDATE items SET item_cost_cents = new_cost WHERE source_name = ''coke'' AND item_data[1] = NEW.params[1];
469 IF NEW.params[4] <> '''' THEN
470 new_stock = CAST(CAST(NEW.params[4] AS TEXT) AS INTEGER);
471 IF new_stock <= -1 THEN
472 RAISE EXCEPTION ''Stock count must be -1 or >= 0'';
474 UPDATE items SET item_stock = new_stock WHERE source_name = ''coke'' AND item_data[1] = NEW.params[1];
476 UPDATE items SET item_name = new_name WHERE source_name = ''coke'' AND item_data[1] = NEW.params[1];
479 -- The default handler will have checked that we have stock and
480 -- deducted money et al.
482 -- So if we get this far, we don''t need to care about much.
483 -- Dropping the drink & checking stock occurs in the AFTER-INSERT trigger.
485 -- Mark the request as having been dealt with
489 ' LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
490 REVOKE ALL ON FUNCTION coke_slot_trigger() FROM public;
491 CREATE TRIGGER coke_slot_trigger BEFORE INSERT ON requests FOR EACH ROW
492 EXECUTE PROCEDURE coke_slot_trigger();
494 CREATE OR REPLACE FUNCTION coke_slot_dispense() RETURNS "trigger" AS
500 IF NEW.handled AND EXISTS(SELECT item_name FROM items WHERE source_name = ''coke'' AND item_name = NEW.item_name) THEN
501 -- Drop a drink and update stock
502 SELECT INTO slotnum items.item_data[1] FROM items WHERE item_name = NEW.item_name and source_name = ''coke'';
503 PERFORM dispense_slot(NEW.request_id, slotnum);
507 ' LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
508 REVOKE ALL ON FUNCTION coke_slot_dispense() FROM public;
509 CREATE TRIGGER coke_slot_dispense AFTER INSERT ON requests FOR EACH ROW
510 EXECUTE PROCEDURE coke_slot_dispense();
512 -- Don't show the update function to non-coke people
513 DROP FUNCTION can_show_pre_coke(varchar, varchar);
514 ALTER FUNCTION can_show(varchar(16), varchar(20)) RENAME TO can_show_pre_coke;
515 CREATE FUNCTION can_show(varchar(16), varchar(20)) RETURNS boolean AS
516 'SELECT can_show_pre_coke($1, $2) AND NOT ($2 = ''update_coke'' AND NOT in_coke($1))'
517 LANGUAGE SQL EXTERNAL SECURITY DEFINER;
518 REVOKE ALL ON FUNCTION can_show(varchar, varchar) FROM public;
520 ------------------------------------------------------------------------------
521 --- Vending Machine Services ---
522 ------------------------------------------------------------------------------
524 INSERT INTO sources VALUES ('vend');
526 INSERT INTO items VALUES ('vend', 'twisties', 120, array['11'], NULL, 8);
527 INSERT INTO items VALUES ('vend', 'cheese and onion', 125, array['21'], NULL, 0);
528 INSERT INTO items VALUES ('vend', 'update_vend', NULL, NULL, '<slot number> <new name> <new price> <new count>', NULL);
530 DROP TABLE vend_requests;
531 CREATE TABLE vend_requests (
533 request_slot varchar(2),
534 request_handled boolean NOT NULL DEFAULT false,
535 request_time timestamp DEFAULT now()
537 GRANT SELECT ON vend_requests TO vendserver;
539 CREATE OR REPLACE FUNCTION vend_success(integer) RETURNS void AS
540 'UPDATE vend_requests SET request_handled = true WHERE request_id = $1'
541 LANGUAGE SQL EXTERNAL SECURITY DEFINER;
542 REVOKE ALL ON FUNCTION valid_vend_slot(varchar(2)) FROM public;
543 GRANT EXECUTE ON FUNCTION vend_success(integer) TO vendserver;
545 CREATE OR REPLACE FUNCTION vend_failed(integer) RETURNS void AS
548 UPDATE vend_requests SET request_handled = true WHERE request_id = $1;
552 LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
553 REVOKE ALL ON FUNCTION valid_vend_slot(varchar(2)) FROM public;
554 GRANT EXECUTE ON FUNCTION vend_failed(integer) TO vendserver;
556 CREATE OR REPLACE FUNCTION valid_vend_slot(varchar(2)) RETURNS boolean AS
557 'SELECT $1 ~ ''^[0-9]{2}$''' LANGUAGE SQL EXTERNAL SECURITY DEFINER;
558 REVOKE ALL ON FUNCTION valid_vend_slot(varchar(2)) FROM public;
560 CREATE OR REPLACE FUNCTION update_vend_slot_info(varchar(2), varchar(20), integer, integer) RETURNS void AS
563 -- Check such a slot exists
564 IF NOT valid_vend_slot($1) THEN
565 RAISE EXCEPTION ''There is no such slot %'', $1;
567 IF $2 IS NOT NULL THEN
568 UPDATE items SET item_name = $2 WHERE item_data[1] = $1 and source_id = ''vend'';
570 IF $3 IS NOT NULL THEN
571 UPDATE items SET item_cost_cents = $3 WHERE item_data[1] = $1 and source_id = ''vend'';
573 IF $4 IS NOT NULL THEN
574 UPDATE items SET item_stock = $4 WHERE item_data[1] = $1 and source_id = ''vend'';
577 ' LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
578 REVOKE ALL ON FUNCTION update_vend_slot_info(varchar(2), varchar, integer, integer) FROM public;
580 CREATE OR REPLACE FUNCTION vend_slot(integer, varchar(2)) RETURNS void AS
583 RAISE NOTICE ''And out pops a snack'';
584 INSERT INTO vend_requests (request_id, request_slot) VALUES ($1, $2);
585 NOTIFY vend_requests;
588 ' LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
589 REVOKE ALL ON FUNCTION vend_slot(integer, varchar(2)) FROM public;
591 CREATE OR REPLACE FUNCTION vend_slot_trigger() RETURNS "trigger" AS
594 new_name VARCHAR(20);
598 -- Check if we are to handle this request
599 IF NEW.handled OR NOT EXISTS(SELECT item_name FROM items WHERE source_name = ''vend'' AND item_name = NEW.item_name) THEN
603 -- Check if we are wanted to update a slot
604 IF NEW.item_name = ''update_vend'' THEN
606 IF NEW.params IS NULL THEN
607 RAISE EXCEPTION ''Missing parameters for update_vend'';
609 IF array_upper(NEW.params, 1) <> 4 THEN
610 RAISE EXCEPTION ''Invalid number of parameters for update_vend'';
612 IF NEW.params[1] NOT IN (SELECT item_data[1] FROM items WHERE source_name = ''vend'' and item_data[1] IS NOT NULL) THEN
613 new_name = NEW.params[1];
614 RAISE EXCEPTION ''No idea what slot % is.'', new_name;
616 new_name = NEW.params[2];
617 IF NEW.params[3] <> '''' THEN
618 new_cost = CAST(CAST(NEW.params[3] AS TEXT) AS INTEGER);
619 IF new_cost <= 0 THEN
620 RAISE EXCEPTION ''Amount must be positive'';
622 UPDATE items SET item_cost_cents = new_cost WHERE source_name = ''vend'' AND item_data[1] = NEW.params[1];
624 IF NEW.params[4] <> '''' THEN
625 new_stock = CAST(CAST(NEW.params[4] AS TEXT) AS INTEGER);
626 IF new_stock <= -1 THEN
627 RAISE EXCEPTION ''Stock count must be -1 or >= 0'';
629 UPDATE items SET item_stock = new_stock WHERE source_name = ''vend'' AND item_data[1] = NEW.params[1];
631 UPDATE items SET item_name = new_name WHERE source_name = ''vend'' AND item_data[1] = NEW.params[1];
634 -- The default handler will have checked that we have stock and
635 -- deducted money et al.
637 -- So if we get this far, we don''t need to care about much.
638 -- Dropping the snack occurs in the AFTER-INSERT trigger.
640 -- Mark the request as having been dealt with
644 ' LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
645 REVOKE ALL ON FUNCTION vend_slot_trigger() FROM public;
646 CREATE TRIGGER vend_slot_trigger BEFORE INSERT ON requests FOR EACH ROW
647 EXECUTE PROCEDURE vend_slot_trigger();
649 CREATE OR REPLACE FUNCTION vend_slot_dispense() RETURNS "trigger" AS
654 IF NEW.handled AND EXISTS(SELECT item_name FROM items WHERE source_name = ''vend'' AND item_name = NEW.item_name) THEN
655 -- Drop a snack and update stock
656 SELECT INTO slotnum items.item_data[1] FROM items WHERE item_name = NEW.item_name and source_name = ''vend'';
657 PERFORM vend_slot(NEW.request_id, slotnum);
661 ' LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
662 REVOKE ALL ON FUNCTION vend_slot_dispense() FROM public;
663 CREATE TRIGGER vend_slot_dispense AFTER INSERT ON requests FOR EACH ROW
664 EXECUTE PROCEDURE vend_slot_dispense();
666 -- Don't show the update function to non-coke people
667 DROP FUNCTION can_show_pre_vend(varchar, varchar);
668 ALTER FUNCTION can_show(varchar(16), varchar(20)) RENAME TO can_show_pre_vend;
669 CREATE FUNCTION can_show(varchar(16), varchar(20)) RETURNS boolean AS
670 'SELECT can_show_pre_vend($1, $2) AND NOT ($2 = ''update_vend'' AND NOT in_coke($1))'
671 LANGUAGE SQL EXTERNAL SECURITY DEFINER;
672 REVOKE ALL ON FUNCTION can_show(varchar, varchar) FROM public;
674 ------------------------------------------------------------------------------
675 --- UCC Door Services ---
676 ------------------------------------------------------------------------------
678 CREATE TABLE doorcontrollers (
679 user_name varchar(16) UNIQUE references users(user_name),
683 CREATE OR REPLACE FUNCTION in_door(varchar(16)) RETURNS boolean
684 AS 'SELECT EXISTS(SELECT user_name FROM doorcontrollers WHERE user_name = $1)'
685 LANGUAGE sql EXTERNAL SECURITY DEFINER;
686 REVOKE ALL ON FUNCTION in_door(varchar(16)) FROM public;
688 INSERT INTO sources VALUES ('door');
690 INSERT INTO items VALUES ('door', 'opendoor', NULL, NULL, NULL, NULL);
692 CREATE OR REPLACE FUNCTION open_door() RETURNS void AS
694 system("/usr/bin/sudo /usr/sbin/opendoor");
695 ' LANGUAGE plperlu EXTERNAL SECURITY DEFINER;
696 REVOKE ALL ON FUNCTION open_door() FROM public;
698 CREATE OR REPLACE FUNCTION door_open_trigger() RETURNS "trigger" AS
701 -- Check if we are to handle this request
702 IF NEW.handled OR NOT EXISTS(SELECT item_name FROM items WHERE source_name = ''door'' AND item_name = NEW.item_name) THEN
706 -- You can''t open the door for somebody else
707 IF NEW.request_requestor_name <> NEW.request_target_name THEN
708 RAISE EXCEPTION ''You can''''t open the door for somebody else.'';
711 -- Ensure the user is in the door group
712 IF NOT in_door(NEW.request_requestor_name) THEN
713 RAISE EXCEPTION ''You are not permitted to open the door.'';
716 -- Mark the request as having been dealt with
720 ' LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
721 REVOKE ALL ON FUNCTION door_open_trigger() FROM public;
722 CREATE TRIGGER door_open_trigger BEFORE INSERT ON requests FOR EACH ROW
723 EXECUTE PROCEDURE door_open_trigger();
725 CREATE OR REPLACE FUNCTION door_open_do() RETURNS "trigger" AS
728 IF NEW.handled AND NEW.item_name = ''opendoor'' THEN
733 ' LANGUAGE plpgsql EXTERNAL SECURITY DEFINER;
734 REVOKE ALL ON FUNCTION door_open_do() FROM public;
735 CREATE TRIGGER door_open_do AFTER INSERT ON requests FOR EACH ROW
736 EXECUTE PROCEDURE door_open_do();
738 -- Don't show the door functions to non-door people
739 DROP FUNCTION can_show_pre_door(varchar, varchar);
740 ALTER FUNCTION can_show(varchar(16), varchar(20)) RENAME TO can_show_pre_door;
741 CREATE FUNCTION can_show(varchar(16), varchar(20)) RETURNS boolean AS
742 'SELECT can_show_pre_door($1, $2) AND NOT ($2 = ''opendoor'' AND (NOT in_door($1)))' LANGUAGE SQL EXTERNAL SECURITY DEFINER;
743 REVOKE ALL ON FUNCTION can_show(varchar, varchar) FROM public;