~vauxoo/addons-vauxoo/gbw

« back to all changes in this revision

Viewing changes to account/report/account_invoice_report.py

  • Committer: Isaac Lopez
  • Date: 2012-05-08 22:46:41 UTC
  • Revision ID: isaac@vauxoo.com-20120508224641-ge7uo6srn4ift4mq
[ADD][account] account with patch requiered by facturae and digits_compute added on quantity field
[ADD][l10n_mx_invoice_discount] discount module customized GBW

Show diffs side-by-side

added added

removed removed

Lines of Context:
 
1
# -*- coding: utf-8 -*-
 
2
##############################################################################
 
3
#
 
4
#    OpenERP, Open Source Management Solution
 
5
#    Copyright (C) 2004-2010 Tiny SPRL (<http://tiny.be>).
 
6
#
 
7
#    This program is free software: you can redistribute it and/or modify
 
8
#    it under the terms of the GNU Affero General Public License as
 
9
#    published by the Free Software Foundation, either version 3 of the
 
10
#    License, or (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 Affero General Public License for more details.
 
16
#
 
17
#    You should have received a copy of the GNU Affero General Public License
 
18
#    along with this program.  If not, see <http://www.gnu.org/licenses/>.
 
19
#
 
20
##############################################################################
 
21
 
 
22
import tools
 
23
from osv import fields,osv
 
24
 
 
25
class account_invoice_report(osv.osv):
 
26
    _name = "account.invoice.report"
 
27
    _description = "Invoices Statistics"
 
28
    _auto = False
 
29
    _rec_name = 'date'
 
30
    _columns = {
 
31
        'date': fields.date('Date', readonly=True),
 
32
        'year': fields.char('Year', size=4, readonly=True),
 
33
        'day': fields.char('Day', size=128, readonly=True),
 
34
        'month': fields.selection([('01','January'), ('02','February'), ('03','March'), ('04','April'),
 
35
            ('05','May'), ('06','June'), ('07','July'), ('08','August'), ('09','September'),
 
36
            ('10','October'), ('11','November'), ('12','December')], 'Month', readonly=True),
 
37
        'product_id': fields.many2one('product.product', 'Product', readonly=True),
 
38
        'product_qty':fields.float('Qty', readonly=True),
 
39
        'uom_name': fields.char('Reference UoM', size=128, readonly=True),
 
40
        'payment_term': fields.many2one('account.payment.term', 'Payment Term', readonly=True),
 
41
        'period_id': fields.many2one('account.period', 'Force Period', domain=[('state','<>','done')], readonly=True),
 
42
        'fiscal_position': fields.many2one('account.fiscal.position', 'Fiscal Position', readonly=True),
 
43
        'currency_id': fields.many2one('res.currency', 'Currency', readonly=True),
 
44
        'categ_id': fields.many2one('product.category','Category of Product', readonly=True),
 
45
        'journal_id': fields.many2one('account.journal', 'Journal', readonly=True),
 
46
        'partner_id': fields.many2one('res.partner', 'Partner', readonly=True),
 
47
        'company_id': fields.many2one('res.company', 'Company', readonly=True),
 
48
        'user_id': fields.many2one('res.users', 'Salesman', readonly=True),
 
49
        'price_total': fields.float('Total Without Tax', readonly=True),
 
50
        'price_total_tax': fields.float('Total With Tax', readonly=True),
 
51
        'price_average': fields.float('Average Price', readonly=True, group_operator="avg"),
 
52
        'currency_rate': fields.float('Currency Rate', readonly=True),
 
53
        'nbr':fields.integer('# of Lines', readonly=True),
 
54
        'type': fields.selection([
 
55
            ('out_invoice','Customer Invoice'),
 
56
            ('in_invoice','Supplier Invoice'),
 
57
            ('out_refund','Customer Refund'),
 
58
            ('in_refund','Supplier Refund'),
 
59
            ],'Type', readonly=True),
 
60
        'state': fields.selection([
 
61
            ('draft','Draft'),
 
62
            ('proforma','Pro-forma'),
 
63
            ('proforma2','Pro-forma'),
 
64
            ('open','Open'),
 
65
            ('paid','Done'),
 
66
            ('cancel','Cancelled')
 
67
            ], 'Invoice State', readonly=True),
 
68
        'date_due': fields.date('Due Date', readonly=True),
 
69
        'address_contact_id': fields.many2one('res.partner.address', 'Contact Address Name', readonly=True),
 
70
        'address_invoice_id': fields.many2one('res.partner.address', 'Invoice Address Name', readonly=True),
 
71
        'account_id': fields.many2one('account.account', 'Account',readonly=True),
 
72
        'partner_bank_id': fields.many2one('res.partner.bank', 'Bank Account',readonly=True),
 
73
        'residual': fields.float('Total Residual', readonly=True),
 
74
        'delay_to_pay': fields.float('Avg. Delay To Pay', readonly=True, group_operator="avg"),
 
75
        'due_delay': fields.float('Avg. Due Delay', readonly=True, group_operator="avg"),
 
76
    }
 
