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

Revision 2464, 41.8 kB (checked in by jerome, 19 years ago)

Added support to write the maxjobsize and passthrough attributes
for printers.

  • 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., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.
20#
21# $Id$
22#
23#
24
25from types import StringType
26from pykota.storage import PyKotaStorageError, BaseStorage, StorageObject, \
27                           StorageUser, StorageGroup, StoragePrinter, \
28                           StorageJob, StorageLastJob, StorageUserPQuota, \
29                           StorageGroupPQuota, StorageBillingCode
30
31class SQLStorage :
32    def prepareRawResult(self, result) :
33        """Prepares a raw result by including the headers."""
34        if result.ntuples() > 0 :
35            entries = [result.listfields()]
36            entries.extend(result.getresult())
37            nbfields = len(entries[0])
38            for i in range(1, len(entries)) :
39                fields = list(entries[i])
40                for j in range(nbfields) :
41                    field = fields[j]
42                    if type(field) == StringType :
43                        fields[j] = self.databaseToUserCharset(field) 
44                entries[i] = tuple(fields)   
45            return entries
46       
47    def createFilter(self, only) :   
48        """Returns the appropriate SQL filter."""
49        if only :
50            expressions = []
51            for (k, v) in only.items() :
52                expressions.append("%s=%s" % (k, self.doQuote(self.userCharsetToDatabase(v))))
53            return " AND ".join(expressions)     
54        return ""       
55       
56    def extractPrinters(self, extractonly={}) :
57        """Extracts all printer records."""
58        thefilter = self.createFilter(extractonly)
59        if thefilter :
60            thefilter = "WHERE %s" % thefilter
61        result = self.doRawSearch("SELECT * FROM printers %s ORDER BY id ASC" % thefilter)
62        return self.prepareRawResult(result)
63       
64    def extractUsers(self, extractonly={}) :
65        """Extracts all user records."""
66        thefilter = self.createFilter(extractonly)
67        if thefilter :
68            thefilter = "WHERE %s" % thefilter
69        result = self.doRawSearch("SELECT * FROM users %s ORDER BY id ASC" % thefilter)
70        return self.prepareRawResult(result)
71       
72    def extractBillingcodes(self, extractonly={}) :
73        """Extracts all billing codes records."""
74        thefilter = self.createFilter(extractonly)
75        if thefilter :
76            thefilter = "WHERE %s" % thefilter
77        result = self.doRawSearch("SELECT * FROM billingcodes %s ORDER BY id ASC" % thefilter)
78        return self.prepareRawResult(result)
79       
80    def extractGroups(self, extractonly={}) :
81        """Extracts all group records."""
82        thefilter = self.createFilter(extractonly)
83        if thefilter :
84            thefilter = "WHERE %s" % thefilter
85        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,groups.description ORDER BY groups.id ASC" % thefilter)
86        return self.prepareRawResult(result)
87       
88    def extractPayments(self, extractonly={}) :
89        """Extracts all payment records."""
90        thefilter = self.createFilter(extractonly)
91        if thefilter :
92            thefilter = "AND %s" % thefilter
93        result = self.doRawSearch("SELECT username,payments.* FROM users,payments WHERE users.id=payments.userid %s ORDER BY payments.id ASC" % thefilter)
94        return self.prepareRawResult(result)
95       
96    def extractUpquotas(self, extractonly={}) :
97        """Extracts all userpquota records."""
98        thefilter = self.createFilter(extractonly)
99        if thefilter :
100            thefilter = "AND %s" % thefilter
101        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)
102        return self.prepareRawResult(result)
103       
104    def extractGpquotas(self, extractonly={}) :
105        """Extracts all grouppquota records."""
106        thefilter = self.createFilter(extractonly)
107        if thefilter :
108            thefilter = "AND %s" % thefilter
109        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,grouppquota.maxjobsize,groups.groupname,printers.printername ORDER BY grouppquota.id" % thefilter)
110        return self.prepareRawResult(result)
111       
112    def extractUmembers(self, extractonly={}) :
113        """Extracts all user groups members."""
114        thefilter = self.createFilter(extractonly)
115        if thefilter :
116            thefilter = "AND %s" % thefilter
117        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)
118        return self.prepareRawResult(result)
119       
120    def extractPmembers(self, extractonly={}) :
121        """Extracts all printer groups members."""
122        for (k, v) in extractonly.items() :
123            if k == "pgroupname" :
124                del extractonly[k]
125                extractonly["p1.printername"] = v
126            elif k == "printername" :
127                del extractonly[k]
128                extractonly["p2.printername"] = v
129        thefilter = self.createFilter(extractonly)
130        if thefilter :
131            thefilter = "AND %s" % thefilter
132        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)
133        return self.prepareRawResult(result)
134       
135    def extractHistory(self, extractonly={}) :
136        """Extracts all jobhistory records."""
137        startdate = extractonly.get("start")
138        enddate = extractonly.get("end")
139        for limit in ("start", "end") :
140            try :
141                del extractonly[limit]
142            except KeyError :   
143                pass
144        thefilter = self.createFilter(extractonly)
145        if thefilter :
146            thefilter = "AND %s" % thefilter
147        (startdate, enddate) = self.cleanDates(startdate, enddate)
148        if startdate and enddate : 
149            thefilter = "%s AND jobdate>=%s AND jobdate<=%s" % (thefilter, self.doQuote(startdate), self.doQuote(enddate))
150        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)
151        return self.prepareRawResult(result)
152           
153    def getAllUsersNames(self) :   
154        """Extracts all user names."""
155        usernames = []
156        result = self.doSearch("SELECT username FROM users")
157        if result :
158            usernames = [record["username"] for record in result]
159        return usernames
160       
161    def getAllGroupsNames(self) :   
162        """Extracts all group names."""
163        groupnames = []
164        result = self.doSearch("SELECT groupname FROM groups")
165        if result :
166            groupnames = [record["groupname"] for record in result]
167        return groupnames
168       
169    def getUserNbJobsFromHistory(self, user) :
170        """Returns the number of jobs the user has in history."""
171        result = self.doSearch("SELECT COUNT(*) FROM jobhistory WHERE userid=%s" % self.doQuote(user.ident))
172        if result :
173            return result[0]["count"]
174        return 0
175       
176    def getUserFromBackend(self, username) :   
177        """Extracts user information given its name."""
178        user = StorageUser(self, username)
179        result = self.doSearch("SELECT * FROM users WHERE username=%s LIMIT 1" % self.doQuote(username))
180        if result :
181            fields = result[0]
182            user.ident = fields.get("id")
183            user.Name = fields.get("username", username)
184            user.LimitBy = fields.get("limitby") or "quota"
185            user.AccountBalance = fields.get("balance")
186            user.LifeTimePaid = fields.get("lifetimepaid")
187            user.Email = fields.get("email")
188            user.OverCharge = fields.get("overcharge", 1.0)
189            user.Exists = 1
190        return user
191       
192    def getGroupFromBackend(self, groupname) :   
193        """Extracts group information given its name."""
194        group = StorageGroup(self, groupname)
195        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,groups.description LIMIT 1" % self.doQuote(groupname))
196        if result :
197            fields = result[0]
198            group.ident = fields.get("id")
199            group.Name = fields.get("groupname", groupname)
200            group.LimitBy = fields.get("limitby") or "quota"
201            group.AccountBalance = fields.get("balance")
202            group.LifeTimePaid = fields.get("lifetimepaid")
203            group.Exists = 1
204        return group
205       
206    def getPrinterFromBackend(self, printername) :       
207        """Extracts printer information given its name."""
208        printer = StoragePrinter(self, printername)
209        result = self.doSearch("SELECT * FROM printers WHERE printername=%s LIMIT 1" % self.doQuote(printername))
210        if result :
211            fields = result[0]
212            printer.ident = fields.get("id")
213            printer.Name = fields.get("printername", printername)
214            printer.PricePerJob = fields.get("priceperjob") or 0.0
215            printer.PricePerPage = fields.get("priceperpage") or 0.0
216            printer.MaxJobSize = fields.get("maxjobsize") or 0
217            printer.PassThrough = fields.get("passthrough") or 0
218            if printer.PassThrough in (1, "1", "t", "true", "TRUE", "True") :
219                printer.PassThrough = 1
220            else :
221                printer.PassThrough = 0
222            printer.Description = self.databaseToUserCharset(fields.get("description") or "")
223            printer.Exists = 1
224        return printer   
225       
226    def getBillingCodeFromBackend(self, label) :       
227        """Extracts a billing code information given its name."""
228        code = StorageBillingCode(self, label)
229        result = self.doSearch("SELECT * FROM billingcodes WHERE billingcode=%s LIMIT 1" % self.doQuote(self.userCharsetToDatabase(label)))
230        if result :
231            fields = result[0]
232            code.ident = fields.get("id")
233            code.BillingCode = self.databaseToUserCharset(fields.get("billingcode"))
234            code.Description = self.databaseToUserCharset(fields.get("description") or "")
235            code.Balance = fields.get("balance") or 0.0
236            code.PageCounter = fields.get("pagecounter") or 0
237            code.Exists = 1
238        return code   
239       
240    def getUserPQuotaFromBackend(self, user, printer) :       
241        """Extracts a user print quota."""
242        userpquota = StorageUserPQuota(self, user, printer)
243        if printer.Exists and user.Exists :
244            result = self.doSearch("SELECT * FROM userpquota WHERE userid=%s AND printerid=%s" % (self.doQuote(user.ident), self.doQuote(printer.ident)))
245            if result :
246                fields = result[0]
247                userpquota.ident = fields.get("id")
248                userpquota.PageCounter = fields.get("pagecounter")
249                userpquota.LifePageCounter = fields.get("lifepagecounter")
250                userpquota.SoftLimit = fields.get("softlimit")
251                userpquota.HardLimit = fields.get("hardlimit")
252                userpquota.DateLimit = fields.get("datelimit")
253                userpquota.WarnCount = fields.get("warncount")
254                userpquota.Exists = 1
255        return userpquota
256       
257    def getGroupPQuotaFromBackend(self, group, printer) :       
258        """Extracts a group print quota."""
259        grouppquota = StorageGroupPQuota(self, group, printer)
260        if group.Exists :
261            result = self.doSearch("SELECT * FROM grouppquota WHERE groupid=%s AND printerid=%s" % (self.doQuote(group.ident), self.doQuote(printer.ident)))
262            if result :
263                fields = result[0]
264                grouppquota.ident = fields.get("id")
265                grouppquota.SoftLimit = fields.get("softlimit")
266                grouppquota.HardLimit = fields.get("hardlimit")
267                grouppquota.DateLimit = fields.get("datelimit")
268                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)))
269                if result :
270                    fields = result[0]
271                    grouppquota.PageCounter = fields.get("pagecounter") or 0
272                    grouppquota.LifePageCounter = fields.get("lifepagecounter") or 0
273                grouppquota.Exists = 1
274        return grouppquota
275       
276    def getPrinterLastJobFromBackend(self, printer) :       
277        """Extracts a printer's last job information."""
278        lastjob = StorageLastJob(self, printer)
279        result = self.doSearch("SELECT jobhistory.id, jobid, userid, username, pagecounter, jobsize, jobprice, filename, title, copies, options, hostname, jobdate, md5sum, pages, billingcode, precomputedjobsize, precomputedjobprice FROM jobhistory, users WHERE printerid=%s AND userid=users.id ORDER BY jobdate DESC LIMIT 1" % self.doQuote(printer.ident))
280        if result :
281            fields = result[0]
282            lastjob.ident = fields.get("id")
283            lastjob.JobId = fields.get("jobid")
284            lastjob.UserName = fields.get("username")
285            lastjob.PrinterPageCounter = fields.get("pagecounter")
286            lastjob.JobSize = fields.get("jobsize")
287            lastjob.JobPrice = fields.get("jobprice")
288            lastjob.JobAction = fields.get("action")
289            lastjob.JobFileName = self.databaseToUserCharset(fields.get("filename") or "") 
290            lastjob.JobTitle = self.databaseToUserCharset(fields.get("title") or "") 
291            lastjob.JobCopies = fields.get("copies")
292            lastjob.JobOptions = self.databaseToUserCharset(fields.get("options") or "") 
293            lastjob.JobDate = fields.get("jobdate")
294            lastjob.JobHostName = fields.get("hostname")
295            lastjob.JobSizeBytes = fields.get("jobsizebytes")
296            lastjob.JobMD5Sum = fields.get("md5sum")
297            lastjob.JobPages = fields.get("pages")
298            lastjob.JobBillingCode = self.databaseToUserCharset(fields.get("billingcode"))
299            lastjob.PrecomputedJobSize = fields.get("precomputedjobsize")
300            lastjob.PrecomputedJobPrice = fields.get("precomputedjobprice")
301            if lastjob.JobTitle == lastjob.JobFileName == lastjob.JobOptions == "hidden" :
302                (lastjob.JobTitle, lastjob.JobFileName, lastjob.JobOptions) = (_("Hidden because of privacy concerns"),) * 3
303            lastjob.Exists = 1
304        return lastjob
305           
306    def getGroupMembersFromBackend(self, group) :       
307        """Returns the group's members list."""
308        groupmembers = []
309        result = self.doSearch("SELECT * FROM groupsmembers JOIN users ON groupsmembers.userid=users.id WHERE groupid=%s" % self.doQuote(group.ident))
310        if result :
311            for record in result :
312                user = StorageUser(self, record.get("username"))
313                user.ident = record.get("userid")
314                user.LimitBy = record.get("limitby") or "quota"
315                user.AccountBalance = record.get("balance")
316                user.LifeTimePaid = record.get("lifetimepaid")
317                user.Email = record.get("email")
318                user.OverCharge = record.get("overcharge")
319                user.Exists = 1
320                groupmembers.append(user)
321                self.cacheEntry("USERS", user.Name, user)
322        return groupmembers       
323       
324    def getUserGroupsFromBackend(self, user) :       
325        """Returns the user's groups list."""
326        groups = []
327        result = self.doSearch("SELECT groupname FROM groupsmembers JOIN groups ON groupsmembers.groupid=groups.id WHERE userid=%s" % self.doQuote(user.ident))
328        if result :
329            for record in result :
330                groups.append(self.getGroup(record.get("groupname")))
331        return groups       
332       
333    def getParentPrintersFromBackend(self, printer) :   
334        """Get all the printer groups this printer is a member of."""
335        pgroups = []
336        result = self.doSearch("SELECT groupid,printername FROM printergroupsmembers JOIN printers ON groupid=id WHERE printerid=%s" % self.doQuote(printer.ident))
337        if result :
338            for record in result :
339                if record["groupid"] != printer.ident : # in case of integrity violation
340                    parentprinter = self.getPrinter(record.get("printername"))
341                    if parentprinter.Exists :
342                        pgroups.append(parentprinter)
343        return pgroups
344       
345    def getMatchingPrinters(self, printerpattern) :
346        """Returns the list of all printers for which name matches a certain pattern."""
347        printers = []
348        # We 'could' do a SELECT printername FROM printers WHERE printername LIKE ...
349        # but we don't because other storages semantics may be different, so every
350        # storage should use fnmatch to match patterns and be storage agnostic
351        result = self.doSearch("SELECT * FROM printers")
352        if result :
353            for record in result :
354                if self.tool.matchString(record["printername"], printerpattern.split(",")) :
355                    printer = StoragePrinter(self, record["printername"])
356                    printer.ident = record.get("id")
357                    printer.PricePerJob = record.get("priceperjob") or 0.0
358                    printer.PricePerPage = record.get("priceperpage") or 0.0
359                    printer.Description = self.databaseToUserCharset(record.get("description") or "") 
360                    printer.MaxJobSize = record.get("maxjobsize") or 0
361                    printer.PassThrough = record.get("passthrough") or 0
362                    if printer.PassThrough in (1, "1", "t", "true", "TRUE", "True") :
363                        printer.PassThrough = 1
364                    else :
365                        printer.PassThrough = 0
366                    printer.Exists = 1
367                    printers.append(printer)
368                    self.cacheEntry("PRINTERS", printer.Name, printer)
369        return printers       
370       
371    def getMatchingBillingCodes(self, billingcodepattern) :
372        """Returns the list of all billing codes for which the label matches a certain pattern."""
373        codes = []
374        result = self.doSearch("SELECT * FROM billingcodes")
375        if result :
376            for record in result :
377                bcode = self.databaseToUserCharset(record["billingcode"])
378                if self.tool.matchString(bcode, billingcodepattern.split(",")) :
379                    code = StorageBillingCode(self, bcode)
380                    code.ident = record.get("id")
381                    code.Balance = record.get("balance") or 0.0
382                    code.PageCounter = record.get("pagecounter") or 0
383                    code.Description = self.databaseToUserCharset(record.get("description") or "") 
384                    code.Exists = 1
385                    codes.append(code)
386                    self.cacheEntry("BILLINGCODES", code.BillingCode, code)
387        return codes       
388       
389    def getPrinterUsersAndQuotas(self, printer, names=["*"]) :       
390        """Returns the list of users who uses a given printer, along with their quotas."""
391        usersandquotas = []
392        result = self.doSearch("SELECT users.id as uid,username,balance,lifetimepaid,limitby,email,overcharge,userpquota.id,lifepagecounter,pagecounter,softlimit,hardlimit,datelimit,warncount FROM users JOIN userpquota ON users.id=userpquota.userid AND printerid=%s ORDER BY username ASC" % self.doQuote(printer.ident))
393        if result :
394            for record in result :
395                if self.tool.matchString(record.get("username"), names) :
396                    user = StorageUser(self, record.get("username"))
397                    user.ident = record.get("uid")
398                    user.LimitBy = record.get("limitby") or "quota"
399                    user.AccountBalance = record.get("balance")
400                    user.LifeTimePaid = record.get("lifetimepaid")
401                    user.Email = record.get("email") 
402                    user.OverCharge = record.get("overcharge")
403                    user.Exists = 1
404                    userpquota = StorageUserPQuota(self, user, printer)
405                    userpquota.ident = record.get("id")
406                    userpquota.PageCounter = record.get("pagecounter")
407                    userpquota.LifePageCounter = record.get("lifepagecounter")
408                    userpquota.SoftLimit = record.get("softlimit")
409                    userpquota.HardLimit = record.get("hardlimit")
410                    userpquota.DateLimit = record.get("datelimit")
411                    userpquota.WarnCount = record.get("warncount")
412                    userpquota.Exists = 1
413                    usersandquotas.append((user, userpquota))
414                    self.cacheEntry("USERS", user.Name, user)
415                    self.cacheEntry("USERPQUOTAS", "%s@%s" % (user.Name, printer.Name), userpquota)
416        return usersandquotas
417               
418    def getPrinterGroupsAndQuotas(self, printer, names=["*"]) :       
419        """Returns the list of groups which uses a given printer, along with their quotas."""
420        groupsandquotas = []
421        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))
422        if result :
423            for record in result :
424                if self.tool.matchString(record.get("groupname"), names) :
425                    group = self.getGroup(record.get("groupname"))
426                    grouppquota = self.getGroupPQuota(group, printer)
427                    groupsandquotas.append((group, grouppquota))
428        return groupsandquotas
429       
430    def addPrinter(self, printername) :       
431        """Adds a printer to the quota storage, returns it."""
432        self.doModify("INSERT INTO printers (printername) VALUES (%s)" % self.doQuote(printername))
433        return self.getPrinter(printername)
434       
435    def addBillingCode(self, label) :       
436        """Adds a billing code to the quota storage, returns it."""
437        self.doModify("INSERT INTO billingcodes (billingcode) VALUES (%s)" % self.doQuote(self.userCharsetToDatabase(label)))
438        return self.getBillingCode(label)
439       
440    def addUser(self, user) :       
441        """Adds a user to the quota storage, returns it."""
442        self.doModify("INSERT INTO users (username, limitby, balance, lifetimepaid, email, overcharge) VALUES (%s, %s, %s, %s, %s, %s)" % (self.doQuote(user.Name), self.doQuote(user.LimitBy or 'quota'), self.doQuote(user.AccountBalance or 0.0), self.doQuote(user.LifeTimePaid or 0.0), self.doQuote(user.Email), self.doQuote(user.OverCharge)))
443        return self.getUser(user.Name)
444       
445    def addGroup(self, group) :       
446        """Adds a group to the quota storage, returns it."""
447        self.doModify("INSERT INTO groups (groupname, limitby) VALUES (%s, %s)" % (self.doQuote(group.Name), self.doQuote(group.LimitBy or "quota")))
448        return self.getGroup(group.Name)
449
450    def addUserToGroup(self, user, group) :   
451        """Adds an user to a group."""
452        result = self.doSearch("SELECT COUNT(*) AS mexists FROM groupsmembers WHERE groupid=%s AND userid=%s" % (self.doQuote(group.ident), self.doQuote(user.ident)))
453        try :
454            mexists = int(result[0].get("mexists"))
455        except (IndexError, TypeError) :   
456            mexists = 0
457        if not mexists :   
458            self.doModify("INSERT INTO groupsmembers (groupid, userid) VALUES (%s, %s)" % (self.doQuote(group.ident), self.doQuote(user.ident)))
459           
460    def addUserPQuota(self, user, printer) :
461        """Initializes a user print quota on a printer."""
462        self.doModify("INSERT INTO userpquota (userid, printerid) VALUES (%s, %s)" % (self.doQuote(user.ident), self.doQuote(printer.ident)))
463        return self.getUserPQuota(user, printer)
464       
465    def addGroupPQuota(self, group, printer) :
466        """Initializes a group print quota on a printer."""
467        self.doModify("INSERT INTO grouppquota (groupid, printerid) VALUES (%s, %s)" % (self.doQuote(group.ident), self.doQuote(printer.ident)))
468        return self.getGroupPQuota(group, printer)
469       
470    def writePrinterPrices(self, printer) :   
471        """Write the printer's prices back into the storage."""
472        self.doModify("UPDATE printers SET priceperpage=%s, priceperjob=%s WHERE id=%s" % (self.doQuote(printer.PricePerPage), self.doQuote(printer.PricePerJob), self.doQuote(printer.ident)))
473       
474    def writePrinterDescription(self, printer) :   
475        """Write the printer's description back into the storage."""
476        description = self.userCharsetToDatabase(printer.Description)
477        self.doModify("UPDATE printers SET description=%s WHERE id=%s" % (self.doQuote(description), self.doQuote(printer.ident)))
478       
479    def setPrinterMaxJobSize(self, printer, maxjobsize) :     
480        """Write the printer's maxjobsize attribute."""
481        self.doModify("UPDATE printers SET maxjobsize=%s WHERE id=%s" % (self.doQuote(maxjobsize), self.doQuote(printer.ident)))
482       
483    def setPrinterPassThroughMode(self, printer, passthrough) :
484        """Write the printer's passthrough attribute."""
485        self.doModify("UPDATE printers SET passthrough=%s WHERE id=%s" % (self.doQuote((passthrough and "t") or "f"), self.doQuote(printer.ident)))
486       
487    def writeUserOverCharge(self, user, factor) :
488        """Sets the user's overcharging coefficient."""
489        self.doModify("UPDATE users SET overcharge=%s WHERE id=%s" % (self.doQuote(factor), self.doQuote(user.ident)))
490       
491    def writeUserLimitBy(self, user, limitby) :   
492        """Sets the user's limiting factor."""
493        self.doModify("UPDATE users SET limitby=%s WHERE id=%s" % (self.doQuote(limitby), self.doQuote(user.ident)))
494       
495    def writeGroupLimitBy(self, group, limitby) :   
496        """Sets the group's limiting factor."""
497        self.doModify("UPDATE groups SET limitby=%s WHERE id=%s" % (self.doQuote(limitby), self.doQuote(group.ident)))
498       
499    def writeUserPQuotaDateLimit(self, userpquota, datelimit) :   
500        """Sets the date limit permanently for a user print quota."""
501        self.doModify("UPDATE userpquota SET datelimit=%s WHERE id=%s" % (self.doQuote(datelimit), self.doQuote(userpquota.ident)))
502           
503    def writeGroupPQuotaDateLimit(self, grouppquota, datelimit) :   
504        """Sets the date limit permanently for a group print quota."""
505        self.doModify("UPDATE grouppquota SET datelimit=%s WHERE id=%s" % (self.doQuote(datelimit), self.doQuote(grouppquota.ident)))
506       
507    def increaseUserPQuotaPagesCounters(self, userpquota, nbpages) :   
508        """Increase page counters for a user print quota."""
509        self.doModify("UPDATE userpquota SET pagecounter=pagecounter + %s,lifepagecounter=lifepagecounter + %s WHERE id=%s" % (self.doQuote(nbpages), self.doQuote(nbpages), self.doQuote(userpquota.ident)))
510       
511    def writeUserPQuotaPagesCounters(self, userpquota, newpagecounter, newlifepagecounter) :   
512        """Sets the new page counters permanently for a user print quota."""
513        self.doModify("UPDATE userpquota SET pagecounter=%s, lifepagecounter=%s, warncount=0, datelimit=NULL WHERE id=%s" % (self.doQuote(newpagecounter), self.doQuote(newlifepagecounter), self.doQuote(userpquota.ident)))
514       
515    def writeBillingCodeDescription(self, code) :
516        """Sets the new description for a billing code."""
517        self.doModify("UPDATE billingcodes SET description=%s WHERE id=%s" % (self.doQuote(self.userCharsetToDatabase(code.Description or "")), self.doQuote(code.ident)))
518       
519    def setBillingCodeValues(self, code, newpagecounter, newbalance) :   
520        """Sets the new page counter and balance for a billing code."""
521        self.doModify("UPDATE billingcodes SET balance=%s, pagecounter=%s WHERE id=%s" % (self.doQuote(newbalance), self.doQuote(newpagecounter), self.doQuote(code.ident)))
522       
523    def consumeBillingCode(self, code, pagecounter, balance) :
524        """Consumes from a billing code."""
525        self.doModify("UPDATE billingcodes SET balance=balance + %s, pagecounter=pagecounter + %s WHERE id=%s" % (self.doQuote(balance), self.doQuote(pagecounter), self.doQuote(code.ident)))
526       
527    def decreaseUserAccountBalance(self, user, amount) :   
528        """Decreases user's account balance from an amount."""
529        self.doModify("UPDATE users SET balance=balance - %s WHERE id=%s" % (self.doQuote(amount), self.doQuote(user.ident)))
530       
531    def writeUserAccountBalance(self, user, newbalance, newlifetimepaid=None) :   
532        """Sets the new account balance and eventually new lifetime paid."""
533        if newlifetimepaid is not None :
534            self.doModify("UPDATE users SET balance=%s, lifetimepaid=%s WHERE id=%s" % (self.doQuote(newbalance), self.doQuote(newlifetimepaid), self.doQuote(user.ident)))
535        else :   
536            self.doModify("UPDATE users SET balance=%s WHERE id=%s" % (self.doQuote(newbalance), self.doQuote(user.ident)))
537           
538    def writeNewPayment(self, user, amount, comment="") :
539        """Adds a new payment to the payments history."""
540        self.doModify("INSERT INTO payments (userid, amount, description) VALUES (%s, %s, %s)" % (self.doQuote(user.ident), self.doQuote(amount), self.doQuote(comment)))
541       
542    def writeLastJobSize(self, lastjob, jobsize, jobprice) :       
543        """Sets the last job's size permanently."""
544        self.doModify("UPDATE jobhistory SET jobsize=%s, jobprice=%s WHERE id=%s" % (self.doQuote(jobsize), self.doQuote(jobprice), self.doQuote(lastjob.ident)))
545       
546    def writeJobNew(self, printer, user, jobid, pagecounter, action, jobsize=None, jobprice=None, filename=None, title=None, copies=None, options=None, clienthost=None, jobsizebytes=None, jobmd5sum=None, jobpages=None, jobbilling=None, precomputedsize=None, precomputedprice=None) :
547        """Adds a job in a printer's history."""
548        if self.privacy :   
549            # For legal reasons, we want to hide the title, filename and options
550            title = filename = options = "hidden"
551        filename = self.userCharsetToDatabase(filename)
552        title = self.userCharsetToDatabase(title)
553        options = self.userCharsetToDatabase(options)
554        jobbilling = self.userCharsetToDatabase(jobbilling)
555        if (not self.disablehistory) or (not printer.LastJob.Exists) :
556            if jobsize is not None :
557                self.doModify("INSERT INTO jobhistory (userid, printerid, jobid, pagecounter, action, jobsize, jobprice, filename, title, copies, options, hostname, jobsizebytes, md5sum, pages, billingcode, precomputedjobsize, precomputedjobprice) VALUES (%s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s)" % (self.doQuote(user.ident), self.doQuote(printer.ident), self.doQuote(jobid), self.doQuote(pagecounter), self.doQuote(action), self.doQuote(jobsize), self.doQuote(jobprice), self.doQuote(filename), self.doQuote(title), self.doQuote(copies), self.doQuote(options), self.doQuote(clienthost), self.doQuote(jobsizebytes), self.doQuote(jobmd5sum), self.doQuote(jobpages), self.doQuote(jobbilling), self.doQuote(precomputedsize), self.doQuote(precomputedprice)))
558            else :   
559                self.doModify("INSERT INTO jobhistory (userid, printerid, jobid, pagecounter, action, filename, title, copies, options, hostname, jobsizebytes, md5sum, pages, billingcode, precomputedjobsize, precomputedjobprice) VALUES (%s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s)" % (self.doQuote(user.ident), self.doQuote(printer.ident), self.doQuote(jobid), self.doQuote(pagecounter), self.doQuote(action), self.doQuote(filename), self.doQuote(title), self.doQuote(copies), self.doQuote(options), self.doQuote(clienthost), self.doQuote(jobsizebytes), self.doQuote(jobmd5sum), self.doQuote(jobpages), self.doQuote(jobbilling), self.doQuote(precomputedsize), self.doQuote(precomputedprice)))
560        else :       
561            # here we explicitly want to reset jobsize to NULL if needed
562            self.doModify("UPDATE jobhistory SET userid=%s, jobid=%s, pagecounter=%s, action=%s, jobsize=%s, jobprice=%s, filename=%s, title=%s, copies=%s, options=%s, hostname=%s, jobsizebytes=%s, md5sum=%s, pages=%s, billingcode=%s, precomputedjobsize=%s, precomputedjobprice=%s, jobdate=now() WHERE id=%s" % (self.doQuote(user.ident), self.doQuote(jobid), self.doQuote(pagecounter), self.doQuote(action), self.doQuote(jobsize), self.doQuote(jobprice), self.doQuote(filename), self.doQuote(title), self.doQuote(copies), self.doQuote(options), self.doQuote(clienthost), self.doQuote(jobsizebytes), self.doQuote(jobmd5sum), self.doQuote(jobpages), self.doQuote(jobbilling), self.doQuote(precomputedsize), self.doQuote(precomputedprice), self.doQuote(printer.LastJob.ident)))
563           
564    def writeUserPQuotaLimits(self, userpquota, softlimit, hardlimit) :
565        """Sets soft and hard limits for a user quota."""
566        self.doModify("UPDATE userpquota SET softlimit=%s, hardlimit=%s, warncount=0, datelimit=NULL WHERE id=%s" % (self.doQuote(softlimit), self.doQuote(hardlimit), self.doQuote(userpquota.ident)))
567       
568    def writeUserPQuotaWarnCount(self, userpquota, warncount) :
569        """Sets the warn counter value for a user quota."""
570        self.doModify("UPDATE userpquota SET warncount=%s WHERE id=%s" % (self.doQuote(warncount), self.doQuote(userpquota.ident)))
571       
572    def increaseUserPQuotaWarnCount(self, userpquota) :
573        """Increases the warn counter value for a user quota."""
574        self.doModify("UPDATE userpquota SET warncount=warncount+1 WHERE id=%s" % self.doQuote(userpquota.ident))
575       
576    def writeGroupPQuotaLimits(self, grouppquota, softlimit, hardlimit) :
577        """Sets soft and hard limits for a group quota on a specific printer."""
578        self.doModify("UPDATE grouppquota SET softlimit=%s, hardlimit=%s, datelimit=NULL WHERE id=%s" % (self.doQuote(softlimit), self.doQuote(hardlimit), self.doQuote(grouppquota.ident)))
579
580    def writePrinterToGroup(self, pgroup, printer) :
581        """Puts a printer into a printer group."""
582        children = []
583        result = self.doSearch("SELECT printerid FROM printergroupsmembers WHERE groupid=%s" % self.doQuote(pgroup.ident))
584        if result :
585            for record in result :
586                children.append(record.get("printerid")) # TODO : put this into the database integrity rules
587        if printer.ident not in children :       
588            self.doModify("INSERT INTO printergroupsmembers (groupid, printerid) VALUES (%s, %s)" % (self.doQuote(pgroup.ident), self.doQuote(printer.ident)))
589       
590    def removePrinterFromGroup(self, pgroup, printer) :
591        """Removes a printer from a printer group."""
592        self.doModify("DELETE FROM printergroupsmembers WHERE groupid=%s AND printerid=%s" % (self.doQuote(pgroup.ident), self.doQuote(printer.ident)))
593       
594    def retrieveHistory(self, user=None, printer=None, hostname=None, billingcode=None, limit=100, start=None, end=None) :
595        """Retrieves all print jobs for user on printer (or all) between start and end date, limited to first 100 results."""
596        query = "SELECT jobhistory.*,username,printername FROM jobhistory,users,printers WHERE users.id=userid AND printers.id=printerid"
597        where = []
598        if user is not None : # user.ident is None anyway if user doesn't exist
599            where.append("userid=%s" % self.doQuote(user.ident))
600        if printer is not None : # printer.ident is None anyway if printer doesn't exist
601            where.append("printerid=%s" % self.doQuote(printer.ident))
602        if hostname is not None :   
603            where.append("hostname=%s" % self.doQuote(hostname))
604        if billingcode is not None :   
605            where.append("billingcode=%s" % self.doQuote(self.userCharsetToDatabase(billingcode)))
606        if start is not None :   
607            where.append("jobdate>=%s" % self.doQuote(start))
608        if end is not None :   
609            where.append("jobdate<=%s" % self.doQuote(end))
610        if where :   
611            query += " AND %s" % " AND ".join(where)
612        query += " ORDER BY id DESC"
613        if limit :
614            query += " LIMIT %s" % self.doQuote(int(limit))
615        jobs = []   
616        result = self.doSearch(query)   
617        if result :
618            for fields in result :
619                job = StorageJob(self)
620                job.ident = fields.get("id")
621                job.JobId = fields.get("jobid")
622                job.PrinterPageCounter = fields.get("pagecounter")
623                job.JobSize = fields.get("jobsize")
624                job.JobPrice = fields.get("jobprice")
625                job.JobAction = fields.get("action")
626                job.JobFileName = self.databaseToUserCharset(fields.get("filename") or "") 
627                job.JobTitle = self.databaseToUserCharset(fields.get("title") or "") 
628                job.JobCopies = fields.get("copies")
629                job.JobOptions = self.databaseToUserCharset(fields.get("options") or "") 
630                job.JobDate = fields.get("jobdate")
631                job.JobHostName = fields.get("hostname")
632                job.JobSizeBytes = fields.get("jobsizebytes")
633                job.JobMD5Sum = fields.get("md5sum")
634                job.JobPages = fields.get("pages")
635                job.JobBillingCode = self.databaseToUserCharset(fields.get("billingcode") or "")
636                job.PrecomputedJobSize = fields.get("precomputedjobsize")
637                job.PrecomputedJobPrice = fields.get("precomputedjobprice")
638                job.UserName = fields.get("username")
639                job.PrinterName = fields.get("printername")
640                if job.JobTitle == job.JobFileName == job.JobOptions == "hidden" :
641                    (job.JobTitle, job.JobFileName, job.JobOptions) = (_("Hidden because of privacy concerns"),) * 3
642                job.Exists = 1
643                jobs.append(job)
644        return jobs
645       
646    def deleteUser(self, user) :   
647        """Completely deletes an user from the Quota Storage."""
648        # TODO : What should we do if we delete the last person who used a given printer ?
649        # TODO : we can't reassign the last job to the previous one, because next user would be
650        # TODO : incorrectly charged (overcharged).
651        for q in [ 
652                    "DELETE FROM payments WHERE userid=%s" % self.doQuote(user.ident),
653                    "DELETE FROM groupsmembers WHERE userid=%s" % self.doQuote(user.ident),
654                    "DELETE FROM jobhistory WHERE userid=%s" % self.doQuote(user.ident),
655                    "DELETE FROM userpquota WHERE userid=%s" % self.doQuote(user.ident),
656                    "DELETE FROM users WHERE id=%s" % self.doQuote(user.ident),
657                  ] :
658            self.doModify(q)
659       
660    def deleteGroup(self, group) :   
661        """Completely deletes a group from the Quota Storage."""
662        for q in [
663                   "DELETE FROM groupsmembers WHERE groupid=%s" % self.doQuote(group.ident),
664                   "DELETE FROM grouppquota WHERE groupid=%s" % self.doQuote(group.ident),
665                   "DELETE FROM groups WHERE id=%s" % self.doQuote(group.ident),
666                 ] : 
667            self.doModify(q)
668           
669    def deletePrinter(self, printer) :   
670        """Completely deletes a printer from the Quota Storage."""
671        for q in [ 
672                    "DELETE FROM printergroupsmembers WHERE groupid=%s OR printerid=%s" % (self.doQuote(printer.ident), self.doQuote(printer.ident)),
673                    "DELETE FROM jobhistory WHERE printerid=%s" % self.doQuote(printer.ident),
674                    "DELETE FROM grouppquota WHERE printerid=%s" % self.doQuote(printer.ident),
675                    "DELETE FROM userpquota WHERE printerid=%s" % self.doQuote(printer.ident),
676                    "DELETE FROM printers WHERE id=%s" % self.doQuote(printer.ident),
677                  ] :
678            self.doModify(q)
679           
680    def deleteBillingCode(self, code) :   
681        """Completely deletes a billing code from the Quota Storage."""
682        for q in [
683                   "DELETE FROM billingcodes WHERE id=%s" % self.doQuote(code.ident),
684                 ] : 
685            self.doModify(q)
686       
Note: See TracBrowser for help on using the browser.