Redbrick User management tool
You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

45 lines
1.8 KiB

  1. -- $Id$
  2. CREATE TABLE "users" (
  3. username VARCHAR(8) PRIMARY KEY,
  4. usertype VARCHAR NOT NULL CONSTRAINT valid_usertype REFERENCES usertypes,
  5. name VARCHAR NOT NULL CONSTRAINT require_name CHECK (name != ''),
  6. newbie BOOLEAN NOT NULL,
  7. email VARCHAR NOT NULL CONSTRAINT require_email CHECK (email != ''),
  8. id INT UNIQUE CONSTRAINT require_id CHECK ((usertype != 'member' AND usertype != 'associat' AND usertype != 'staff') OR (id IS NOT NULL AND id > 0)),
  9. course VARCHAR CONSTRAINT require_course CHECK (usertype != 'member' OR (course IS NOT NULL AND course != '')),
  10. year VARCHAR CONSTRAINT require_year CHECK (usertype != 'member' OR year IS NOT NULL),
  11. years_paid INT CONSTRAINT require_years_paid CHECK ((usertype != 'member' AND usertype != 'associat' AND usertype != 'staff') OR (years_paid IS NOT NULL)),
  12. created_by VARCHAR(8) NOT NULL CONSTRAINT require_created_by CHECK (created_by != ''),
  13. created_at TIMESTAMP(0) NOT NULL DEFAULT now(),
  14. updated_by VARCHAR(8) NOT NULL CONSTRAINT require_updated_by CHECK (updated_by != ''),
  15. updated_at TIMESTAMP(0) NOT NULL DEFAULT now(),
  16. -- Following are optional or non-essential additions
  17. birthday DATE
  18. );
  19. GRANT ALL ON users TO root;
  20. GRANT SELECT ON users TO webgroup;
  21. GRANT SELECT ON users TO www;
  22. /*
  23. * Set updated_at to current time for each update
  24. */
  25. CREATE FUNCTION users_updated_at_stamp () RETURNS OPAQUE AS '
  26. DECLARE
  27. curtime timestamp;
  28. BEGIN
  29. curtime = ''now'';
  30. NEW.updated_at := curtime;
  31. RETURN NEW;
  32. END;
  33. ' LANGUAGE 'plpgsql';
  34. CREATE TRIGGER users_updated_at BEFORE UPDATE ON users
  35. FOR EACH ROW EXECUTE PROCEDURE users_updated_at_stamp();