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

Revision 1792, 33.5 kB (checked in by jalet, 20 years ago)

Improved SQL queries for groups. Same work has to be done for groups print quotas.

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