1 | -- |
---|
2 | -- PyKota - Print Quotas for CUPS and LPRng |
---|
3 | -- |
---|
4 | -- (c) 2003, 2004, 2005, 2006 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., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA. |
---|
18 | -- |
---|
19 | -- $Id$ |
---|
20 | -- |
---|
21 | -- |
---|
22 | |
---|
23 | -- |
---|
24 | -- PyKota Database creation script for PostgreSQL |
---|
25 | -- |
---|
26 | -- Launch this as PostgreSQL administrator with \i |
---|
27 | -- |
---|
28 | |
---|
29 | |
---|
30 | -- |
---|
31 | -- Create the print quota database |
---|
32 | -- |
---|
33 | CREATE DATABASE pykota; |
---|
34 | |
---|
35 | -- |
---|
36 | -- Create the print quota database users |
---|
37 | -- |
---|
38 | CREATE USER pykotaadmin; |
---|
39 | CREATE USER pykotauser; |
---|
40 | |
---|
41 | -- |
---|
42 | -- Now connect to the new database |
---|
43 | -- |
---|
44 | \connect pykota |
---|
45 | |
---|
46 | -- |
---|
47 | -- Create the users table |
---|
48 | -- |
---|
49 | CREATE TABLE users(id SERIAL PRIMARY KEY NOT NULL, |
---|
50 | username TEXT UNIQUE NOT NULL, |
---|
51 | email TEXT, |
---|
52 | balance FLOAT DEFAULT 0.0, |
---|
53 | lifetimepaid FLOAT DEFAULT 0.0, |
---|
54 | limitby TEXT DEFAULT 'quota', |
---|
55 | description TEXT, |
---|
56 | overcharge FLOAT NOT NULL DEFAULT 1.0); |
---|
57 | |
---|
58 | -- |
---|
59 | -- Create the groups table |
---|
60 | -- |
---|
61 | CREATE TABLE groups(id SERIAL PRIMARY KEY NOT NULL, |
---|
62 | groupname TEXT UNIQUE NOT NULL, |
---|
63 | description TEXT, |
---|
64 | limitby TEXT DEFAULT 'quota'); |
---|
65 | |
---|
66 | -- |
---|
67 | -- Create the printers table |
---|
68 | -- |
---|
69 | CREATE TABLE printers(id SERIAL PRIMARY KEY NOT NULL, |
---|
70 | printername TEXT UNIQUE NOT NULL, |
---|
71 | description TEXT, |
---|
72 | priceperpage FLOAT DEFAULT 0.0, |
---|
73 | priceperjob FLOAT DEFAULT 0.0, |
---|
74 | passthrough BOOLEAN DEFAULT FALSE, |
---|
75 | maxjobsize INT4); |
---|
76 | |
---|
77 | -- |
---|
78 | -- Create the print quota table for users |
---|
79 | -- |
---|
80 | CREATE TABLE userpquota(id SERIAL PRIMARY KEY NOT NULL, |
---|
81 | userid INT4 REFERENCES users(id), |
---|
82 | printerid INT4 REFERENCES printers(id), |
---|
83 | lifepagecounter INT4 DEFAULT 0, |
---|
84 | pagecounter INT4 DEFAULT 0, |
---|
85 | softlimit INT4, |
---|
86 | hardlimit INT4, |
---|
87 | datelimit TIMESTAMP, |
---|
88 | maxjobsize INT4, |
---|
89 | warncount INT4 DEFAULT 0); |
---|
90 | CREATE INDEX userpquota_u_id_ix ON userpquota (userid); |
---|
91 | CREATE INDEX userpquota_p_id_ix ON userpquota (printerid); |
---|
92 | CREATE UNIQUE INDEX userpquota_up_id_ix ON userpquota (userid, printerid); |
---|
93 | |
---|
94 | -- |
---|
95 | -- Create the job history table |
---|
96 | -- |
---|
97 | CREATE TABLE jobhistory(id SERIAL PRIMARY KEY NOT NULL, |
---|
98 | jobid TEXT, |
---|
99 | userid INT4, |
---|
100 | printerid INT4, |
---|
101 | pagecounter INT4 DEFAULT 0, |
---|
102 | jobsizebytes INT8, |
---|
103 | jobsize INT4, |
---|
104 | jobprice FLOAT, |
---|
105 | action TEXT, |
---|
106 | filename TEXT, |
---|
107 | title TEXT, |
---|
108 | copies INT4, |
---|
109 | options TEXT, |
---|
110 | hostname TEXT, |
---|
111 | md5sum TEXT, |
---|
112 | pages TEXT, |
---|
113 | billingcode TEXT, |
---|
114 | precomputedjobsize INT4, |
---|
115 | precomputedjobprice FLOAT, |
---|
116 | jobdate TIMESTAMP DEFAULT now(), |
---|
117 | CONSTRAINT checkUserPQuota FOREIGN KEY (userid, printerid) REFERENCES userpquota(userid, printerid)); |
---|
118 | CREATE INDEX jobhistory_u_id_ix ON jobhistory (userid); |
---|
119 | CREATE INDEX jobhistory_p_id_ix ON jobhistory (printerid); |
---|
120 | CREATE INDEX jobhistory_pd_id_ix ON jobhistory (printerid, jobdate); |
---|
121 | CREATE INDEX jobhistory_hostname_ix ON jobhistory (hostname); |
---|
122 | |
---|
123 | -- |
---|
124 | -- Create the print quota table for groups |
---|
125 | -- |
---|
126 | CREATE TABLE grouppquota(id SERIAL PRIMARY KEY NOT NULL, |
---|
127 | groupid INT4 REFERENCES groups(id), |
---|
128 | printerid INT4 REFERENCES printers(id), |
---|
129 | softlimit INT4, |
---|
130 | hardlimit INT4, |
---|
131 | maxjobsize INT4, |
---|
132 | datelimit TIMESTAMP); |
---|
133 | CREATE INDEX grouppquota_g_id_ix ON grouppquota (groupid); |
---|
134 | CREATE INDEX grouppquota_p_id_ix ON grouppquota (printerid); |
---|
135 | CREATE UNIQUE INDEX grouppquota_up_id_ix ON grouppquota (groupid, printerid); |
---|
136 | |
---|
137 | -- |
---|
138 | -- Create the groups/members relationship |
---|
139 | -- |
---|
140 | CREATE TABLE groupsmembers(groupid INT4 REFERENCES groups(id), |
---|
141 | userid INT4 REFERENCES users(id), |
---|
142 | PRIMARY KEY (groupid, userid)); |
---|
143 | |
---|
144 | -- |
---|
145 | -- Create the printer groups relationship |
---|
146 | -- |
---|
147 | CREATE TABLE printergroupsmembers(groupid INT4 REFERENCES printers(id), |
---|
148 | printerid INT4 REFERENCES printers(id), |
---|
149 | PRIMARY KEY (groupid, printerid)); |
---|
150 | -- |
---|
151 | -- Create the table for payments |
---|
152 | -- |
---|
153 | CREATE TABLE payments (id SERIAL PRIMARY KEY NOT NULL, |
---|
154 | userid INT4 REFERENCES users(id), |
---|
155 | amount FLOAT, |
---|
156 | description TEXT, |
---|
157 | date TIMESTAMP DEFAULT now()); |
---|
158 | CREATE INDEX payments_date_ix ON payments (date); |
---|
159 | |
---|
160 | -- |
---|
161 | -- Create the table for coefficients wrt paper sizes and the like |
---|
162 | -- |
---|
163 | CREATE TABLE coefficients (id SERIAL PRIMARY KEY NOT NULL, |
---|
164 | printerid INTEGER NOT NULL REFERENCES printers(id), |
---|
165 | label TEXT NOT NULL, |
---|
166 | coefficient FLOAT DEFAULT 1.0, |
---|
167 | CONSTRAINT coeffconstraint UNIQUE (printerid, label)); |
---|
168 | |
---|
169 | -- |
---|
170 | -- Create the table for the billing codes |
---|
171 | -- |
---|
172 | CREATE TABLE billingcodes (id SERIAL PRIMARY KEY NOT NULL, |
---|
173 | billingcode TEXT UNIQUE NOT NULL, |
---|
174 | description TEXT, |
---|
175 | balance FLOAT DEFAULT 0.0, |
---|
176 | pagecounter INT4 DEFAULT 0); |
---|
177 | |
---|
178 | -- |
---|
179 | -- Set some ACLs |
---|
180 | -- |
---|
181 | REVOKE ALL ON users, groups, printers, userpquota, grouppquota, groupsmembers, printergroupsmembers, jobhistory, payments, coefficients, billingcodes FROM public; |
---|
182 | REVOKE ALL ON users_id_seq, groups_id_seq, printers_id_seq, userpquota_id_seq, grouppquota_id_seq, jobhistory_id_seq, payments_id_seq, coefficients_id_seq, billingcodes_id_seq FROM public; |
---|
183 | |
---|
184 | GRANT SELECT, INSERT, UPDATE, DELETE, REFERENCES ON users, groups, printers, userpquota, grouppquota, groupsmembers, printergroupsmembers, jobhistory, payments, coefficients, billingcodes TO pykotaadmin; |
---|
185 | GRANT SELECT, UPDATE ON users_id_seq, groups_id_seq, printers_id_seq, userpquota_id_seq, grouppquota_id_seq, jobhistory_id_seq, payments_id_seq, coefficients_id_seq, billingcodes_id_seq TO pykotaadmin; |
---|
186 | GRANT SELECT ON users, groups, printers, userpquota, grouppquota, groupsmembers, printergroupsmembers, jobhistory, payments, coefficients, billingcodes TO pykotauser; |
---|