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.

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