root / pykota / trunk / initscripts / pykota-postgresql.sql @ 910

Revision 910, 5.4 kB (checked in by jalet, 21 years ago)

New database schema for users' account balance

  • Property svn:eol-style set to native
  • Property svn:keywords set to Author Date Id Revision
Line 
1--
2-- PyKota - Print Quotas for CUPS
3--
4-- (c) 2003 Jerome Alet <alet@librelogiciel.com>
5-- This program is free software; you can redistribute it and/or modify
6-- it under the terms of the GNU General Public License as published by
7-- the Free Software Foundation; either version 2 of the License, or
8-- (at your option) any later version.
9--
10-- This program is distributed in the hope that it will be useful,
11-- but WITHOUT ANY WARRANTY; without even the implied warranty of
12-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
13-- GNU General Public License for more details.
14--
15-- You should have received a copy of the GNU General Public License
16-- along with this program; if not, write to the Free Software
17-- Foundation, Inc., 59 Temple Place, Suite 330, Boston, MA 02111-1307, USA.
18--
19-- $Id$
20--
21-- $Log$
22-- Revision 1.11  2003/04/14 19:58:59  jalet
23-- New database schema for users' account balance
24--
25-- Revision 1.10  2003/04/10 21:47:20  jalet
26-- Job history added. Upgrade script neutralized for now !
27--
28-- Revision 1.9  2003/04/09 20:11:29  jalet
29-- Added a field to save the action taken for this job (Allow, Deny)
30--
31-- Revision 1.8  2003/04/09 20:09:34  jalet
32-- New table to keep job history
33--
34-- Revision 1.7  2003/04/08 20:38:08  jalet
35-- The last job Id is saved now for each printer, this will probably
36-- allow other accounting methods in the future.
37--
38-- Revision 1.6  2003/03/29 13:45:27  jalet
39-- GPL paragraphs were incorrectly (from memory) copied into the sources.
40-- Two README files were added.
41-- Upgrade script for PostgreSQL pre 1.01 schema was added.
42--
43-- Revision 1.5  2003/03/12 19:06:08  jalet
44-- Initial support for groups added.
45--
46-- Revision 1.4  2003/02/27 08:40:14  jalet
47-- DATETIME is not supported anymore in PostgreSQL 7.3 it seems, but
48-- TIMESTAMP is.
49--
50-- Revision 1.3  2003/02/26 20:34:22  jalet
51-- Default value for printer page counter set to 0
52--
53-- Revision 1.2  2003/02/08 22:12:09  jalet
54-- Life time counter for users and groups added.
55--
56-- Revision 1.1  2003/02/05 21:28:17  jalet
57-- Initial import into CVS
58--
59--
60--
61
62--
63-- PyKota Database creation script for PostgreSQL
64--
65-- Launch this as PostgreSQL administrator with \i
66--
67
68
69--
70-- Create the print quota database
71--
72CREATE DATABASE pykota;
73
74--
75-- Create the print quota database users
76--
77CREATE USER pykotauser;
78CREATE USER pykotaadmin;
79
80--
81-- Now connect to the new database
82--
83\connect pykota
84
85--
86-- Create the users table
87--
88CREATE TABLE users(id SERIAL PRIMARY KEY NOT NULL,
89                   username TEXT UNIQUE NOT NULL,
90                   balance FLOAT DEFAULT 0.0,
91                   lieftimepaid FLOAT DEFAULT 0.0,
92                   limitby TEXT DEFAULT 'quota');
93                   
94--
95-- Create the groups table
96--
97CREATE TABLE groups(id SERIAL PRIMARY KEY NOT NULL,
98                    groupname TEXT UNIQUE NOT NULL);
99                   
100--
101-- Create the printers table
102--
103CREATE TABLE printers(id SERIAL PRIMARY KEY NOT NULL,
104                      printername TEXT UNIQUE NOT NULL,
105                      priceperpage FLOAT DEFAULT 0.0,
106                      priceperjob FLOAT DEFAULT 0.0);
107                   
108--
109-- Create the print quota table for users
110--
111CREATE TABLE userpquota(id SERIAL PRIMARY KEY NOT NULL,
112                        userid INT4 REFERENCES users(id),
113                        printerid INT4 REFERENCES printers(id),
114                        lifepagecounter INT4 DEFAULT 0,
115                        pagecounter INT4 DEFAULT 0,
116                        softlimit INT4,
117                        hardlimit INT4,
118                        datelimit TIMESTAMP);
119                       
120--
121-- Create the job history table
122--
123CREATE TABLE jobhistory(id SERIAL PRIMARY KEY NOT NULL,
124                        jobid TEXT,
125                        userid INT4 REFERENCES users(id),
126                        printerid INT4 REFERENCES printers(id),
127                        pagecounter INT4 DEFAULT 0,
128                        jobsize INT4,
129                        action TEXT,
130                        jobdate TIMESTAMP DEFAULT now());
131                       
132--
133-- Create the print quota table for groups
134--
135CREATE TABLE grouppquota(id SERIAL PRIMARY KEY NOT NULL,
136                         groupid INT4 REFERENCES groups(id),
137                         printerid INT4 REFERENCES printers(id),
138                         softlimit INT4,
139                         hardlimit INT4,
140                         datelimit TIMESTAMP);
141                       
142--                         
143-- Create the groups/members relationship
144--
145CREATE TABLE groupsmembers(groupid INT4 REFERENCES groups(id),
146                           userid INT4 REFERENCES users(id),
147                           PRIMARY KEY (groupid, userid));
148
149--                       
150-- Set some ACLs                       
151--
152REVOKE ALL ON users, groups, printers, userpquota, grouppquota, groupsmembers, jobhistory FROM public;                       
153GRANT SELECT, INSERT, UPDATE, DELETE, REFERENCES ON users, groups, printers, userpquota, grouppquota, groupsmembers, jobhistory TO pykotaadmin;
154GRANT SELECT, UPDATE ON users_id_seq, groups_id_seq, printers_id_seq, userpquota_id_seq, grouppquota_id_seq, jobhistory_id_seq TO pykotaadmin;
155GRANT SELECT, UPDATE ON printers, userpquota, grouppquota TO pykotauser;
156GRANT SELECT ON users, groups, groupsmembers TO pykotauser;
157GRANT SELECT, INSERT, UPDATE ON jobhistory TO pykotauser;
158GRANT SELECT, UPDATE ON jobhistory_id_seq TO pykotauser;
Note: See TracBrowser for help on using the browser.