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.

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