1 | # PyKota |
---|
2 | # -*- coding: ISO-8859-15 -*- |
---|
3 | # |
---|
4 | # PyKota : Print Quotas for CUPS and LPRng |
---|
5 | # |
---|
6 | # (c) 2003-2004 Jerome Alet <alet@librelogiciel.com> |
---|
7 | # This program is free software; you can redistribute it and/or modify |
---|
8 | # it under the terms of the GNU General Public License as published by |
---|
9 | # the Free Software Foundation; either version 2 of the License, or |
---|
10 | # (at your option) any later version. |
---|
11 | # |
---|
12 | # This program is distributed in the hope that it will be useful, |
---|
13 | # but WITHOUT ANY WARRANTY; without even the implied warranty of |
---|
14 | # MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the |
---|
15 | # GNU General Public License for more details. |
---|
16 | # |
---|
17 | # You should have received a copy of the GNU General Public License |
---|
18 | # along with this program; if not, write to the Free Software |
---|
19 | # Foundation, Inc., 59 Temple Place, Suite 330, Boston, MA 02111-1307, USA. |
---|
20 | # |
---|
21 | # $Id$ |
---|
22 | # |
---|
23 | # $Log$ |
---|
24 | # Revision 1.66 2005/02/13 22:48:38 jalet |
---|
25 | # Added the md5sum to the history |
---|
26 | # |
---|
27 | # Revision 1.65 2005/02/13 22:02:29 jalet |
---|
28 | # Big database structure changes. Upgrade script is now included as well as |
---|
29 | # the new LDAP schema. |
---|
30 | # Introduction of the -o | --overcharge command line option to edpykota. |
---|
31 | # The output of repykota is more complete, but doesn't fit in 80 columns anymore. |
---|
32 | # Introduction of the new 'maxdenybanners' directive. |
---|
33 | # |
---|
34 | # Revision 1.64 2005/01/18 19:47:50 jalet |
---|
35 | # Big bug fix wrt the datelimit attribute |
---|
36 | # |
---|
37 | # Revision 1.63 2005/01/01 08:16:17 jalet |
---|
38 | # Fixed a problem which occured when 'limitby' was unset in the PostgreSQL |
---|
39 | # database |
---|
40 | # |
---|
41 | # Revision 1.62 2004/12/21 16:19:44 jalet |
---|
42 | # Fixed the problem with dumpykota's filtering of printers groups membership |
---|
43 | # |
---|
44 | # Revision 1.61 2004/12/21 15:49:59 jalet |
---|
45 | # The dumpykota command now supports extended filtering capabilities with |
---|
46 | # the PostgreSQL backend. LDAP doesn't yet support such possibilities. |
---|
47 | # |
---|
48 | # Revision 1.60 2004/12/21 14:45:31 jalet |
---|
49 | # Prepared dumpykota to accept the new --filter command line option. Some |
---|
50 | # additionnal work needs to be done in the backends though. |
---|
51 | # |
---|
52 | # Revision 1.59 2004/10/25 14:12:25 jalet |
---|
53 | # For URGENT legal reasons (Italy), a new "privacy" directive was added to pykota.conf |
---|
54 | # to hide print jobs' title, filename, and options. |
---|
55 | # |
---|
56 | # Revision 1.58 2004/10/12 08:58:53 jalet |
---|
57 | # Now warnpykota only warns users who have already printed, to not confuse |
---|
58 | # users who have just opened their account. |
---|
59 | # |
---|
60 | # Revision 1.57 2004/10/10 10:12:21 jalet |
---|
61 | # Improved SQL queries for groups. Same work has to be done for groups print quotas. |
---|
62 | # |
---|
63 | # Revision 1.56 2004/10/07 21:14:28 jalet |
---|
64 | # Hopefully final fix for data encoding to and from the database |
---|
65 | # |
---|
66 | # Revision 1.55 2004/10/07 09:37:53 jalet |
---|
67 | # Fixes recently introduced bug wrt users groups (was it three days ago ?) |
---|
68 | # |
---|
69 | # Revision 1.54 2004/10/05 10:05:04 jalet |
---|
70 | # UnicodeEncodeError isn't defined in Python2.1 |
---|
71 | # |
---|
72 | # Revision 1.53 2004/10/05 09:59:20 jalet |
---|
73 | # Restore compatibility with Python 2.1 |
---|
74 | # |
---|
75 | # Revision 1.52 2004/10/04 22:23:54 jalet |
---|
76 | # Charset conversions for dumps from the PostgreSQL backend |
---|
77 | # |
---|
78 | # Revision 1.51 2004/10/04 16:11:38 jalet |
---|
79 | # Now outputs page counters when dumping user groups quotas |
---|
80 | # |
---|
81 | # Revision 1.50 2004/10/04 16:01:15 jalet |
---|
82 | # More complete dumps for groups and groups quotas |
---|
83 | # |
---|
84 | # Revision 1.49 2004/10/02 13:33:13 jalet |
---|
85 | # Some work done of user's charset handling in database dumps. |
---|
86 | # |
---|
87 | # Revision 1.48 2004/10/02 05:48:56 jalet |
---|
88 | # Should now correctly deal with charsets both when storing into databases and when |
---|
89 | # retrieving datas. Works with both PostgreSQL and LDAP. |
---|
90 | # |
---|
91 | # Revision 1.47 2004/09/15 07:26:20 jalet |
---|
92 | # Data dumps are now ordered by entry creation date if applicable. |
---|
93 | # Now dumpykota exits with a message when there's a broken pipe like |
---|
94 | # in dumpykota --data history | head -3 |
---|
95 | # |
---|
96 | # Revision 1.46 2004/09/15 06:58:25 jalet |
---|
97 | # User groups membership and printer groups membership can now be dumped too |
---|
98 | # |
---|
99 | # Revision 1.45 2004/09/14 22:29:13 jalet |
---|
100 | # First version of dumpykota. Works fine but only with PostgreSQL backend |
---|
101 | # for now. |
---|
102 | # |
---|
103 | # Revision 1.44 2004/09/10 21:32:54 jalet |
---|
104 | # Small fixes for incomplete entry intialization |
---|
105 | # |
---|
106 | # Revision 1.43 2004/07/01 17:45:49 jalet |
---|
107 | # Added code to handle the description field for printers |
---|
108 | # |
---|
109 | # Revision 1.42 2004/06/08 17:44:43 jalet |
---|
110 | # Payment now gets deleted when the user is deleted |
---|
111 | # |
---|
112 | # Revision 1.41 2004/06/05 22:03:50 jalet |
---|
113 | # Payments history is now stored in database |
---|
114 | # |
---|
115 | # Revision 1.40 2004/06/03 23:14:11 jalet |
---|
116 | # Now stores the job's size in bytes in the database. |
---|
117 | # Preliminary work on payments storage : database schemas are OK now, |
---|
118 | # but no code to store payments yet. |
---|
119 | # Removed schema picture, not relevant anymore. |
---|
120 | # |
---|
121 | # Revision 1.39 2004/05/26 14:50:12 jalet |
---|
122 | # First try at saving the job-originating-hostname in the database |
---|
123 | # |
---|
124 | # Revision 1.38 2004/05/06 12:37:47 jalet |
---|
125 | # pkpgcounter : comments |
---|
126 | # pkprinters : when --add is used, existing printers are now skipped. |
---|
127 | # |
---|
128 | # Revision 1.37 2004/02/23 22:53:21 jalet |
---|
129 | # Don't retrieve data when it's not needed, to avoid database queries |
---|
130 | # |
---|
131 | # Revision 1.36 2004/02/04 13:24:41 jalet |
---|
132 | # pkprinters can now remove printers from printers groups. |
---|
133 | # |
---|
134 | # Revision 1.35 2004/02/04 11:17:00 jalet |
---|
135 | # pkprinters command line tool added. |
---|
136 | # |
---|
137 | # Revision 1.34 2004/02/02 22:44:16 jalet |
---|
138 | # Preliminary work on Relationnal Database Independance via DB-API 2.0 |
---|
139 | # |
---|
140 | # |
---|
141 | # |
---|
142 | |
---|
143 | from types import StringType |
---|
144 | from pykota.storage import PyKotaStorageError,BaseStorage,StorageObject,StorageUser,StorageGroup,StoragePrinter,StorageJob,StorageLastJob,StorageUserPQuota,StorageGroupPQuota |
---|
145 | |
---|
146 | class SQLStorage : |
---|
147 | def prepareRawResult(self, result) : |
---|
148 | """Prepares a raw result by including the headers.""" |
---|
149 | if result.ntuples() > 0 : |
---|
150 | entries = [result.listfields()] |
---|
151 | entries.extend(result.getresult()) |
---|
152 | nbfields = len(entries[0]) |
---|
153 | for i in range(1, len(entries)) : |
---|
154 | fields = list(entries[i]) |
---|
155 | for j in range(nbfields) : |
---|
156 | field = fields[j] |
---|
157 | if type(field) == StringType : |
---|
158 | fields[j] = self.databaseToUserCharset(field) |
---|
159 | entries[i] = tuple(fields) |
---|
160 | return entries |
---|
161 | |
---|
162 | def createFilter(self, only) : |
---|
163 | """Returns the appropriate SQL filter.""" |
---|
164 | if only : |
---|
165 | expressions = [] |
---|
166 | for (k, v) in only.items() : |
---|
167 | expressions.append("%s=%s" % (k, self.doQuote(v))) |
---|
168 | return " AND ".join(expressions) |
---|
169 | return "" |
---|
170 | |
---|
171 | def extractPrinters(self, extractonly={}) : |
---|
172 | """Extracts all printer records.""" |
---|
173 | thefilter = self.createFilter(extractonly) |
---|
174 | if thefilter : |
---|
175 | thefilter = "WHERE %s" % thefilter |
---|
176 | result = self.doRawSearch("SELECT * FROM printers %s ORDER BY id ASC" % thefilter) |
---|
177 | return self.prepareRawResult(result) |
---|
178 | |
---|
179 | def extractUsers(self, extractonly={}) : |
---|
180 | """Extracts all user records.""" |
---|
181 | thefilter = self.createFilter(extractonly) |
---|
182 | if thefilter : |
---|
183 | thefilter = "WHERE %s" % thefilter |
---|
184 | result = self.doRawSearch("SELECT * FROM users %s ORDER BY id ASC" % thefilter) |
---|
185 | return self.prepareRawResult(result) |
---|
186 | |
---|
187 | def extractGroups(self, extractonly={}) : |
---|
188 | """Extracts all group records.""" |
---|
189 | thefilter = self.createFilter(extractonly) |
---|
190 | if thefilter : |
---|
191 | thefilter = "WHERE %s" % thefilter |
---|
192 | result = self.doRawSearch("SELECT groups.*,COALESCE(SUM(balance), 0) AS balance, COALESCE(SUM(lifetimepaid), 0) as lifetimepaid FROM groups LEFT OUTER JOIN users ON users.id IN (SELECT userid FROM groupsmembers WHERE groupid=groups.id) %s GROUP BY groups.id,groups.groupname,groups.limitby ORDER BY groups.id ASC" % thefilter) |
---|
193 | return self.prepareRawResult(result) |
---|
194 | |
---|
195 | def extractPayments(self, extractonly={}) : |
---|
196 | """Extracts all payment records.""" |
---|
197 | thefilter = self.createFilter(extractonly) |
---|
198 | if thefilter : |
---|
199 | thefilter = "AND %s" % thefilter |
---|
200 | result = self.doRawSearch("SELECT username,payments.* FROM users,payments WHERE users.id=payments.userid %s ORDER BY payments.id ASC" % thefilter) |
---|
201 | return self.prepareRawResult(result) |
---|
202 | |
---|
203 | def extractUpquotas(self, extractonly={}) : |
---|
204 | """Extracts all userpquota records.""" |
---|
205 | thefilter = self.createFilter(extractonly) |
---|
206 | if thefilter : |
---|
207 | thefilter = "AND %s" % thefilter |
---|
208 | result = self.doRawSearch("SELECT users.username,printers.printername,userpquota.* FROM users,printers,userpquota WHERE users.id=userpquota.userid AND printers.id=userpquota.printerid %s ORDER BY userpquota.id ASC" % thefilter) |
---|
209 | return self.prepareRawResult(result) |
---|
210 | |
---|
211 | def extractGpquotas(self, extractonly={}) : |
---|
212 | """Extracts all grouppquota records.""" |
---|
213 | thefilter = self.createFilter(extractonly) |
---|
214 | if thefilter : |
---|
215 | thefilter = "AND %s" % thefilter |
---|
216 | result = self.doRawSearch("SELECT groups.groupname,printers.printername,grouppquota.*,coalesce(sum(pagecounter), 0) AS pagecounter,coalesce(sum(lifepagecounter), 0) AS lifepagecounter FROM groups,printers,grouppquota,userpquota WHERE groups.id=grouppquota.groupid AND printers.id=grouppquota.printerid AND userpquota.printerid=grouppquota.printerid AND userpquota.userid IN (SELECT userid FROM groupsmembers WHERE groupsmembers.groupid=grouppquota.groupid) %s GROUP BY grouppquota.id,grouppquota.groupid,grouppquota.printerid,grouppquota.softlimit,grouppquota.hardlimit,grouppquota.datelimit,groups.groupname,printers.printername ORDER BY grouppquota.id" % thefilter) |
---|
217 | return self.prepareRawResult(result) |
---|
218 | |
---|
219 | def extractUmembers(self, extractonly={}) : |
---|
220 | """Extracts all user groups members.""" |
---|
221 | thefilter = self.createFilter(extractonly) |
---|
222 | if thefilter : |
---|
223 | thefilter = "AND %s" % thefilter |
---|
224 | result = self.doRawSearch("SELECT groups.groupname, users.username, groupsmembers.* FROM groups,users,groupsmembers WHERE users.id=groupsmembers.userid AND groups.id=groupsmembers.groupid %s ORDER BY groupsmembers.groupid, groupsmembers.userid ASC" % thefilter) |
---|
225 | return self.prepareRawResult(result) |
---|
226 | |
---|
227 | def extractPmembers(self, extractonly={}) : |
---|
228 | """Extracts all printer groups members.""" |
---|
229 | for (k, v) in extractonly.items() : |
---|
230 | if k == "pgroupname" : |
---|
231 | del extractonly[k] |
---|
232 | extractonly["p1.printername"] = v |
---|
233 | elif k == "printername" : |
---|
234 | del extractonly[k] |
---|
235 | extractonly["p2.printername"] = v |
---|
236 | thefilter = self.createFilter(extractonly) |
---|
237 | if thefilter : |
---|
238 | thefilter = "AND %s" % thefilter |
---|
239 | result = self.doRawSearch("SELECT p1.printername as pgroupname, p2.printername as printername, printergroupsmembers.* FROM printers p1, printers p2, printergroupsmembers WHERE p1.id=printergroupsmembers.groupid AND p2.id=printergroupsmembers.printerid %s ORDER BY printergroupsmembers.groupid, printergroupsmembers.printerid ASC" % thefilter) |
---|
240 | return self.prepareRawResult(result) |
---|
241 | |
---|
242 | def extractHistory(self, extractonly={}) : |
---|
243 | """Extracts all jobhistory records.""" |
---|
244 | thefilter = self.createFilter(extractonly) |
---|
245 | if thefilter : |
---|
246 | thefilter = "AND %s" % thefilter |
---|
247 | result = self.doRawSearch("SELECT users.username,printers.printername,jobhistory.* FROM users,printers,jobhistory WHERE users.id=jobhistory.userid AND printers.id=jobhistory.printerid %s ORDER BY jobhistory.id ASC" % thefilter) |
---|
248 | return self.prepareRawResult(result) |
---|
249 | |
---|
250 | def getAllUsersNames(self) : |
---|
251 | """Extracts all user names.""" |
---|
252 | usernames = [] |
---|
253 | result = self.doSearch("SELECT username FROM users") |
---|
254 | if result : |
---|
255 | usernames = [record["username"] for record in result] |
---|
256 | return usernames |
---|
257 | |
---|
258 | def getAllGroupsNames(self) : |
---|
259 | """Extracts all group names.""" |
---|
260 | groupnames = [] |
---|
261 | result = self.doSearch("SELECT groupname FROM groups") |
---|
262 | if result : |
---|
263 | groupnames = [record["groupname"] for record in result] |
---|
264 | return groupnames |
---|
265 | |
---|
266 | def getUserNbJobsFromHistory(self, user) : |
---|
267 | """Returns the number of jobs the user has in history.""" |
---|
268 | result = self.doSearch("SELECT COUNT(*) FROM jobhistory WHERE userid=%s" % self.doQuote(user.ident)) |
---|
269 | if result : |
---|
270 | return result[0]["count"] |
---|
271 | return 0 |
---|
272 | |
---|
273 | def getUserFromBackend(self, username) : |
---|
274 | """Extracts user information given its name.""" |
---|
275 | user = StorageUser(self, username) |
---|
276 | result = self.doSearch("SELECT * FROM users WHERE username=%s LIMIT 1" % self.doQuote(username)) |
---|
277 | if result : |
---|
278 | fields = result[0] |
---|
279 | user.ident = fields.get("id") |
---|
280 | user.Name = fields.get("username", username) |
---|
281 | user.LimitBy = fields.get("limitby") or "quota" |
---|
282 | user.AccountBalance = fields.get("balance") |
---|
283 | user.LifeTimePaid = fields.get("lifetimepaid") |
---|
284 | user.Email = fields.get("email") |
---|
285 | user.OverCharge = fields.get("overcharge", 1.0) |
---|
286 | user.Exists = 1 |
---|
287 | return user |
---|
288 | |
---|
289 | def getGroupFromBackend(self, groupname) : |
---|
290 | """Extracts group information given its name.""" |
---|
291 | group = StorageGroup(self, groupname) |
---|
292 | result = self.doSearch("SELECT groups.*,COALESCE(SUM(balance), 0.0) AS balance, COALESCE(SUM(lifetimepaid), 0.0) AS lifetimepaid FROM groups LEFT OUTER JOIN users ON users.id IN (SELECT userid FROM groupsmembers WHERE groupid=groups.id) WHERE groupname=%s GROUP BY groups.id,groups.groupname,groups.limitby LIMIT 1" % self.doQuote(groupname)) |
---|
293 | if result : |
---|
294 | fields = result[0] |
---|
295 | group.ident = fields.get("id") |
---|
296 | group.Name = fields.get("groupname", groupname) |
---|
297 | group.LimitBy = fields.get("limitby") or "quota" |
---|
298 | group.AccountBalance = fields.get("balance") |
---|
299 | group.LifeTimePaid = fields.get("lifetimepaid") |
---|
300 | group.Exists = 1 |
---|
301 | return group |
---|
302 | |
---|
303 | def getPrinterFromBackend(self, printername) : |
---|
304 | """Extracts printer information given its name.""" |
---|
305 | printer = StoragePrinter(self, printername) |
---|
306 | result = self.doSearch("SELECT * FROM printers WHERE printername=%s LIMIT 1" % self.doQuote(printername)) |
---|
307 | if result : |
---|
308 | fields = result[0] |
---|
309 | printer.ident = fields.get("id") |
---|
310 | printer.Name = fields.get("printername", printername) |
---|
311 | printer.PricePerJob = fields.get("priceperjob") or 0.0 |
---|
312 | printer.PricePerPage = fields.get("priceperpage") or 0.0 |
---|
313 | printer.Description = self.databaseToUserCharset(fields.get("description") or "") |
---|
314 | printer.Exists = 1 |
---|
315 | return printer |
---|
316 | |
---|
317 | def getUserPQuotaFromBackend(self, user, printer) : |
---|
318 | """Extracts a user print quota.""" |
---|
319 | userpquota = StorageUserPQuota(self, user, printer) |
---|
320 | if printer.Exists and user.Exists : |
---|
321 | result = self.doSearch("SELECT id, lifepagecounter, pagecounter, softlimit, hardlimit, datelimit FROM userpquota WHERE userid=%s AND printerid=%s" % (self.doQuote(user.ident), self.doQuote(printer.ident))) |
---|
322 | if result : |
---|
323 | fields = result[0] |
---|
324 | userpquota.ident = fields.get("id") |
---|
325 | userpquota.PageCounter = fields.get("pagecounter") |
---|
326 | userpquota.LifePageCounter = fields.get("lifepagecounter") |
---|
327 | userpquota.SoftLimit = fields.get("softlimit") |
---|
328 | userpquota.HardLimit = fields.get("hardlimit") |
---|
329 | userpquota.DateLimit = fields.get("datelimit") |
---|
330 | userpquota.WarnCount = fields.get("warncount") |
---|
331 | userpquota.Exists = 1 |
---|
332 | return userpquota |
---|
333 | |
---|
334 | def getGroupPQuotaFromBackend(self, group, printer) : |
---|
335 | """Extracts a group print quota.""" |
---|
336 | grouppquota = StorageGroupPQuota(self, group, printer) |
---|
337 | if group.Exists : |
---|
338 | result = self.doSearch("SELECT id, softlimit, hardlimit, datelimit FROM grouppquota WHERE groupid=%s AND printerid=%s" % (self.doQuote(group.ident), self.doQuote(printer.ident))) |
---|
339 | if result : |
---|
340 | fields = result[0] |
---|
341 | grouppquota.ident = fields.get("id") |
---|
342 | grouppquota.SoftLimit = fields.get("softlimit") |
---|
343 | grouppquota.HardLimit = fields.get("hardlimit") |
---|
344 | grouppquota.DateLimit = fields.get("datelimit") |
---|
345 | result = self.doSearch("SELECT SUM(lifepagecounter) AS lifepagecounter, SUM(pagecounter) AS pagecounter FROM userpquota WHERE printerid=%s AND userid IN (SELECT userid FROM groupsmembers WHERE groupid=%s)" % (self.doQuote(printer.ident), self.doQuote(group.ident))) |
---|
346 | if result : |
---|
347 | fields = result[0] |
---|
348 | grouppquota.PageCounter = fields.get("pagecounter") or 0 |
---|
349 | grouppquota.LifePageCounter = fields.get("lifepagecounter") or 0 |
---|
350 | grouppquota.Exists = 1 |
---|
351 | return grouppquota |
---|
352 | |
---|
353 | def getPrinterLastJobFromBackend(self, printer) : |
---|
354 | """Extracts a printer's last job information.""" |
---|
355 | lastjob = StorageLastJob(self, printer) |
---|
356 | result = self.doSearch("SELECT jobhistory.id, jobid, userid, username, pagecounter, jobsize, jobprice, filename, title, copies, options, hostname, jobdate FROM jobhistory, users WHERE printerid=%s AND userid=users.id ORDER BY jobdate DESC LIMIT 1" % self.doQuote(printer.ident)) |
---|
357 | if result : |
---|
358 | fields = result[0] |
---|
359 | lastjob.ident = fields.get("id") |
---|
360 | lastjob.JobId = fields.get("jobid") |
---|
361 | lastjob.UserName = fields.get("username") |
---|
362 | lastjob.PrinterPageCounter = fields.get("pagecounter") |
---|
363 | lastjob.JobSize = fields.get("jobsize") |
---|
364 | lastjob.JobPrice = fields.get("jobprice") |
---|
365 | lastjob.JobAction = fields.get("action") |
---|
366 | lastjob.JobFileName = self.databaseToUserCharset(fields.get("filename") or "") |
---|
367 | lastjob.JobTitle = self.databaseToUserCharset(fields.get("title") or "") |
---|
368 | lastjob.JobCopies = fields.get("copies") |
---|
369 | lastjob.JobOptions = self.databaseToUserCharset(fields.get("options") or "") |
---|
370 | lastjob.JobDate = fields.get("jobdate") |
---|
371 | lastjob.JobHostName = fields.get("hostname") |
---|
372 | lastjob.JobSizeBytes = fields.get("jobsizebytes") |
---|
373 | lastjob.JobMD5Sum = fields.get("md5sum") |
---|
374 | lastjob.JobPages = fields.get("pages") |
---|
375 | lastjob.JobBillingCode = fields.get("billingcode") |
---|
376 | lastjob.Exists = 1 |
---|
377 | return lastjob |
---|
378 | |
---|
379 | def getGroupMembersFromBackend(self, group) : |
---|
380 | """Returns the group's members list.""" |
---|
381 | groupmembers = [] |
---|
382 | result = self.doSearch("SELECT * FROM groupsmembers JOIN users ON groupsmembers.userid=users.id WHERE groupid=%s" % self.doQuote(group.ident)) |
---|
383 | if result : |
---|
384 | for record in result : |
---|
385 | user = StorageUser(self, record.get("username")) |
---|
386 | user.ident = record.get("userid") |
---|
387 | user.LimitBy = record.get("limitby") or "quota" |
---|
388 | user.AccountBalance = record.get("balance") |
---|
389 | user.LifeTimePaid = record.get("lifetimepaid") |
---|
390 | user.Email = record.get("email") |
---|
391 | user.OverCharge = record.get("overcharge") |
---|
392 | user.Exists = 1 |
---|
393 | groupmembers.append(user) |
---|
394 | self.cacheEntry("USERS", user.Name, user) |
---|
395 | return groupmembers |
---|
396 | |
---|
397 | def getUserGroupsFromBackend(self, user) : |
---|
398 | """Returns the user's groups list.""" |
---|
399 | groups = [] |
---|
400 | result = self.doSearch("SELECT groupname FROM groupsmembers JOIN groups ON groupsmembers.groupid=groups.id WHERE userid=%s" % self.doQuote(user.ident)) |
---|
401 | if result : |
---|
402 | for record in result : |
---|
403 | groups.append(self.getGroup(record.get("groupname"))) |
---|
404 | return groups |
---|
405 | |
---|
406 | def getParentPrintersFromBackend(self, printer) : |
---|
407 | """Get all the printer groups this printer is a member of.""" |
---|
408 | pgroups = [] |
---|
409 | result = self.doSearch("SELECT groupid,printername FROM printergroupsmembers JOIN printers ON groupid=id WHERE printerid=%s" % self.doQuote(printer.ident)) |
---|
410 | if result : |
---|
411 | for record in result : |
---|
412 | if record["groupid"] != printer.ident : # in case of integrity violation |
---|
413 | parentprinter = self.getPrinter(record.get("printername")) |
---|
414 | if parentprinter.Exists : |
---|
415 | pgroups.append(parentprinter) |
---|
416 | return pgroups |
---|
417 | |
---|
418 | def getMatchingPrinters(self, printerpattern) : |
---|
419 | """Returns the list of all printers for which name matches a certain pattern.""" |
---|
420 | printers = [] |
---|
421 | # We 'could' do a SELECT printername FROM printers WHERE printername LIKE ... |
---|
422 | # but we don't because other storages semantics may be different, so every |
---|
423 | # storage should use fnmatch to match patterns and be storage agnostic |
---|
424 | result = self.doSearch("SELECT * FROM printers") |
---|
425 | if result : |
---|
426 | for record in result : |
---|
427 | if self.tool.matchString(record["printername"], printerpattern.split(",")) : |
---|
428 | printer = StoragePrinter(self, record["printername"]) |
---|
429 | printer.ident = record.get("id") |
---|
430 | printer.PricePerJob = record.get("priceperjob") or 0.0 |
---|
431 | printer.PricePerPage = record.get("priceperpage") or 0.0 |
---|
432 | printer.Description = self.databaseToUserCharset(record.get("description") or "") |
---|
433 | printer.Exists = 1 |
---|
434 | printers.append(printer) |
---|
435 | self.cacheEntry("PRINTERS", printer.Name, printer) |
---|
436 | return printers |
---|
437 | |
---|
438 | def getPrinterUsersAndQuotas(self, printer, names=["*"]) : |
---|
439 | """Returns the list of users who uses a given printer, along with their quotas.""" |
---|
440 | usersandquotas = [] |
---|
441 | result = self.doSearch("SELECT users.id as uid,username,balance,lifetimepaid,limitby,email,overcharge,userpquota.id,lifepagecounter,pagecounter,softlimit,hardlimit,datelimit,warncount FROM users JOIN userpquota ON users.id=userpquota.userid AND printerid=%s ORDER BY username ASC" % self.doQuote(printer.ident)) |
---|
442 | if result : |
---|
443 | for record in result : |
---|
444 | if self.tool.matchString(record.get("username"), names) : |
---|
445 | user = StorageUser(self, record.get("username")) |
---|
446 | user.ident = record.get("uid") |
---|
447 | user.LimitBy = record.get("limitby") or "quota" |
---|
448 | user.AccountBalance = record.get("balance") |
---|
449 | user.LifeTimePaid = record.get("lifetimepaid") |
---|
450 | user.Email = record.get("email") |
---|
451 | user.OverCharge = record.get("overcharge") |
---|
452 | user.Exists = 1 |
---|
453 | userpquota = StorageUserPQuota(self, user, printer) |
---|
454 | userpquota.ident = record.get("id") |
---|
455 | userpquota.PageCounter = record.get("pagecounter") |
---|
456 | userpquota.LifePageCounter = record.get("lifepagecounter") |
---|
457 | userpquota.SoftLimit = record.get("softlimit") |
---|
458 | userpquota.HardLimit = record.get("hardlimit") |
---|
459 | userpquota.DateLimit = record.get("datelimit") |
---|
460 | userpquota.WarnCount = record.get("warncount") |
---|
461 | userpquota.Exists = 1 |
---|
462 | usersandquotas.append((user, userpquota)) |
---|
463 | self.cacheEntry("USERS", user.Name, user) |
---|
464 | self.cacheEntry("USERPQUOTAS", "%s@%s" % (user.Name, printer.Name), userpquota) |
---|
465 | return usersandquotas |
---|
466 | |
---|
467 | def getPrinterGroupsAndQuotas(self, printer, names=["*"]) : |
---|
468 | """Returns the list of groups which uses a given printer, along with their quotas.""" |
---|
469 | groupsandquotas = [] |
---|
470 | result = self.doSearch("SELECT groupname FROM groups JOIN grouppquota ON groups.id=grouppquota.groupid AND printerid=%s ORDER BY groupname ASC" % self.doQuote(printer.ident)) |
---|
471 | if result : |
---|
472 | for record in result : |
---|
473 | if self.tool.matchString(record.get("groupname"), names) : |
---|
474 | group = self.getGroup(record.get("groupname")) |
---|
475 | grouppquota = self.getGroupPQuota(group, printer) |
---|
476 | groupsandquotas.append((group, grouppquota)) |
---|
477 | return groupsandquotas |
---|
478 | |
---|
479 | def addPrinter(self, printername) : |
---|
480 | """Adds a printer to the quota storage, returns it.""" |
---|
481 | self.doModify("INSERT INTO printers (printername) VALUES (%s)" % self.doQuote(printername)) |
---|
482 | return self.getPrinter(printername) |
---|
483 | |
---|
484 | def addUser(self, user) : |
---|
485 | """Adds a user to the quota storage, returns its id.""" |
---|
486 | self.doModify("INSERT INTO users (username, limitby, balance, lifetimepaid, email, overcharge) VALUES (%s, %s, %s, %s, %s, %s)" % (self.doQuote(user.Name), self.doQuote(user.LimitBy or 'quota'), self.doQuote(user.AccountBalance or 0.0), self.doQuote(user.LifeTimePaid or 0.0), self.doQuote(user.Email), self.doQuote(user.OverCharge))) |
---|
487 | return self.getUser(user.Name) |
---|
488 | |
---|
489 | def addGroup(self, group) : |
---|
490 | """Adds a group to the quota storage, returns its id.""" |
---|
491 | self.doModify("INSERT INTO groups (groupname, limitby) VALUES (%s, %s)" % (self.doQuote(group.Name), self.doQuote(group.LimitBy or "quota"))) |
---|
492 | return self.getGroup(group.Name) |
---|
493 | |
---|
494 | def addUserToGroup(self, user, group) : |
---|
495 | """Adds an user to a group.""" |
---|
496 | result = self.doSearch("SELECT COUNT(*) AS mexists FROM groupsmembers WHERE groupid=%s AND userid=%s" % (self.doQuote(group.ident), self.doQuote(user.ident))) |
---|
497 | try : |
---|
498 | mexists = int(result[0].get("mexists")) |
---|
499 | except (IndexError, TypeError) : |
---|
500 | mexists = 0 |
---|
501 | if not mexists : |
---|
502 | self.doModify("INSERT INTO groupsmembers (groupid, userid) VALUES (%s, %s)" % (self.doQuote(group.ident), self.doQuote(user.ident))) |
---|
503 | |
---|
504 | def addUserPQuota(self, user, printer) : |
---|
505 | """Initializes a user print quota on a printer.""" |
---|
506 | self.doModify("INSERT INTO userpquota (userid, printerid) VALUES (%s, %s)" % (self.doQuote(user.ident), self.doQuote(printer.ident))) |
---|
507 | return self.getUserPQuota(user, printer) |
---|
508 | |
---|
509 | def addGroupPQuota(self, group, printer) : |
---|
510 | """Initializes a group print quota on a printer.""" |
---|
511 | self.doModify("INSERT INTO grouppquota (groupid, printerid) VALUES (%s, %s)" % (self.doQuote(group.ident), self.doQuote(printer.ident))) |
---|
512 | return self.getGroupPQuota(group, printer) |
---|
513 | |
---|
514 | def writePrinterPrices(self, printer) : |
---|
515 | """Write the printer's prices back into the storage.""" |
---|
516 | self.doModify("UPDATE printers SET priceperpage=%s, priceperjob=%s WHERE id=%s" % (self.doQuote(printer.PricePerPage), self.doQuote(printer.PricePerJob), self.doQuote(printer.ident))) |
---|
517 | |
---|
518 | def writePrinterDescription(self, printer) : |
---|
519 | """Write the printer's description back into the storage.""" |
---|
520 | description = self.userCharsetToDatabase(printer.Description) |
---|
521 | self.doModify("UPDATE printers SET description=%s WHERE id=%s" % (self.doQuote(description), self.doQuote(printer.ident))) |
---|
522 | |
---|
523 | def writeUserOverCharge(self, user, factor) : |
---|
524 | """Sets the user's overcharging coefficient.""" |
---|
525 | self.doModify("UPDATE users SET overcharge=%s WHERE id=%s" % (self.doQuote(factor), self.doQuote(user.ident))) |
---|
526 | |
---|
527 | def writeUserLimitBy(self, user, limitby) : |
---|
528 | """Sets the user's limiting factor.""" |
---|
529 | self.doModify("UPDATE users SET limitby=%s WHERE id=%s" % (self.doQuote(limitby), self.doQuote(user.ident))) |
---|
530 | |
---|
531 | def writeGroupLimitBy(self, group, limitby) : |
---|
532 | """Sets the group's limiting factor.""" |
---|
533 | self.doModify("UPDATE groups SET limitby=%s WHERE id=%s" % (self.doQuote(limitby), self.doQuote(group.ident))) |
---|
534 | |
---|
535 | def writeUserPQuotaDateLimit(self, userpquota, datelimit) : |
---|
536 | """Sets the date limit permanently for a user print quota.""" |
---|
537 | self.doModify("UPDATE userpquota SET datelimit=%s WHERE id=%s" % (self.doQuote(datelimit), self.doQuote(userpquota.ident))) |
---|
538 | |
---|
539 | def writeGroupPQuotaDateLimit(self, grouppquota, datelimit) : |
---|
540 | """Sets the date limit permanently for a group print quota.""" |
---|
541 | self.doModify("UPDATE grouppquota SET datelimit=%s WHERE id=%s" % (self.doQuote(datelimit), self.doQuote(grouppquota.ident))) |
---|
542 | |
---|
543 | def increaseUserPQuotaPagesCounters(self, userpquota, nbpages) : |
---|
544 | """Increase page counters for a user print quota.""" |
---|
545 | self.doModify("UPDATE userpquota SET pagecounter=pagecounter + %s,lifepagecounter=lifepagecounter + %s WHERE id=%s" % (self.doQuote(nbpages), self.doQuote(nbpages), self.doQuote(userpquota.ident))) |
---|
546 | |
---|
547 | def writeUserPQuotaPagesCounters(self, userpquota, newpagecounter, newlifepagecounter) : |
---|
548 | """Sets the new page counters permanently for a user print quota.""" |
---|
549 | self.doModify("UPDATE userpquota SET pagecounter=%s, lifepagecounter=%s, warncount=0, datelimit=NULL WHERE id=%s" % (self.doQuote(newpagecounter), self.doQuote(newlifepagecounter), self.doQuote(userpquota.ident))) |
---|
550 | |
---|
551 | def decreaseUserAccountBalance(self, user, amount) : |
---|
552 | """Decreases user's account balance from an amount.""" |
---|
553 | self.doModify("UPDATE users SET balance=balance - %s WHERE id=%s" % (self.doQuote(amount), self.doQuote(user.ident))) |
---|
554 | |
---|
555 | def writeUserAccountBalance(self, user, newbalance, newlifetimepaid=None) : |
---|
556 | """Sets the new account balance and eventually new lifetime paid.""" |
---|
557 | if newlifetimepaid is not None : |
---|
558 | self.doModify("UPDATE users SET balance=%s, lifetimepaid=%s WHERE id=%s" % (self.doQuote(newbalance), self.doQuote(newlifetimepaid), self.doQuote(user.ident))) |
---|
559 | else : |
---|
560 | self.doModify("UPDATE users SET balance=%s WHERE id=%s" % (self.doQuote(newbalance), self.doQuote(user.ident))) |
---|
561 | |
---|
562 | def writeNewPayment(self, user, amount) : |
---|
563 | """Adds a new payment to the payments history.""" |
---|
564 | self.doModify("INSERT INTO payments (userid, amount) VALUES (%s, %s)" % (self.doQuote(user.ident), self.doQuote(amount))) |
---|
565 | |
---|
566 | def writeLastJobSize(self, lastjob, jobsize, jobprice) : |
---|
567 | """Sets the last job's size permanently.""" |
---|
568 | self.doModify("UPDATE jobhistory SET jobsize=%s, jobprice=%s WHERE id=%s" % (self.doQuote(jobsize), self.doQuote(jobprice), self.doQuote(lastjob.ident))) |
---|
569 | |
---|
570 | def writeJobNew(self, printer, user, jobid, pagecounter, action, jobsize=None, jobprice=None, filename=None, title=None, copies=None, options=None, clienthost=None, jobsizebytes=None, jobmd5sum=None) : |
---|
571 | """Adds a job in a printer's history.""" |
---|
572 | if self.privacy : |
---|
573 | # For legal reasons, we want to hide the title, filename and options |
---|
574 | title = filename = options = "Hidden because of privacy concerns" |
---|
575 | filename = self.userCharsetToDatabase(filename) |
---|
576 | title = self.userCharsetToDatabase(title) |
---|
577 | options = self.userCharsetToDatabase(options) |
---|
578 | if (not self.disablehistory) or (not printer.LastJob.Exists) : |
---|
579 | if jobsize is not None : |
---|
580 | self.doModify("INSERT INTO jobhistory (userid, printerid, jobid, pagecounter, action, jobsize, jobprice, filename, title, copies, options, hostname, jobsizebytes, md5sum) VALUES (%s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s)" % (self.doQuote(user.ident), self.doQuote(printer.ident), self.doQuote(jobid), self.doQuote(pagecounter), self.doQuote(action), self.doQuote(jobsize), self.doQuote(jobprice), self.doQuote(filename), self.doQuote(title), self.doQuote(copies), self.doQuote(options), self.doQuote(clienthost), self.doQuote(jobsizebytes), self.doQuote(jobmd5sum))) |
---|
581 | else : |
---|
582 | self.doModify("INSERT INTO jobhistory (userid, printerid, jobid, pagecounter, action, filename, title, copies, options, hostname, jobsizebytes, md5sum) VALUES (%s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s)" % (self.doQuote(user.ident), self.doQuote(printer.ident), self.doQuote(jobid), self.doQuote(pagecounter), self.doQuote(action), self.doQuote(filename), self.doQuote(title), self.doQuote(copies), self.doQuote(options), self.doQuote(clienthost), self.doQuote(jobsizebytes), self.doQuote(jobmd5sum))) |
---|
583 | else : |
---|
584 | # here we explicitly want to reset jobsize to NULL if needed |
---|
585 | self.doModify("UPDATE jobhistory SET userid=%s, jobid=%s, pagecounter=%s, action=%s, jobsize=%s, jobprice=%s, filename=%s, title=%s, copies=%s, options=%s, hostname=%s, jobsizebytes=%s, md5sum=%s, jobdate=now() WHERE id=%s" % (self.doQuote(user.ident), self.doQuote(jobid), self.doQuote(pagecounter), self.doQuote(action), self.doQuote(jobsize), self.doQuote(jobprice), self.doQuote(filename), self.doQuote(title), self.doQuote(copies), self.doQuote(options), self.doQuote(clienthost), self.doQuote(jobsizebytes), self.doQuote(jobmd5sum), self.doQuote(printer.LastJob.ident))) |
---|
586 | |
---|
587 | def writeUserPQuotaLimits(self, userpquota, softlimit, hardlimit) : |
---|
588 | """Sets soft and hard limits for a user quota.""" |
---|
589 | self.doModify("UPDATE userpquota SET softlimit=%s, hardlimit=%s, warncount=0, datelimit=NULL WHERE id=%s" % (self.doQuote(softlimit), self.doQuote(hardlimit), self.doQuote(userpquota.ident))) |
---|
590 | |
---|
591 | def writeUserPQuotaWarnCount(self, userpquota, warncount) : |
---|
592 | """Sets the warn counter value for a user quota.""" |
---|
593 | self.doModify("UPDATE userpquota SET warncount=%s WHERE id=%s" % (self.doQuote(warncount), self.doQuote(userpquota.ident))) |
---|
594 | |
---|
595 | def increaseUserPQuotaWarnCount(self, userpquota) : |
---|
596 | """Increases the warn counter value for a user quota.""" |
---|
597 | self.doModify("UPDATE userpquota SET warncount=warncount+1 WHERE id=%s" % self.doQuote(userpquota.ident)) |
---|
598 | |
---|
599 | def writeGroupPQuotaLimits(self, grouppquota, softlimit, hardlimit) : |
---|
600 | """Sets soft and hard limits for a group quota on a specific printer.""" |
---|
601 | self.doModify("UPDATE grouppquota SET softlimit=%s, hardlimit=%s, datelimit=NULL WHERE id=%s" % (self.doQuote(softlimit), self.doQuote(hardlimit), self.doQuote(grouppquota.ident))) |
---|
602 | |
---|
603 | def writePrinterToGroup(self, pgroup, printer) : |
---|
604 | """Puts a printer into a printer group.""" |
---|
605 | children = [] |
---|
606 | result = self.doSearch("SELECT printerid FROM printergroupsmembers WHERE groupid=%s" % self.doQuote(pgroup.ident)) |
---|
607 | if result : |
---|
608 | for record in result : |
---|
609 | children.append(record.get("printerid")) # TODO : put this into the database integrity rules |
---|
610 | if printer.ident not in children : |
---|
611 | self.doModify("INSERT INTO printergroupsmembers (groupid, printerid) VALUES (%s, %s)" % (self.doQuote(pgroup.ident), self.doQuote(printer.ident))) |
---|
612 | |
---|
613 | def removePrinterFromGroup(self, pgroup, printer) : |
---|
614 | """Removes a printer from a printer group.""" |
---|
615 | self.doModify("DELETE FROM printergroupsmembers WHERE groupid=%s AND printerid=%s" % (self.doQuote(pgroup.ident), self.doQuote(printer.ident))) |
---|
616 | |
---|
617 | def retrieveHistory(self, user=None, printer=None, datelimit=None, hostname=None, limit=100) : |
---|
618 | """Retrieves all print jobs for user on printer (or all) before date, limited to first 100 results.""" |
---|
619 | query = "SELECT jobhistory.*,username,printername FROM jobhistory,users,printers WHERE users.id=userid AND printers.id=printerid" |
---|
620 | where = [] |
---|
621 | if (user is not None) and user.Exists : |
---|
622 | where.append("userid=%s" % self.doQuote(user.ident)) |
---|
623 | if (printer is not None) and printer.Exists : |
---|
624 | where.append("printerid=%s" % self.doQuote(printer.ident)) |
---|
625 | if hostname is not None : |
---|
626 | where.append("hostname=%s" % self.doQuote(hostname)) |
---|
627 | if datelimit is not None : |
---|
628 | where.append("jobdate<=%s" % self.doQuote(datelimit)) |
---|
629 | if where : |
---|
630 | query += " AND %s" % " AND ".join(where) |
---|
631 | query += " ORDER BY id DESC" |
---|
632 | if limit : |
---|
633 | query += " LIMIT %s" % self.doQuote(int(limit)) |
---|
634 | jobs = [] |
---|
635 | result = self.doSearch(query) |
---|
636 | if result : |
---|
637 | for fields in result : |
---|
638 | job = StorageJob(self) |
---|
639 | job.ident = fields.get("id") |
---|
640 | job.JobId = fields.get("jobid") |
---|
641 | job.PrinterPageCounter = fields.get("pagecounter") |
---|
642 | job.JobSize = fields.get("jobsize") |
---|
643 | job.JobPrice = fields.get("jobprice") |
---|
644 | job.JobAction = fields.get("action") |
---|
645 | job.JobFileName = self.databaseToUserCharset(fields.get("filename") or "") |
---|
646 | job.JobTitle = self.databaseToUserCharset(fields.get("title") or "") |
---|
647 | job.JobCopies = fields.get("copies") |
---|
648 | job.JobOptions = self.databaseToUserCharset(fields.get("options") or "") |
---|
649 | job.JobDate = fields.get("jobdate") |
---|
650 | job.JobHostName = fields.get("hostname") |
---|
651 | job.JobSizeBytes = fields.get("jobsizebytes") |
---|
652 | job.JobMD5Sum = fields.get("md5sum") |
---|
653 | job.JobPages = fields.get("pages") |
---|
654 | job.JobBillingCode = fields.get("billingcode") |
---|
655 | job.UserName = fields.get("username") |
---|
656 | job.PrinterName = fields.get("printername") |
---|
657 | job.Exists = 1 |
---|
658 | jobs.append(job) |
---|
659 | return jobs |
---|
660 | |
---|
661 | def deleteUser(self, user) : |
---|
662 | """Completely deletes an user from the Quota Storage.""" |
---|
663 | # TODO : What should we do if we delete the last person who used a given printer ? |
---|
664 | # TODO : we can't reassign the last job to the previous one, because next user would be |
---|
665 | # TODO : incorrectly charged (overcharged). |
---|
666 | for q in [ |
---|
667 | "DELETE FROM payments WHERE userid=%s" % self.doQuote(user.ident), |
---|
668 | "DELETE FROM groupsmembers WHERE userid=%s" % self.doQuote(user.ident), |
---|
669 | "DELETE FROM jobhistory WHERE userid=%s" % self.doQuote(user.ident), |
---|
670 | "DELETE FROM userpquota WHERE userid=%s" % self.doQuote(user.ident), |
---|
671 | "DELETE FROM users WHERE id=%s" % self.doQuote(user.ident), |
---|
672 | ] : |
---|
673 | self.doModify(q) |
---|
674 | |
---|
675 | def deleteGroup(self, group) : |
---|
676 | """Completely deletes a group from the Quota Storage.""" |
---|
677 | for q in [ |
---|
678 | "DELETE FROM groupsmembers WHERE groupid=%s" % self.doQuote(group.ident), |
---|
679 | "DELETE FROM grouppquota WHERE groupid=%s" % self.doQuote(group.ident), |
---|
680 | "DELETE FROM groups WHERE id=%s" % self.doQuote(group.ident), |
---|
681 | ] : |
---|
682 | self.doModify(q) |
---|
683 | |
---|
684 | def deletePrinter(self, printer) : |
---|
685 | """Completely deletes a printer from the Quota Storage.""" |
---|
686 | for q in [ |
---|
687 | "DELETE FROM printergroupsmembers WHERE groupid=%s OR printerid=%s" % (self.doQuote(printer.ident), self.doQuote(printer.ident)), |
---|
688 | "DELETE FROM jobhistory WHERE printerid=%s" % self.doQuote(printer.ident), |
---|
689 | "DELETE FROM grouppquota WHERE printerid=%s" % self.doQuote(printer.ident), |
---|
690 | "DELETE FROM userpquota WHERE printerid=%s" % self.doQuote(printer.ident), |
---|
691 | "DELETE FROM printers WHERE id=%s" % self.doQuote(printer.ident), |
---|
692 | ] : |
---|
693 | self.doModify(q) |
---|
694 | |
---|