You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

322 lines
15 KiB

  1. # -*- coding: utf-8 -*-
  2. # Copyright 2017 Eficent Business and IT Consulting Services S.L.
  3. # (http://www.eficent.com)
  4. # License AGPL-3.0 or later (https://www.gnu.org/licenses/agpl.html).
  5. from datetime import datetime, timedelta
  6. from odoo.tools.misc import DEFAULT_SERVER_DATE_FORMAT
  7. from odoo import api, fields, models
  8. class CustomerOutstandingStatement(models.AbstractModel):
  9. """Model of Customer Outstanding Statement"""
  10. _name = 'report.customer_outstanding_statement.statement'
  11. def _format_date_to_partner_lang(self, str_date, partner_id):
  12. lang_code = self.env['res.partner'].browse(partner_id).lang
  13. lang = self.env['res.lang']._lang_get(lang_code)
  14. date = datetime.strptime(str_date, DEFAULT_SERVER_DATE_FORMAT).date()
  15. return date.strftime(lang.date_format)
  16. def _display_lines_sql_q1(self, partners, date_end):
  17. return """
  18. SELECT m.name as move_id, l.partner_id, l.date, l.name,
  19. l.ref, l.blocked, l.currency_id, l.company_id,
  20. CASE WHEN (l.currency_id is not null AND l.amount_currency > 0.0)
  21. THEN sum(l.amount_currency)
  22. ELSE sum(l.debit)
  23. END as debit,
  24. CASE WHEN (l.currency_id is not null AND l.amount_currency < 0.0)
  25. THEN sum(l.amount_currency * (-1))
  26. ELSE sum(l.credit)
  27. END as credit,
  28. CASE WHEN l.balance > 0.0
  29. THEN l.balance - sum(coalesce(pd.amount, 0.0))
  30. ELSE l.balance + sum(coalesce(pc.amount, 0.0))
  31. END AS open_amount,
  32. CASE WHEN l.balance > 0.0
  33. THEN l.amount_currency - sum(coalesce(pd.amount_currency, 0.0))
  34. ELSE l.amount_currency + sum(coalesce(pc.amount_currency, 0.0))
  35. END AS open_amount_currency,
  36. CASE WHEN l.date_maturity is null
  37. THEN l.date
  38. ELSE l.date_maturity
  39. END as date_maturity
  40. FROM account_move_line l
  41. JOIN account_account_type at ON (at.id = l.user_type_id)
  42. JOIN account_move m ON (l.move_id = m.id)
  43. LEFT JOIN (SELECT pr.*
  44. FROM account_partial_reconcile pr
  45. INNER JOIN account_move_line l2
  46. ON pr.credit_move_id = l2.id
  47. WHERE l2.date <= '%s'
  48. ) as pd ON pd.debit_move_id = l.id
  49. LEFT JOIN (SELECT pr.*
  50. FROM account_partial_reconcile pr
  51. INNER JOIN account_move_line l2
  52. ON pr.debit_move_id = l2.id
  53. WHERE l2.date <= '%s'
  54. ) as pc ON pc.credit_move_id = l.id
  55. WHERE l.partner_id IN (%s) AND at.type = 'receivable'
  56. AND not l.reconciled AND l.date <= '%s'
  57. GROUP BY l.partner_id, m.name, l.date, l.date_maturity, l.name,
  58. l.ref, l.blocked, l.currency_id,
  59. l.balance, l.amount_currency, l.company_id
  60. """ % (date_end, date_end, partners, date_end)
  61. def _display_lines_sql_q2(self):
  62. return """
  63. SELECT partner_id, currency_id, move_id, date, date_maturity,
  64. debit, credit, name, ref, blocked, company_id,
  65. CASE WHEN currency_id is not null
  66. THEN open_amount_currency
  67. ELSE open_amount
  68. END as open_amount
  69. FROM Q1
  70. """
  71. def _display_lines_sql_q3(self, company_id):
  72. return """
  73. SELECT Q2.partner_id, move_id, date, date_maturity, Q2.name, ref,
  74. debit, credit, debit-credit AS amount, blocked,
  75. COALESCE(Q2.currency_id, c.currency_id) AS currency_id, open_amount
  76. FROM Q2
  77. JOIN res_company c ON (c.id = Q2.company_id)
  78. WHERE c.id = %s
  79. """ % company_id
  80. def _get_account_display_lines(self, company_id, partner_ids, date_end):
  81. res = dict(map(lambda x: (x, []), partner_ids))
  82. partners = ', '.join([str(i) for i in partner_ids])
  83. date_end = datetime.strptime(
  84. date_end, DEFAULT_SERVER_DATE_FORMAT).date()
  85. self.env.cr.execute("""WITH Q1 AS (%s), Q2 AS (%s), Q3 AS (%s)
  86. SELECT partner_id, currency_id, move_id, date, date_maturity, debit,
  87. credit, amount, open_amount, name, ref, blocked
  88. FROM Q3
  89. ORDER BY date, date_maturity, move_id""" % (
  90. self._display_lines_sql_q1(partners, date_end),
  91. self._display_lines_sql_q2(),
  92. self._display_lines_sql_q3(company_id)))
  93. for row in self.env.cr.dictfetchall():
  94. res[row.pop('partner_id')].append(row)
  95. return res
  96. def _show_buckets_sql_q1(self, partners, date_end):
  97. return """
  98. SELECT l.partner_id, l.currency_id, l.company_id, l.move_id,
  99. CASE WHEN l.balance > 0.0
  100. THEN l.balance - sum(coalesce(pd.amount, 0.0))
  101. ELSE l.balance + sum(coalesce(pc.amount, 0.0))
  102. END AS open_due,
  103. CASE WHEN l.balance > 0.0
  104. THEN l.amount_currency - sum(coalesce(pd.amount_currency, 0.0))
  105. ELSE l.amount_currency + sum(coalesce(pc.amount_currency, 0.0))
  106. END AS open_due_currency,
  107. CASE WHEN l.date_maturity is null
  108. THEN l.date
  109. ELSE l.date_maturity
  110. END as date_maturity
  111. FROM account_move_line l
  112. JOIN account_account_type at ON (at.id = l.user_type_id)
  113. JOIN account_move m ON (l.move_id = m.id)
  114. LEFT JOIN (SELECT pr.*
  115. FROM account_partial_reconcile pr
  116. INNER JOIN account_move_line l2
  117. ON pr.credit_move_id = l2.id
  118. WHERE l2.date <= '%s'
  119. ) as pd ON pd.debit_move_id = l.id
  120. LEFT JOIN (SELECT pr.*
  121. FROM account_partial_reconcile pr
  122. INNER JOIN account_move_line l2
  123. ON pr.debit_move_id = l2.id
  124. WHERE l2.date <= '%s'
  125. ) as pc ON pc.credit_move_id = l.id
  126. WHERE l.partner_id IN (%s) AND at.type = 'receivable'
  127. AND not l.reconciled AND not l.blocked
  128. GROUP BY l.partner_id, l.currency_id, l.date, l.date_maturity,
  129. l.amount_currency, l.balance, l.move_id,
  130. l.company_id
  131. """ % (date_end, date_end, partners)
  132. def _show_buckets_sql_q2(self, today, minus_30, minus_60, minus_90,
  133. minus_120):
  134. return """
  135. SELECT partner_id, currency_id, date_maturity, open_due,
  136. open_due_currency, move_id, company_id,
  137. CASE
  138. WHEN '%s' <= date_maturity AND currency_id is null
  139. THEN open_due
  140. WHEN '%s' <= date_maturity AND currency_id is not null
  141. THEN open_due_currency
  142. ELSE 0.0
  143. END as current,
  144. CASE
  145. WHEN '%s' < date_maturity AND date_maturity < '%s'
  146. AND currency_id is null THEN open_due
  147. WHEN '%s' < date_maturity AND date_maturity < '%s'
  148. AND currency_id is not null
  149. THEN open_due_currency
  150. ELSE 0.0
  151. END as b_1_30,
  152. CASE
  153. WHEN '%s' < date_maturity AND date_maturity <= '%s'
  154. AND currency_id is null THEN open_due
  155. WHEN '%s' < date_maturity AND date_maturity <= '%s'
  156. AND currency_id is not null
  157. THEN open_due_currency
  158. ELSE 0.0
  159. END as b_30_60,
  160. CASE
  161. WHEN '%s' < date_maturity AND date_maturity <= '%s'
  162. AND currency_id is null THEN open_due
  163. WHEN '%s' < date_maturity AND date_maturity <= '%s'
  164. AND currency_id is not null
  165. THEN open_due_currency
  166. ELSE 0.0
  167. END as b_60_90,
  168. CASE
  169. WHEN '%s' < date_maturity AND date_maturity <= '%s'
  170. AND currency_id is null THEN open_due
  171. WHEN '%s' < date_maturity AND date_maturity <= '%s'
  172. AND currency_id is not null
  173. THEN open_due_currency
  174. ELSE 0.0
  175. END as b_90_120,
  176. CASE
  177. WHEN date_maturity <= '%s' AND currency_id is null
  178. THEN open_due
  179. WHEN date_maturity <= '%s' AND currency_id is not null
  180. THEN open_due_currency
  181. ELSE 0.0
  182. END as b_over_120
  183. FROM Q1
  184. GROUP BY partner_id, currency_id, date_maturity, open_due,
  185. open_due_currency, move_id, company_id
  186. """ % (today, today, minus_30, today, minus_30, today, minus_60,
  187. minus_30, minus_60, minus_30, minus_90, minus_60, minus_90,
  188. minus_60, minus_120, minus_90, minus_120, minus_90, minus_120,
  189. minus_120)
  190. def _show_buckets_sql_q3(self, company_id):
  191. return """
  192. SELECT Q2.partner_id, current, b_1_30, b_30_60, b_60_90, b_90_120,
  193. b_over_120,
  194. COALESCE(Q2.currency_id, c.currency_id) AS currency_id
  195. FROM Q2
  196. JOIN res_company c ON (c.id = Q2.company_id)
  197. WHERE c.id = %s
  198. """ % company_id
  199. def _show_buckets_sql_q4(self):
  200. return """
  201. SELECT partner_id, currency_id, sum(current) as current,
  202. sum(b_1_30) as b_1_30,
  203. sum(b_30_60) as b_30_60,
  204. sum(b_60_90) as b_60_90,
  205. sum(b_90_120) as b_90_120,
  206. sum(b_over_120) as b_over_120
  207. FROM Q3
  208. GROUP BY partner_id, currency_id
  209. """
  210. _bucket_dates = {
  211. 'today': fields.date.today(),
  212. 'minus_30': fields.date.today() - timedelta(days=30),
  213. 'minus_60': fields.date.today() - timedelta(days=60),
  214. 'minus_90': fields.date.today() - timedelta(days=90),
  215. 'minus_120': fields.date.today() - timedelta(days=120),
  216. }
  217. def _get_account_show_buckets(self, company_id, partner_ids, date_end):
  218. res = dict(map(lambda x: (x, []), partner_ids))
  219. partners = ', '.join([str(i) for i in partner_ids])
  220. date_end = datetime.strptime(
  221. date_end, DEFAULT_SERVER_DATE_FORMAT).date()
  222. self.env.cr.execute("""WITH Q1 AS (%s), Q2 AS (%s),
  223. Q3 AS (%s), Q4 AS (%s)
  224. SELECT partner_id, currency_id, current, b_1_30, b_30_60, b_60_90,
  225. b_90_120, b_over_120,
  226. current+b_1_30+b_30_60+b_60_90+b_90_120+b_over_120
  227. AS balance
  228. FROM Q4
  229. GROUP BY partner_id, currency_id, current, b_1_30, b_30_60, b_60_90,
  230. b_90_120, b_over_120""" % (
  231. self._show_buckets_sql_q1(partners, date_end),
  232. self._show_buckets_sql_q2(
  233. self._bucket_dates['today'],
  234. self._bucket_dates['minus_30'],
  235. self._bucket_dates['minus_60'],
  236. self._bucket_dates['minus_90'],
  237. self._bucket_dates['minus_120']),
  238. self._show_buckets_sql_q3(company_id),
  239. self._show_buckets_sql_q4()))
  240. for row in self.env.cr.dictfetchall():
  241. res[row.pop('partner_id')].append(row)
  242. return res
  243. @api.multi
  244. def render_html(self, docids, data):
  245. company_id = data['company_id']
  246. partner_ids = data['partner_ids']
  247. date_end = data['date_end']
  248. today = fields.Date.today()
  249. buckets_to_display = {}
  250. lines_to_display, amount_due = {}, {}
  251. currency_to_display = {}
  252. today_display, date_end_display = {}, {}
  253. lines = self._get_account_display_lines(
  254. company_id, partner_ids, date_end)
  255. for partner_id in partner_ids:
  256. lines_to_display[partner_id], amount_due[partner_id] = {}, {}
  257. currency_to_display[partner_id] = {}
  258. today_display[partner_id] = self._format_date_to_partner_lang(
  259. today, partner_id)
  260. date_end_display[partner_id] = self._format_date_to_partner_lang(
  261. date_end, partner_id)
  262. for line in lines[partner_id]:
  263. currency = self.env['res.currency'].browse(line['currency_id'])
  264. if currency not in lines_to_display[partner_id]:
  265. lines_to_display[partner_id][currency] = []
  266. currency_to_display[partner_id][currency] = currency
  267. amount_due[partner_id][currency] = 0.0
  268. if not line['blocked']:
  269. amount_due[partner_id][currency] += line['open_amount']
  270. line['balance'] = amount_due[partner_id][currency]
  271. line['date'] = self._format_date_to_partner_lang(
  272. line['date'], partner_id)
  273. line['date_maturity'] = self._format_date_to_partner_lang(
  274. line['date_maturity'], partner_id)
  275. lines_to_display[partner_id][currency].append(line)
  276. if data['show_aging_buckets']:
  277. buckets = self._get_account_show_buckets(
  278. company_id, partner_ids, date_end)
  279. for partner_id in partner_ids:
  280. buckets_to_display[partner_id] = {}
  281. for line in buckets[partner_id]:
  282. currency = self.env['res.currency'].browse(
  283. line['currency_id'])
  284. if currency not in buckets_to_display[partner_id]:
  285. buckets_to_display[partner_id][currency] = []
  286. buckets_to_display[partner_id][currency] = line
  287. docargs = {
  288. 'doc_ids': partner_ids,
  289. 'doc_model': 'res.partner',
  290. 'docs': self.env['res.partner'].browse(partner_ids),
  291. 'Amount_Due': amount_due,
  292. 'Lines': lines_to_display,
  293. 'Buckets': buckets_to_display,
  294. 'Currencies': currency_to_display,
  295. 'Show_Buckets': data['show_aging_buckets'],
  296. 'Filter_non_due_partners': data['filter_non_due_partners'],
  297. 'Date_end': date_end_display,
  298. 'Date': today_display,
  299. }
  300. return self.env['report'].render(
  301. 'customer_outstanding_statement.statement', values=docargs)