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.

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