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

Revision 2030, 37.0 kB (checked in by jalet, 19 years ago)

Big bug fix wrt the datelimit attribute

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