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.

386 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, account_type):
  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 avg(l.amount_currency)
  45. ELSE avg(l.debit)
  46. END as debit,
  47. CASE WHEN (l.currency_id is not null AND l.amount_currency < 0.0)
  48. THEN avg(l.amount_currency * (-1))
  49. ELSE avg(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 = '%s'
  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, account_type, 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. account_type):
  108. res = dict(map(lambda x: (x, []), partner_ids))
  109. partners = ', '.join([str(i) for i in partner_ids])
  110. date_end = datetime.strptime(
  111. date_end, DEFAULT_SERVER_DATE_FORMAT).date()
  112. # pylint: disable=E8103
  113. self.env.cr.execute("""
  114. WITH Q0 as (%s), Q1 AS (%s), Q2 AS (%s), Q3 AS (%s)
  115. SELECT partner_id, currency_id, move_id, date, date_maturity, debit,
  116. credit, amount, open_amount, name, ref, blocked
  117. FROM Q3
  118. ORDER BY date, date_maturity, move_id""" % (
  119. self._display_lines_sql_q0(date_end),
  120. self._display_lines_sql_q1(partners, date_end, account_type),
  121. self._display_lines_sql_q2(),
  122. self._display_lines_sql_q3(company_id)))
  123. for row in self.env.cr.dictfetchall():
  124. res[row.pop('partner_id')].append(row)
  125. return res
  126. def _show_buckets_sql_q0(self, date_end):
  127. return """
  128. SELECT l1.id,
  129. CASE WHEN l1.reconciled = TRUE and l1.balance > 0.0
  130. THEN max(pd.max_date)
  131. WHEN l1.reconciled = TRUE and l1.balance < 0.0
  132. THEN max(pc.max_date)
  133. ELSE null
  134. END as reconciled_date
  135. FROM account_move_line l1
  136. LEFT JOIN (SELECT pr.*
  137. FROM account_partial_reconcile pr
  138. INNER JOIN account_move_line l2
  139. ON pr.credit_move_id = l2.id
  140. WHERE l2.date <= '%s'
  141. ) as pd ON pd.debit_move_id = l1.id
  142. LEFT JOIN (SELECT pr.*
  143. FROM account_partial_reconcile pr
  144. INNER JOIN account_move_line l2
  145. ON pr.debit_move_id = l2.id
  146. WHERE l2.date <= '%s'
  147. ) as pc ON pc.credit_move_id = l1.id
  148. GROUP BY l1.id
  149. """ % (date_end, date_end)
  150. def _show_buckets_sql_q1(self, partners, date_end, account_type):
  151. return """
  152. SELECT l.partner_id, l.currency_id, l.company_id, l.move_id,
  153. CASE WHEN l.balance > 0.0
  154. THEN l.balance - sum(coalesce(pd.amount, 0.0))
  155. ELSE l.balance + sum(coalesce(pc.amount, 0.0))
  156. END AS open_due,
  157. CASE WHEN l.balance > 0.0
  158. THEN l.amount_currency - sum(coalesce(pd.amount_currency, 0.0))
  159. ELSE l.amount_currency + sum(coalesce(pc.amount_currency, 0.0))
  160. END AS open_due_currency,
  161. CASE WHEN l.date_maturity is null
  162. THEN l.date
  163. ELSE l.date_maturity
  164. END as date_maturity
  165. FROM account_move_line l
  166. JOIN account_account_type at ON (at.id = l.user_type_id)
  167. JOIN account_move m ON (l.move_id = m.id)
  168. LEFT JOIN Q0 ON Q0.id = l.id
  169. LEFT JOIN (SELECT pr.*
  170. FROM account_partial_reconcile pr
  171. INNER JOIN account_move_line l2
  172. ON pr.credit_move_id = l2.id
  173. WHERE l2.date <= '%s'
  174. ) as pd ON pd.debit_move_id = l.id
  175. LEFT JOIN (SELECT pr.*
  176. FROM account_partial_reconcile pr
  177. INNER JOIN account_move_line l2
  178. ON pr.debit_move_id = l2.id
  179. WHERE l2.date <= '%s'
  180. ) as pc ON pc.credit_move_id = l.id
  181. WHERE l.partner_id IN (%s) AND at.type = '%s'
  182. AND (Q0.reconciled_date is null or
  183. Q0.reconciled_date > '%s')
  184. AND l.date <= '%s' AND not l.blocked
  185. GROUP BY l.partner_id, l.currency_id, l.date, l.date_maturity,
  186. l.amount_currency, l.balance, l.move_id,
  187. l.company_id
  188. """ % (date_end, date_end, partners, account_type, date_end, date_end)
  189. def _show_buckets_sql_q2(self, date_end, minus_30, minus_60, minus_90,
  190. minus_120):
  191. return """
  192. SELECT partner_id, currency_id, date_maturity, open_due,
  193. open_due_currency, move_id, company_id,
  194. CASE
  195. WHEN '%s' <= date_maturity AND currency_id is null
  196. THEN open_due
  197. WHEN '%s' <= date_maturity AND currency_id is not null
  198. THEN open_due_currency
  199. ELSE 0.0
  200. END as current,
  201. CASE
  202. WHEN '%s' < date_maturity AND date_maturity < '%s'
  203. AND currency_id is null THEN open_due
  204. WHEN '%s' < date_maturity AND date_maturity < '%s'
  205. AND currency_id is not null
  206. THEN open_due_currency
  207. ELSE 0.0
  208. END as b_1_30,
  209. CASE
  210. WHEN '%s' < date_maturity AND date_maturity <= '%s'
  211. AND currency_id is null THEN open_due
  212. WHEN '%s' < date_maturity AND date_maturity <= '%s'
  213. AND currency_id is not null
  214. THEN open_due_currency
  215. ELSE 0.0
  216. END as b_30_60,
  217. CASE
  218. WHEN '%s' < date_maturity AND date_maturity <= '%s'
  219. AND currency_id is null THEN open_due
  220. WHEN '%s' < date_maturity AND date_maturity <= '%s'
  221. AND currency_id is not null
  222. THEN open_due_currency
  223. ELSE 0.0
  224. END as b_60_90,
  225. CASE
  226. WHEN '%s' < date_maturity AND date_maturity <= '%s'
  227. AND currency_id is null THEN open_due
  228. WHEN '%s' < date_maturity AND date_maturity <= '%s'
  229. AND currency_id is not null
  230. THEN open_due_currency
  231. ELSE 0.0
  232. END as b_90_120,
  233. CASE
  234. WHEN date_maturity <= '%s' AND currency_id is null
  235. THEN open_due
  236. WHEN date_maturity <= '%s' AND currency_id is not null
  237. THEN open_due_currency
  238. ELSE 0.0
  239. END as b_over_120
  240. FROM Q1
  241. GROUP BY partner_id, currency_id, date_maturity, open_due,
  242. open_due_currency, move_id, company_id
  243. """ % (date_end, date_end, minus_30, date_end, minus_30, date_end,
  244. minus_60, minus_30, minus_60, minus_30, minus_90, minus_60,
  245. minus_90, minus_60, minus_120, minus_90, minus_120, minus_90,
  246. minus_120, minus_120)
  247. def _show_buckets_sql_q3(self, company_id):
  248. return """
  249. SELECT Q2.partner_id, current, b_1_30, b_30_60, b_60_90, b_90_120,
  250. b_over_120,
  251. COALESCE(Q2.currency_id, c.currency_id) AS currency_id
  252. FROM Q2
  253. JOIN res_company c ON (c.id = Q2.company_id)
  254. WHERE c.id = %s
  255. """ % company_id
  256. def _show_buckets_sql_q4(self):
  257. return """
  258. SELECT partner_id, currency_id, sum(current) as current,
  259. sum(b_1_30) as b_1_30,
  260. sum(b_30_60) as b_30_60,
  261. sum(b_60_90) as b_60_90,
  262. sum(b_90_120) as b_90_120,
  263. sum(b_over_120) as b_over_120
  264. FROM Q3
  265. GROUP BY partner_id, currency_id
  266. """
  267. def _get_bucket_dates(self, date_end):
  268. return {
  269. 'date_end': date_end,
  270. 'minus_30': date_end - timedelta(days=30),
  271. 'minus_60': date_end - timedelta(days=60),
  272. 'minus_90': date_end - timedelta(days=90),
  273. 'minus_120': date_end - timedelta(days=120),
  274. }
  275. def _get_account_show_buckets(self, company_id, partner_ids, date_end,
  276. account_type):
  277. res = dict(map(lambda x: (x, []), partner_ids))
  278. partners = ', '.join([str(i) for i in partner_ids])
  279. date_end = datetime.strptime(
  280. date_end, DEFAULT_SERVER_DATE_FORMAT).date()
  281. full_dates = self._get_bucket_dates(date_end)
  282. # pylint: disable=E8103
  283. self.env.cr.execute("""
  284. WITH Q0 AS (%s), Q1 AS (%s), Q2 AS (%s), Q3 AS (%s), Q4 AS (%s)
  285. SELECT partner_id, currency_id, current, b_1_30, b_30_60, b_60_90,
  286. b_90_120, b_over_120,
  287. current+b_1_30+b_30_60+b_60_90+b_90_120+b_over_120
  288. AS balance
  289. FROM Q4
  290. GROUP BY partner_id, currency_id, current, b_1_30, b_30_60, b_60_90,
  291. b_90_120, b_over_120""" % (
  292. self._show_buckets_sql_q0(date_end),
  293. self._show_buckets_sql_q1(partners, date_end, account_type),
  294. self._show_buckets_sql_q2(
  295. full_dates['date_end'],
  296. full_dates['minus_30'],
  297. full_dates['minus_60'],
  298. full_dates['minus_90'],
  299. full_dates['minus_120']),
  300. self._show_buckets_sql_q3(company_id),
  301. self._show_buckets_sql_q4()))
  302. for row in self.env.cr.dictfetchall():
  303. res[row.pop('partner_id')].append(row)
  304. return res
  305. @api.multi
  306. def get_report_values(self, docids, data):
  307. company_id = data['company_id']
  308. partner_ids = data['partner_ids']
  309. date_end = data['date_end']
  310. account_type = data['account_type']
  311. today = fields.Date.today()
  312. buckets_to_display = {}
  313. lines_to_display, amount_due = {}, {}
  314. currency_to_display = {}
  315. today_display, date_end_display = {}, {}
  316. lines = self._get_account_display_lines(
  317. company_id, partner_ids, date_end, account_type)
  318. for partner_id in partner_ids:
  319. lines_to_display[partner_id], amount_due[partner_id] = {}, {}
  320. currency_to_display[partner_id] = {}
  321. today_display[partner_id] = self._format_date_to_partner_lang(
  322. today, partner_id)
  323. date_end_display[partner_id] = self._format_date_to_partner_lang(
  324. date_end, partner_id)
  325. for line in lines[partner_id]:
  326. currency = self.env['res.currency'].browse(line['currency_id'])
  327. if currency not in lines_to_display[partner_id]:
  328. lines_to_display[partner_id][currency] = []
  329. currency_to_display[partner_id][currency] = currency
  330. amount_due[partner_id][currency] = 0.0
  331. if not line['blocked']:
  332. amount_due[partner_id][currency] += line['open_amount']
  333. line['balance'] = amount_due[partner_id][currency]
  334. line['date'] = self._format_date_to_partner_lang(
  335. line['date'], partner_id)
  336. line['date_maturity'] = self._format_date_to_partner_lang(
  337. line['date_maturity'], partner_id)
  338. lines_to_display[partner_id][currency].append(line)
  339. if data['show_aging_buckets']:
  340. buckets = self._get_account_show_buckets(
  341. company_id, partner_ids, date_end, account_type)
  342. for partner_id in partner_ids:
  343. buckets_to_display[partner_id] = {}
  344. for line in buckets[partner_id]:
  345. currency = self.env['res.currency'].browse(
  346. line['currency_id'])
  347. if currency not in buckets_to_display[partner_id]:
  348. buckets_to_display[partner_id][currency] = []
  349. buckets_to_display[partner_id][currency] = line
  350. return {
  351. 'doc_ids': partner_ids,
  352. 'doc_model': 'res.partner',
  353. 'docs': self.env['res.partner'].browse(partner_ids),
  354. 'Amount_Due': amount_due,
  355. 'Lines': lines_to_display,
  356. 'Buckets': buckets_to_display,
  357. 'Currencies': currency_to_display,
  358. 'Show_Buckets': data['show_aging_buckets'],
  359. 'Filter_non_due_partners': data['filter_non_due_partners'],
  360. 'Date_end': date_end_display,
  361. 'Date': today_display,
  362. 'account_type': account_type,
  363. }