77
    _order = 'date desc'
 
78
    def init(self, cr):
 
79
        tools.drop_view_if_exists(cr, 'account_invoice_report')
 
80
        cr.execute("""
 
81
            create or replace view account_invoice_report as (
 
82
                 select min(ail.id) as id,
 
83
                    CAST( ai.date_invoice AS DATE) as date,
 
84
                    to_char(ai.date_invoice, 'YYYY') as year,
 
85
                    to_char(ai.date_invoice, 'MM') as month,
 
86
                    to_char(ai.date_invoice, 'YYYY-MM-DD') as day,
 
87
                    to_char(ai.date_invoice, 'YYYY') as year,
 
88
                    to_char(ai.date_invoice, 'MM') as month,
 
89
                    to_char(ai.date_invoice, 'YYYY-MM-DD') as day,
 
90
                    ail.product_id,
 
91
                    ai.partner_id as partner_id,
 
92
                    ai.payment_term as payment_term,
 
93
                    ai.period_id as period_id,
 
94
                    (case when u.uom_type not in ('reference') then
 
95
                        (select name from product_uom where uom_type='reference' and active and category_id=u.category_id LIMIT 1)
 
96
                    else
 
97
                        u.name
 
98
                    end) as uom_name,
 
99
                    ai.currency_id as currency_id,
 
100
                    ai.journal_id as journal_id,
 
101
                    ai.fiscal_position as fiscal_position,
 
102
                    ai.user_id as user_id,
 
103
                    ai.company_id as company_id,
 
104
                    count(ail.*) as nbr,
 
105
                    ai.type as type,
 
106
                    ai.state,
 
107
                    pt.categ_id,
 
108
                    ai.date_due as date_due,
 
109
                    ai.address_contact_id as address_contact_id,
 
110
                    ai.address_invoice_id as address_invoice_id,
 
111
                    ai.account_id as account_id,
 
112
                    ai.partner_bank_id as partner_bank_id,
 
113
                    sum(case when ai.type in ('out_refund','in_invoice') then
 
114
                         ail.quantity / u.factor * -1
 
115
                        else
 
116
                         ail.quantity / u.factor
 
117
                        end) as product_qty,
 
118
                    sum(case when ai.type in ('out_refund','in_invoice') then
 
119
                         ail.quantity*ail.price_unit * -1
 
120
                        else
 
121
                         ail.quantity*ail.price_unit
 
122
                        end) / cr.rate as price_total,
 
123
                    sum(case when ai.type in ('out_refund','in_invoice') then
 
124
                         ai.amount_total * -1
 
125
                        else
 
126
                         ai.amount_total
 
127
                         end) / (CASE WHEN 
 
128
                              (select count(l.id) from account_invoice_line as l
 
129
                               left join account_invoice as a ON (a.id=l.invoice_id)
 
130
                               where a.id=ai.id) <> 0 
 
131
                            THEN 
 
132
                              (select count(l.id) from account_invoice_line as l
 
133
                               left join account_invoice as a ON (a.id=l.invoice_id)
 
134
                               where a.id=ai.id) 
 
135
                            ELSE 1 
 
136
                            END) / cr.rate as price_total_tax,
 
137
                    (case when ai.type in ('out_refund','in_invoice') then
 
138
                      sum(ail.quantity*ail.price_unit*-1)
 
139
                    else
 
140
                      sum(ail.quantity*ail.price_unit)
 
141
                    end) / (CASE WHEN
 
142
                         (case when ai.type in ('out_refund','in_invoice') 
 
143
                          then sum(ail.quantity/u.factor*-1)
 
144
                          else sum(ail.quantity/u.factor) end) <> 0 
 
145
                       THEN 
 
146
                         (case when ai.type in ('out_refund','in_invoice') 
 
147
                          then sum(ail.quantity/u.factor*-1)
 
148
                          else sum(ail.quantity/u.factor) end) 
 
149
                       ELSE 1 
 
150
                       END)
 
151
                     / cr.rate as price_average,
 
152
 
 
153
                    cr.rate as currency_rate,
 
154
                    sum((select extract(epoch from avg(date_trunc('day',aml.date_created)-date_trunc('day',l.create_date)))/(24*60*60)::decimal(16,2)
 
155
                        from account_move_line as aml
 
156
                        left join account_invoice as a ON (a.move_id=aml.move_id)
 
157
                        left join account_invoice_line as l ON (a.id=l.invoice_id)
 
158
                        where a.id=ai.id)) as delay_to_pay,
 
159
                    sum((select extract(epoch from avg(date_trunc('day',a.date_due)-date_trunc('day',a.date_invoice)))/(24*60*60)::decimal(16,2)
 
160
                        from account_move_line as aml
 
161
                        left join account_invoice as a ON (a.move_id=aml.move_id)
 
162
                        left join account_invoice_line as l ON (a.id=l.invoice_id)
 
163
                        where a.id=ai.id)) as due_delay,
 
164
                    (case when ai.type in ('out_refund','in_invoice') then
 
165
                      ai.residual * -1
 
166
                    else
 
167
                      ai.residual
 
168
                    end)/ (CASE WHEN 
 
169
                        (select count(l.id) from account_invoice_line as l
 
170
                         left join account_invoice as a ON (a.id=l.invoice_id)
 
171
                         where a.id=ai.id) <> 0 
 
172
                       THEN
 
173
                        (select count(l.id) from account_invoice_line as l
 
174
                         left join account_invoice as a ON (a.id=l.invoice_id)
 
175
                         where a.id=ai.id) 
 
176
                       ELSE 1 
 
177
                       END) / cr.rate as residual
 
178
                from account_invoice_line as ail
 
179
                left join account_invoice as ai ON (ai.id=ail.invoice_id)
 
180
                left join product_template pt on (pt.id=ail.product_id)
 
181
                left join product_uom u on (u.id=ail.uos_id),
 
182
                res_currency_rate cr
 
183
                where cr.id in (select id from res_currency_rate cr2  where (cr2.currency_id = ai.currency_id)
 
184
                and ((ai.date_invoice is not null and cr.name <= ai.date_invoice) or (ai.date_invoice is null and cr.name <= NOW())) limit 1)
 
185
                group by ail.product_id,
 
186
                    ai.date_invoice,
 
187
                    ai.id,
 
188
                    cr.rate,
 
189
                    to_char(ai.date_invoice, 'YYYY'),
 
190
                    to_char(ai.date_invoice, 'MM'),
 
191
                    to_char(ai.date_invoice, 'YYYY-MM-DD'),
 
192
                    ai.partner_id,
 
193
                    ai.payment_term,
 
194
                    ai.period_id,
 
195
                    u.name,
 
196
                    ai.currency_id,
 
197
                    ai.journal_id,
 
198
                    ai.fiscal_position,
 
199
                    ai.user_id,
 
200
                    ai.company_id,
 
201
                    ai.type,
 
202
                    ai.state,
 
203
                    pt.categ_id,
 
204
                    ai.date_due,
 
205
                    ai.address_contact_id,
 
206
                    ai.address_invoice_id,
 
207
                    ai.account_id,
 
208
                    ai.partner_bank_id,
 
209
                    ai.residual,
 
210
                    ai.amount_total,
 
211
                    u.uom_type,
 
212
                    u.category_id
 
213
            )
 
214
        """)
 
215
 
 
216
account_invoice_report()
 
217
 
 
218
# vim:expandtab:smartindent:tabstop=4:softtabstop=4:shiftwidth=4: