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.

382 lines
17 KiB

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