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.

375 lines
17 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 avg(l.amount_currency)
  22. ELSE avg(l.debit)
  23. END as debit,
  24. CASE WHEN (l.currency_id is not null AND l.amount_currency < 0.0)
  25. THEN avg(l.amount_currency * (-1))
  26. ELSE avg(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.*, Q0c.max_date
  44. FROM account_partial_reconcile pr
  45. INNER JOIN account_move_line l2
  46. ON pr.credit_move_id = l2.id
  47. LEFT JOIN (%s) as Q0c ON Q0c.id = pr.id
  48. WHERE l2.date <= '%s'
  49. ) as pd ON pd.debit_move_id = l.id
  50. LEFT JOIN (SELECT pr.*, Q0c.max_date
  51. FROM account_partial_reconcile pr
  52. INNER JOIN account_move_line l2
  53. ON pr.debit_move_id = l2.id
  54. LEFT JOIN (%s) as Q0c ON Q0c.id = pr.id
  55. WHERE l2.date <= '%s'
  56. ) as pc ON pc.credit_move_id = l.id
  57. WHERE l.partner_id IN (%s) AND at.type = 'receivable'
  58. AND (
  59. (pd.id IS NOT NULL AND
  60. pd.max_date <= '%s') OR
  61. (pc.id IS NOT NULL AND
  62. pc.max_date <= '%s') OR
  63. (pd.id IS NULL AND pc.id IS NULL)
  64. ) AND l.date <= '%s'
  65. GROUP BY l.partner_id, m.name, l.date, l.date_maturity, l.name,
  66. l.ref, l.blocked, l.currency_id,
  67. l.balance, l.amount_currency, l.company_id
  68. """ % (self._get_reconcile_date(), date_end,
  69. self._get_reconcile_date(), date_end, partners,
  70. date_end, date_end, date_end)
  71. def _display_lines_sql_q2(self):
  72. return """
  73. SELECT partner_id, currency_id, move_id, date, date_maturity,
  74. debit, credit, name, ref, blocked, company_id,
  75. CASE WHEN currency_id is not null
  76. THEN open_amount_currency
  77. ELSE open_amount
  78. END as open_amount
  79. FROM Q1
  80. """
  81. def _display_lines_sql_q3(self, company_id):
  82. return """
  83. SELECT Q2.partner_id, move_id, date, date_maturity, Q2.name, ref,
  84. debit, credit, debit-credit AS amount, blocked,
  85. COALESCE(Q2.currency_id, c.currency_id) AS currency_id, open_amount
  86. FROM Q2
  87. JOIN res_company c ON (c.id = Q2.company_id)
  88. WHERE c.id = %s
  89. """ % company_id
  90. def _get_account_display_lines(self, company_id, partner_ids, date_end):
  91. res = dict(map(lambda x: (x, []), partner_ids))
  92. partners = ', '.join([str(i) for i in partner_ids])
  93. date_end = datetime.strptime(
  94. date_end, DEFAULT_SERVER_DATE_FORMAT).date()
  95. # pylint: disable=E8103
  96. self.env.cr.execute("""
  97. WITH Q1 AS (%s), Q2 AS (%s), Q3 AS (%s)
  98. SELECT partner_id, currency_id, move_id, date, date_maturity, debit,
  99. credit, amount, open_amount, name, ref, blocked
  100. FROM Q3
  101. ORDER BY date, date_maturity, move_id""" % (
  102. self._display_lines_sql_q1(partners, date_end),
  103. self._display_lines_sql_q2(),
  104. self._display_lines_sql_q3(company_id)))
  105. for row in self.env.cr.dictfetchall():
  106. res[row.pop('partner_id')].append(row)
  107. return res
  108. def _get_credit_date(self):
  109. return """
  110. SELECT apr.id, aml.date as credit_date
  111. FROM account_partial_reconcile apr
  112. LEFT JOIN account_move_line aml
  113. ON aml.id = apr.credit_move_id
  114. """
  115. def _get_debit_date(self):
  116. return """
  117. SELECT apr.id, aml.date as debit_date
  118. FROM account_partial_reconcile apr
  119. LEFT JOIN account_move_line aml
  120. ON aml.id = apr.debit_move_id
  121. """
  122. def _get_reconcile_date(self):
  123. return """
  124. SELECT pr2.id,
  125. CASE WHEN Q0a.credit_date > Q0b.debit_date
  126. THEN Q0a.credit_date
  127. ELSE Q0b.debit_date
  128. END AS max_date
  129. FROM account_partial_reconcile pr2
  130. LEFT JOIN (%s) as Q0a ON Q0a.id = pr2.id
  131. LEFT JOIN (%s) as Q0b ON Q0b.id = pr2.id
  132. GROUP BY pr2.id, Q0a.credit_date, Q0b.debit_date
  133. """ % (self._get_credit_date(), self._get_debit_date())
  134. def _show_buckets_sql_q1(self, partners, date_end):
  135. return """
  136. SELECT l.partner_id, l.currency_id, l.company_id, l.move_id,
  137. CASE WHEN l.balance > 0.0
  138. THEN l.balance - sum(coalesce(pd.amount, 0.0))
  139. ELSE l.balance + sum(coalesce(pc.amount, 0.0))
  140. END AS open_due,
  141. CASE WHEN l.balance > 0.0
  142. THEN l.amount_currency - sum(coalesce(pd.amount_currency, 0.0))
  143. ELSE l.amount_currency + sum(coalesce(pc.amount_currency, 0.0))
  144. END AS open_due_currency,
  145. CASE WHEN l.date_maturity is null
  146. THEN l.date
  147. ELSE l.date_maturity
  148. END as date_maturity
  149. FROM account_move_line l
  150. JOIN account_account_type at ON (at.id = l.user_type_id)
  151. JOIN account_move m ON (l.move_id = m.id)
  152. LEFT JOIN (SELECT pr.*, Q0c.max_date
  153. FROM account_partial_reconcile pr
  154. INNER JOIN account_move_line l2
  155. ON pr.credit_move_id = l2.id
  156. LEFT JOIN (%s) as Q0c ON Q0c.id = pr.id
  157. WHERE l2.date <= '%s'
  158. ) as pd ON pd.debit_move_id = l.id
  159. LEFT JOIN (SELECT pr.*, Q0c.max_date
  160. FROM account_partial_reconcile pr
  161. INNER JOIN account_move_line l2
  162. ON pr.debit_move_id = l2.id
  163. LEFT JOIN (%s) as Q0c ON Q0c.id = pr.id
  164. WHERE l2.date <= '%s'
  165. ) as pc ON pc.credit_move_id = l.id
  166. WHERE l.partner_id IN (%s) AND at.type = 'receivable'
  167. AND (
  168. (pd.id IS NOT NULL AND
  169. pd.max_date <= '%s') OR
  170. (pc.id IS NOT NULL AND
  171. pc.max_date <= '%s') OR
  172. (pd.id IS NULL AND pc.id IS NULL)
  173. ) AND l.date <= '%s' AND not l.blocked
  174. GROUP BY l.partner_id, l.currency_id, l.date, l.date_maturity,
  175. l.amount_currency, l.balance, l.move_id,
  176. l.company_id, l.id
  177. """ % (self._get_reconcile_date(), date_end,
  178. self._get_reconcile_date(), date_end, partners,
  179. date_end, date_end, date_end)
  180. def _show_buckets_sql_q2(self, date_end, minus_30, minus_60, minus_90,
  181. minus_120):
  182. return """
  183. SELECT partner_id, currency_id, date_maturity, open_due,
  184. open_due_currency, move_id, company_id,
  185. CASE
  186. WHEN '%s' <= date_maturity AND currency_id is null
  187. THEN open_due
  188. WHEN '%s' <= date_maturity AND currency_id is not null
  189. THEN open_due_currency
  190. ELSE 0.0
  191. END as current,
  192. CASE
  193. WHEN '%s' < date_maturity AND date_maturity < '%s'
  194. AND currency_id is null THEN open_due
  195. WHEN '%s' < date_maturity AND date_maturity < '%s'
  196. AND currency_id is not null
  197. THEN open_due_currency
  198. ELSE 0.0
  199. END as b_1_30,
  200. CASE
  201. WHEN '%s' < date_maturity AND date_maturity <= '%s'
  202. AND currency_id is null THEN open_due
  203. WHEN '%s' < date_maturity AND date_maturity <= '%s'
  204. AND currency_id is not null
  205. THEN open_due_currency
  206. ELSE 0.0
  207. END as b_30_60,
  208. CASE
  209. WHEN '%s' < date_maturity AND date_maturity <= '%s'
  210. AND currency_id is null THEN open_due
  211. WHEN '%s' < date_maturity AND date_maturity <= '%s'
  212. AND currency_id is not null
  213. THEN open_due_currency
  214. ELSE 0.0
  215. END as b_60_90,
  216. CASE
  217. WHEN '%s' < date_maturity AND date_maturity <= '%s'
  218. AND currency_id is null THEN open_due
  219. WHEN '%s' < date_maturity AND date_maturity <= '%s'
  220. AND currency_id is not null
  221. THEN open_due_currency
  222. ELSE 0.0
  223. END as b_90_120,
  224. CASE
  225. WHEN date_maturity <= '%s' AND currency_id is null
  226. THEN open_due
  227. WHEN date_maturity <= '%s' AND currency_id is not null
  228. THEN open_due_currency
  229. ELSE 0.0
  230. END as b_over_120
  231. FROM Q1
  232. GROUP BY partner_id, currency_id, date_maturity, open_due,
  233. open_due_currency, move_id, company_id
  234. """ % (date_end, date_end, minus_30, date_end, minus_30, date_end,
  235. minus_60, minus_30, minus_60, minus_30, minus_90, minus_60,
  236. minus_90, minus_60, minus_120, minus_90, minus_120, minus_90,
  237. minus_120, minus_120)
  238. def _show_buckets_sql_q3(self, company_id):
  239. return """
  240. SELECT Q2.partner_id, current, b_1_30, b_30_60, b_60_90, b_90_120,
  241. b_over_120,
  242. COALESCE(Q2.currency_id, c.currency_id) AS currency_id
  243. FROM Q2
  244. JOIN res_company c ON (c.id = Q2.company_id)
  245. WHERE c.id = %s
  246. """ % company_id
  247. def _show_buckets_sql_q4(self):
  248. return """
  249. SELECT partner_id, currency_id, sum(current) as current,
  250. sum(b_1_30) as b_1_30,
  251. sum(b_30_60) as b_30_60,
  252. sum(b_60_90) as b_60_90,
  253. sum(b_90_120) as b_90_120,
  254. sum(b_over_120) as b_over_120
  255. FROM Q3
  256. GROUP BY partner_id, currency_id
  257. """
  258. def _get_bucket_dates(self, date_end):
  259. return {
  260. 'date_end': date_end,
  261. 'minus_30': date_end - timedelta(days=30),
  262. 'minus_60': date_end - timedelta(days=60),
  263. 'minus_90': date_end - timedelta(days=90),
  264. 'minus_120': date_end - timedelta(days=120),
  265. }
  266. def _get_account_show_buckets(self, company_id, partner_ids, date_end):
  267. res = dict(map(lambda x: (x, []), partner_ids))
  268. partners = ', '.join([str(i) for i in partner_ids])
  269. date_end = datetime.strptime(
  270. date_end, DEFAULT_SERVER_DATE_FORMAT).date()
  271. full_dates = self._get_bucket_dates(date_end)
  272. # pylint: disable=E8103
  273. self.env.cr.execute("""
  274. WITH Q1 AS (%s), Q2 AS (%s), Q3 AS (%s), Q4 AS (%s)
  275. SELECT partner_id, currency_id, current, b_1_30, b_30_60, b_60_90,
  276. b_90_120, b_over_120,
  277. current+b_1_30+b_30_60+b_60_90+b_90_120+b_over_120 AS balance
  278. FROM Q4
  279. GROUP BY partner_id, currency_id, current, b_1_30, b_30_60, b_60_90,
  280. b_90_120, b_over_120""" % (
  281. self._show_buckets_sql_q1(partners, date_end),
  282. self._show_buckets_sql_q2(
  283. full_dates['date_end'],
  284. full_dates['minus_30'],
  285. full_dates['minus_60'],
  286. full_dates['minus_90'],
  287. full_dates['minus_120']),
  288. self._show_buckets_sql_q3(company_id),
  289. self._show_buckets_sql_q4()))
  290. for row in self.env.cr.dictfetchall():
  291. res[row.pop('partner_id')].append(row)
  292. return res
  293. @api.multi
  294. def render_html(self, docids, data):
  295. company_id = data['company_id']
  296. partner_ids = data['partner_ids']
  297. date_end = data['date_end']
  298. today = fields.Date.today()
  299. buckets_to_display = {}
  300. lines_to_display, amount_due = {}, {}
  301. currency_to_display = {}
  302. today_display, date_end_display = {}, {}
  303. lines = self._get_account_display_lines(
  304. company_id, partner_ids, date_end)
  305. for partner_id in partner_ids:
  306. lines_to_display[partner_id], amount_due[partner_id] = {}, {}
  307. currency_to_display[partner_id] = {}
  308. today_display[partner_id] = self._format_date_to_partner_lang(
  309. today, partner_id)
  310. date_end_display[partner_id] = self._format_date_to_partner_lang(
  311. date_end, partner_id)
  312. for line in lines[partner_id]:
  313. currency = self.env['res.currency'].browse(line['currency_id'])
  314. if currency not in lines_to_display[partner_id]:
  315. lines_to_display[partner_id][currency] = []
  316. currency_to_display[partner_id][currency] = currency
  317. amount_due[partner_id][currency] = 0.0
  318. if not line['blocked']:
  319. amount_due[partner_id][currency] += line['open_amount']
  320. line['balance'] = amount_due[partner_id][currency]
  321. line['date'] = self._format_date_to_partner_lang(
  322. line['date'], partner_id)
  323. line['date_maturity'] = self._format_date_to_partner_lang(
  324. line['date_maturity'], partner_id)
  325. lines_to_display[partner_id][currency].append(line)
  326. if data['show_aging_buckets']:
  327. buckets = self._get_account_show_buckets(
  328. company_id, partner_ids, date_end)
  329. for partner_id in partner_ids:
  330. buckets_to_display[partner_id] = {}
  331. for line in buckets[partner_id]:
  332. currency = self.env['res.currency'].browse(
  333. line['currency_id'])
  334. if currency not in buckets_to_display[partner_id]:
  335. buckets_to_display[partner_id][currency] = []
  336. buckets_to_display[partner_id][currency] = line
  337. docargs = {
  338. 'doc_ids': partner_ids,
  339. 'doc_model': 'res.partner',
  340. 'docs': self.env['res.partner'].browse(partner_ids),
  341. 'Amount_Due': amount_due,
  342. 'Lines': lines_to_display,
  343. 'Buckets': buckets_to_display,
  344. 'Currencies': currency_to_display,
  345. 'Show_Buckets': data['show_aging_buckets'],
  346. 'Filter_non_due_partners': data['filter_non_due_partners'],
  347. 'Date_end': date_end_display,
  348. 'Date': today_display,
  349. }
  350. return self.env['report'].render(
  351. 'customer_outstanding_statement.statement', values=docargs)