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.

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