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

Revision 1520, 6.8 kB (checked in by jalet, 20 years ago)

Now stores the job's size in bytes in the database.
Preliminary work on payments storage : database schemas are OK now,
but no code to store payments yet.
Removed schema picture, not relevant anymore.

  • Property svn:eol-style set to native
  • Property svn:keywords set to Author Date Id Revision
Line 
1--
2-- PyKota - Print Quotas for CUPS and LPRng
3--
4-- (c) 2003-2004 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.10  2004/06/03 23:14:09  jalet
23-- Now stores the job's size in bytes in the database.
24-- Preliminary work on payments storage : database schemas are OK now,
25-- but no code to store payments yet.
26-- Removed schema picture, not relevant anymore.
27--
28-- Revision 1.9  2004/05/13 11:15:29  jalet
29-- Added hostname field in job history
30--
31-- Revision 1.8  2004/01/08 14:10:32  jalet
32-- Copyright year changed.
33--
34-- Revision 1.7  2003/12/27 16:49:25  uid67467
35-- Should be ok now.
36--
37-- Revision 1.6  2003/11/23 19:01:36  jalet
38-- Job price added to history
39--
40-- Revision 1.5  2003/11/21 14:28:45  jalet
41-- More complete job history.
42--
43-- Revision 1.4  2003/07/16 21:53:07  jalet
44-- Really big modifications wrt new configuration file's location and content.
45--
46-- Revision 1.3  2003/07/09 20:17:07  jalet
47-- Email field added to PostgreSQL schema
48--
49-- Revision 1.2  2003/06/10 16:37:54  jalet
50-- Deletion of the second user which is not needed anymore.
51-- Added a debug configuration field in /etc/pykota.conf
52-- All queries can now be sent to the logger in debug mode, this will
53-- greatly help improve performance when time for this will come.
54--
55-- Revision 1.1  2003/06/05 07:12:31  jalet
56-- Reorganization of directories
57--
58--
59--
60
61--
62-- PyKota Database creation script for PostgreSQL
63--
64-- Launch this as PostgreSQL administrator with \i
65--
66
67
68--
69-- Create the print quota database
70--
71CREATE DATABASE pykota;
72
73--
74-- Create the print quota database users
75--
76CREATE USER pykotaadmin;
77CREATE USER pykotauser;
78
79--
80-- Now connect to the new database
81--
82\connect pykota
83
84--
85-- Create the users table
86--
87CREATE TABLE users(id SERIAL PRIMARY KEY NOT NULL,
88                   username TEXT UNIQUE NOT NULL,
89                   email TEXT, 
90                   balance FLOAT DEFAULT 0.0,
91                   lifetimepaid 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                    limitby TEXT DEFAULT 'quota');
100                   
101--
102-- Create the printers table
103--
104CREATE TABLE printers(id SERIAL PRIMARY KEY NOT NULL,
105                      printername TEXT UNIQUE NOT NULL,
106                      priceperpage FLOAT DEFAULT 0.0,
107                      priceperjob FLOAT DEFAULT 0.0);
108                   
109--
110-- Create the print quota table for users
111--
112CREATE TABLE userpquota(id SERIAL PRIMARY KEY NOT NULL,
113                        userid INT4 REFERENCES users(id),
114                        printerid INT4 REFERENCES printers(id),
115                        lifepagecounter INT4 DEFAULT 0,
116                        pagecounter INT4 DEFAULT 0,
117                        softlimit INT4,
118                        hardlimit INT4,
119                        datelimit TIMESTAMP);
120CREATE UNIQUE INDEX userpquota_up_id_ix ON userpquota (userid, printerid);
121                       
122--
123-- Create the job history table
124--
125CREATE TABLE jobhistory(id SERIAL PRIMARY KEY NOT NULL,
126                        jobid TEXT,
127                        userid INT4,
128                        printerid INT4,
129                        pagecounter INT4 DEFAULT 0,
130                        jobsizebytes INT8,
131                        jobsize INT4,
132                        jobprice FLOAT,
133                        action TEXT,
134                        filename TEXT,
135                        title TEXT,
136                        copies INT4,
137                        options TEXT,
138                        hostname TEXT,
139                        jobdate TIMESTAMP DEFAULT now(),
140                        CONSTRAINT checkUserPQuota FOREIGN KEY (userid, printerid) REFERENCES userpquota(userid, printerid));
141CREATE INDEX jobhistory_p_id_ix ON jobhistory (printerid);
142CREATE INDEX jobhistory_pd_id_ix ON jobhistory (printerid, jobdate);
143CREATE INDEX jobhistory_hostname_ix ON jobhistory (hostname);
144                       
145--
146-- Create the print quota table for groups
147--
148CREATE TABLE grouppquota(id SERIAL PRIMARY KEY NOT NULL,
149                         groupid INT4 REFERENCES groups(id),
150                         printerid INT4 REFERENCES printers(id),
151                         softlimit INT4,
152                         hardlimit INT4,
153                         datelimit TIMESTAMP);
154CREATE UNIQUE INDEX grouppquota_up_id_ix ON grouppquota (groupid, printerid);
155                       
156--                         
157-- Create the groups/members relationship
158--
159CREATE TABLE groupsmembers(groupid INT4 REFERENCES groups(id),
160                           userid INT4 REFERENCES users(id),
161                           PRIMARY KEY (groupid, userid));
162                           
163--                         
164-- Create the printer groups relationship
165--
166CREATE TABLE printergroupsmembers(groupid INT4 REFERENCES printers(id),
167                           printerid INT4 REFERENCES printers(id),
168                           PRIMARY KEY (groupid, printerid));
169--
170-- Create the table for payments
171--
172CREATE TABLE payments (id SERIAL PRIMARY KEY NOT NULL,
173                       userid INT4 REFERENCES users(id),
174                       amount FLOAT,
175                       date TIMESTAMP DEFAULT now());
176CREATE INDEX payments_date_ix ON payments (date);
177
178--                       
179-- Set some ACLs                       
180--
181REVOKE ALL ON users, groups, printers, userpquota, grouppquota, groupsmembers, printergroupsmembers, jobhistory, payments FROM public;                       
182REVOKE ALL ON users_id_seq, groups_id_seq, printers_id_seq, userpquota_id_seq, grouppquota_id_seq, jobhistory_id_seq, payments_id_seq FROM public;
183
184GRANT SELECT, INSERT, UPDATE, DELETE, REFERENCES ON users, groups, printers, userpquota, grouppquota, groupsmembers, printergroupsmembers, jobhistory, payments TO pykotaadmin;
185GRANT SELECT, UPDATE ON users_id_seq, groups_id_seq, printers_id_seq, userpquota_id_seq, grouppquota_id_seq, jobhistory_id_seq, payments_id_seq TO pykotaadmin;
186GRANT SELECT ON users, groups, printers, userpquota, grouppquota, groupsmembers, printergroupsmembers, jobhistory, payments TO pykotauser;
Note: See TracBrowser for help on using the browser.