root / pykota / trunk / pykota / storages / sql.py @ 1999

Revision 1999, 36.9 kB (checked in by jalet, 19 years ago)

Fixed a problem which occured when 'limitby' was unset in the PostgreSQL
database

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