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.

458 lines
18 KiB

6 years ago
  1. # Copyright 2018 ForgeFlow, S.L. (https://www.forgeflow.com)
  2. # License AGPL-3.0 or later (https://www.gnu.org/licenses/agpl.html).
  3. from datetime import datetime, timedelta
  4. from odoo import _, api, fields, models
  5. from odoo.tools.misc import DEFAULT_SERVER_DATE_FORMAT
  6. class ReportStatementCommon(models.AbstractModel):
  7. """Abstract Report Statement for use in other models"""
  8. _name = "statement.common"
  9. _description = "Statement Reports Common"
  10. def _get_invoice_address(self, part):
  11. inv_addr_id = part.address_get(["invoice"]).get("invoice", part.id)
  12. return self.env["res.partner"].browse(inv_addr_id)
  13. def _format_date_to_partner_lang(
  14. self, date, date_format=DEFAULT_SERVER_DATE_FORMAT
  15. ):
  16. if isinstance(date, str):
  17. date = datetime.strptime(date, DEFAULT_SERVER_DATE_FORMAT)
  18. return date.strftime(date_format) if date else ""
  19. def _get_account_display_lines(
  20. self, company_id, partner_ids, date_start, date_end, account_type
  21. ):
  22. raise NotImplementedError
  23. def _get_account_initial_balance(
  24. self, company_id, partner_ids, date_start, account_type
  25. ):
  26. return {}
  27. def _show_buckets_sql_q1(self, partners, date_end, account_type):
  28. return str(
  29. self._cr.mogrify(
  30. """
  31. SELECT l.partner_id, l.currency_id, l.company_id, l.move_id,
  32. (abs(COALESCE(l.balance, 0.0)) + sum(
  33. coalesce(pr.pr_sign, 0.0) * coalesce(pr.amount, 0.0))
  34. ) * sign(COALESCE(l.balance, 0.0)) AS open_due,
  35. (abs(COALESCE(l.amount_currency, 0.0)) + sum(
  36. coalesce(pr.pr_sign, 0.0) * CASE
  37. WHEN pr.currency_id IS NOT NULL AND pr.currency_id = l.currency_id
  38. THEN coalesce(pr.amount_currency, 0.0)
  39. WHEN cur.id IS NOT NULL AND ROUND(
  40. abs(COALESCE(l.balance, 0.0)), cur.decimal_places) > 0.0
  41. THEN ROUND(coalesce(pr.amount, 0.0) *
  42. COALESCE(l.amount_currency, 0.0) / NULLIF(l.balance, 0.0),
  43. cur.decimal_places)
  44. ELSE ROUND(coalesce(pr.amount, 0.0) *
  45. COALESCE((
  46. SELECT r.rate FROM res_currency_rate r
  47. JOIN account_move_line aml
  48. ON pr.credit_move_id = aml.id
  49. WHERE r.currency_id = l.currency_id
  50. AND r.name <= aml.date
  51. AND (r.company_id IS NULL
  52. OR r.company_id = l.company_id)
  53. ORDER BY r.company_id, r.name DESC LIMIT 1), 1.0),
  54. cur.decimal_places)
  55. END)
  56. ) * sign(COALESCE(l.amount_currency, 0.0)) AS open_due_currency,
  57. CASE WHEN l.date_maturity is null
  58. THEN l.date
  59. ELSE l.date_maturity
  60. END as date_maturity
  61. FROM (
  62. SELECT l.*, CASE
  63. WHEN l.debit = 0.0 AND l.credit = 0.0 AND l.currency_id IS NOT NULL
  64. AND ROUND(COALESCE(l.amount_currency, 0.0),
  65. cur.decimal_places) > 0.0 THEN 1
  66. WHEN l.debit = 0.0 AND l.credit = 0.0 AND l.currency_id IS NOT NULL
  67. AND ROUND(COALESCE(l.amount_currency, 0.0),
  68. cur.decimal_places) < 0.0 THEN -1
  69. WHEN l.balance > 0.0 THEN 1 ELSE -1 END as sign
  70. FROM account_move_line l
  71. LEFT JOIN res_currency cur ON cur.id = l.currency_id
  72. ) l
  73. JOIN account_move m ON l.move_id = m.id
  74. LEFT JOIN res_currency cur ON cur.id = l.currency_id
  75. LEFT JOIN LATERAL (SELECT pr.*,
  76. CASE WHEN pr.credit_move_id = l.id THEN l.sign
  77. ELSE -l.sign END AS pr_sign
  78. FROM account_partial_reconcile pr
  79. WHERE pr.max_date <= %(date_end)s AND (
  80. (pr.debit_move_id = l.id) OR (pr.credit_move_id = l.id))
  81. ) as pr ON TRUE
  82. WHERE l.partner_id IN %(partners)s
  83. AND l.account_internal_type = %(account_type)s
  84. AND (
  85. (pr.id IS NOT NULL AND pr.max_date <= %(date_end)s) OR
  86. (pr.id IS NULL)
  87. ) AND l.date <= %(date_end)s AND not l.blocked
  88. AND m.state IN ('posted')
  89. GROUP BY l.partner_id, l.currency_id, l.date, l.date_maturity,
  90. l.amount_currency, l.balance, l.move_id, l.company_id, l.id
  91. """,
  92. locals(),
  93. ),
  94. "utf-8",
  95. )
  96. def _show_buckets_sql_q2(self, date_end, minus_30, minus_60, minus_90, minus_120):
  97. return str(
  98. self._cr.mogrify(
  99. """
  100. SELECT partner_id, currency_id, date_maturity, open_due,
  101. open_due_currency, move_id, company_id,
  102. CASE
  103. WHEN %(date_end)s <= date_maturity AND currency_id is null
  104. THEN open_due
  105. WHEN %(date_end)s <= date_maturity AND currency_id is not null
  106. THEN open_due_currency
  107. ELSE 0.0
  108. END as current,
  109. CASE
  110. WHEN %(minus_30)s < date_maturity
  111. AND date_maturity < %(date_end)s
  112. AND currency_id is null
  113. THEN open_due
  114. WHEN %(minus_30)s < date_maturity
  115. AND date_maturity < %(date_end)s
  116. AND currency_id is not null
  117. THEN open_due_currency
  118. ELSE 0.0
  119. END as b_1_30,
  120. CASE
  121. WHEN %(minus_60)s < date_maturity
  122. AND date_maturity <= %(minus_30)s
  123. AND currency_id is null
  124. THEN open_due
  125. WHEN %(minus_60)s < date_maturity
  126. AND date_maturity <= %(minus_30)s
  127. AND currency_id is not null
  128. THEN open_due_currency
  129. ELSE 0.0
  130. END as b_30_60,
  131. CASE
  132. WHEN %(minus_90)s < date_maturity
  133. AND date_maturity <= %(minus_60)s
  134. AND currency_id is null
  135. THEN open_due
  136. WHEN %(minus_90)s < date_maturity
  137. AND date_maturity <= %(minus_60)s
  138. AND currency_id is not null
  139. THEN open_due_currency
  140. ELSE 0.0
  141. END as b_60_90,
  142. CASE
  143. WHEN %(minus_120)s < date_maturity
  144. AND date_maturity <= %(minus_90)s
  145. AND currency_id is null
  146. THEN open_due
  147. WHEN %(minus_120)s < date_maturity
  148. AND date_maturity <= %(minus_90)s
  149. AND currency_id is not null
  150. THEN open_due_currency
  151. ELSE 0.0
  152. END as b_90_120,
  153. CASE
  154. WHEN date_maturity <= %(minus_120)s
  155. AND currency_id is null
  156. THEN open_due
  157. WHEN date_maturity <= %(minus_120)s
  158. AND currency_id is not null
  159. THEN open_due_currency
  160. ELSE 0.0
  161. END as b_over_120
  162. FROM Q1
  163. GROUP BY partner_id, currency_id, date_maturity, open_due,
  164. open_due_currency, move_id, company_id
  165. """,
  166. locals(),
  167. ),
  168. "utf-8",
  169. )
  170. def _show_buckets_sql_q3(self, company_id):
  171. return str(
  172. self._cr.mogrify(
  173. """
  174. SELECT Q2.partner_id, current, b_1_30, b_30_60, b_60_90, b_90_120,
  175. b_over_120,
  176. COALESCE(Q2.currency_id, c.currency_id) AS currency_id
  177. FROM Q2
  178. JOIN res_company c ON (c.id = Q2.company_id)
  179. WHERE c.id = %(company_id)s
  180. """,
  181. locals(),
  182. ),
  183. "utf-8",
  184. )
  185. def _show_buckets_sql_q4(self):
  186. return """
  187. SELECT partner_id, currency_id, sum(current) as current,
  188. sum(b_1_30) as b_1_30, sum(b_30_60) as b_30_60,
  189. sum(b_60_90) as b_60_90, sum(b_90_120) as b_90_120,
  190. sum(b_over_120) as b_over_120
  191. FROM Q3
  192. GROUP BY partner_id, currency_id
  193. """
  194. def _get_bucket_dates(self, date_end, aging_type):
  195. return getattr(
  196. self, "_get_bucket_dates_%s" % aging_type, self._get_bucket_dates_days
  197. )(date_end)
  198. def _get_bucket_dates_days(self, date_end):
  199. return {
  200. "date_end": date_end,
  201. "minus_30": date_end - timedelta(days=30),
  202. "minus_60": date_end - timedelta(days=60),
  203. "minus_90": date_end - timedelta(days=90),
  204. "minus_120": date_end - timedelta(days=120),
  205. }
  206. def _get_bucket_dates_months(self, date_end):
  207. res = {}
  208. d = date_end
  209. for k in ("date_end", "minus_30", "minus_60", "minus_90", "minus_120"):
  210. res[k] = d
  211. d = d.replace(day=1) - timedelta(days=1)
  212. return res
  213. def _get_account_show_buckets(
  214. self, company_id, partner_ids, date_end, account_type, aging_type
  215. ):
  216. buckets = dict(map(lambda x: (x, []), partner_ids))
  217. partners = tuple(partner_ids)
  218. full_dates = self._get_bucket_dates(date_end, aging_type)
  219. # pylint: disable=E8103
  220. # All input queries are properly escaped - false positive
  221. self.env.cr.execute(
  222. """
  223. WITH Q1 AS (%s),
  224. Q2 AS (%s),
  225. Q3 AS (%s),
  226. Q4 AS (%s)
  227. SELECT partner_id, currency_id, current, b_1_30, b_30_60, b_60_90,
  228. b_90_120, b_over_120,
  229. current+b_1_30+b_30_60+b_60_90+b_90_120+b_over_120
  230. AS balance
  231. FROM Q4
  232. GROUP BY partner_id, currency_id, current, b_1_30, b_30_60,
  233. b_60_90, b_90_120, b_over_120"""
  234. % (
  235. self._show_buckets_sql_q1(partners, date_end, account_type),
  236. self._show_buckets_sql_q2(
  237. full_dates["date_end"],
  238. full_dates["minus_30"],
  239. full_dates["minus_60"],
  240. full_dates["minus_90"],
  241. full_dates["minus_120"],
  242. ),
  243. self._show_buckets_sql_q3(company_id),
  244. self._show_buckets_sql_q4(),
  245. )
  246. )
  247. for row in self.env.cr.dictfetchall():
  248. buckets[row.pop("partner_id")].append(row)
  249. return buckets
  250. def _get_bucket_labels(self, date_end, aging_type):
  251. return getattr(
  252. self, "_get_bucket_labels_%s" % aging_type, self._get_bucket_dates_days
  253. )(date_end)
  254. def _get_bucket_labels_days(self, date_end):
  255. return [
  256. _("Current"),
  257. _("1 - 30 Days"),
  258. _("31 - 60 Days"),
  259. _("61 - 90 Days"),
  260. _("91 - 120 Days"),
  261. _("121 Days +"),
  262. _("Total"),
  263. ]
  264. def _get_bucket_labels_months(self, date_end):
  265. return [
  266. _("Current"),
  267. _("1 Month"),
  268. _("2 Months"),
  269. _("3 Months"),
  270. _("4 Months"),
  271. _("Older"),
  272. _("Total"),
  273. ]
  274. def _get_line_currency_defaults(self, currency_id, currencies, balance_forward):
  275. if currency_id not in currencies:
  276. # This will only happen if currency is inactive
  277. currencies[currency_id] = self.env["res.currency"].browse(currency_id)
  278. return (
  279. {
  280. "lines": [],
  281. "buckets": [],
  282. "balance_forward": balance_forward,
  283. "amount_due": balance_forward,
  284. },
  285. currencies,
  286. )
  287. @api.model
  288. # flake8: noqa: C901
  289. def _get_report_values(self, docids, data=None):
  290. """
  291. @return: returns a dict of parameters to pass to qweb report.
  292. the most important pair is {'data': res} which contains all
  293. the data for each partner. It is structured like:
  294. {partner_id: {
  295. 'start': date string,
  296. 'end': date_string,
  297. 'today': date_string
  298. 'currencies': {
  299. currency_id: {
  300. 'lines': [{'date': date string, ...}, ...],
  301. 'balance_forward': float,
  302. 'amount_due': float,
  303. 'buckets': {
  304. 'p1': float, 'p2': ...
  305. }
  306. }
  307. }
  308. }
  309. """
  310. company_id = data["company_id"]
  311. partner_ids = data["partner_ids"]
  312. date_start = data.get("date_start")
  313. if date_start and isinstance(date_start, str):
  314. date_start = datetime.strptime(
  315. date_start, DEFAULT_SERVER_DATE_FORMAT
  316. ).date()
  317. date_end = data["date_end"]
  318. if isinstance(date_end, str):
  319. date_end = datetime.strptime(date_end, DEFAULT_SERVER_DATE_FORMAT).date()
  320. account_type = data["account_type"]
  321. aging_type = data["aging_type"]
  322. today = fields.Date.today()
  323. amount_field = data.get("amount_field", "amount")
  324. # There should be relatively few of these, so to speed performance
  325. # we cache them - default needed if partner lang not set
  326. self._cr.execute(
  327. """
  328. SELECT p.id, l.date_format
  329. FROM res_partner p LEFT JOIN res_lang l ON p.lang=l.code
  330. WHERE p.id IN %(partner_ids)s
  331. """,
  332. {"partner_ids": tuple(partner_ids)},
  333. )
  334. date_formats = {r[0]: r[1] for r in self._cr.fetchall()}
  335. default_fmt = self.env["res.lang"]._lang_get(self.env.user.lang).date_format
  336. currencies = {x.id: x for x in self.env["res.currency"].search([])}
  337. res = {}
  338. # get base data
  339. lines = self._get_account_display_lines(
  340. company_id, partner_ids, date_start, date_end, account_type
  341. )
  342. balances_forward = self._get_account_initial_balance(
  343. company_id, partner_ids, date_start, account_type
  344. )
  345. if data["show_aging_buckets"]:
  346. buckets = self._get_account_show_buckets(
  347. company_id, partner_ids, date_end, account_type, aging_type
  348. )
  349. bucket_labels = self._get_bucket_labels(date_end, aging_type)
  350. else:
  351. bucket_labels = {}
  352. # organise and format for report
  353. format_date = self._format_date_to_partner_lang
  354. partners_to_remove = set()
  355. for partner_id in partner_ids:
  356. res[partner_id] = {
  357. "today": format_date(today, date_formats.get(partner_id, default_fmt)),
  358. "start": format_date(
  359. date_start, date_formats.get(partner_id, default_fmt)
  360. ),
  361. "end": format_date(date_end, date_formats.get(partner_id, default_fmt)),
  362. "currencies": {},
  363. }
  364. currency_dict = res[partner_id]["currencies"]
  365. for line in balances_forward.get(partner_id, []):
  366. (
  367. currency_dict[line["currency_id"]],
  368. currencies,
  369. ) = self._get_line_currency_defaults(
  370. line["currency_id"], currencies, line["balance"]
  371. )
  372. for line in lines[partner_id]:
  373. if line["currency_id"] not in currency_dict:
  374. (
  375. currency_dict[line["currency_id"]],
  376. currencies,
  377. ) = self._get_line_currency_defaults(
  378. line["currency_id"], currencies, 0.0
  379. )
  380. line_currency = currency_dict[line["currency_id"]]
  381. if not line["blocked"]:
  382. line_currency["amount_due"] += line[amount_field]
  383. line["balance"] = line_currency["amount_due"]
  384. line["date"] = format_date(
  385. line["date"], date_formats.get(partner_id, default_fmt)
  386. )
  387. line["date_maturity"] = format_date(
  388. line["date_maturity"], date_formats.get(partner_id, default_fmt)
  389. )
  390. line_currency["lines"].append(line)
  391. if data["show_aging_buckets"]:
  392. for line in buckets[partner_id]:
  393. if line["currency_id"] not in currency_dict:
  394. (
  395. currency_dict[line["currency_id"]],
  396. currencies,
  397. ) = self._get_line_currency_defaults(
  398. line["currency_id"], currencies, 0.0
  399. )
  400. line_currency = currency_dict[line["currency_id"]]
  401. line_currency["buckets"] = line
  402. if len(partner_ids) > 1:
  403. values = currency_dict.values()
  404. if not any([v["lines"] or v["balance_forward"] for v in values]):
  405. if data["filter_non_due_partners"]:
  406. partners_to_remove.add(partner_id)
  407. continue
  408. else:
  409. res[partner_id]["no_entries"] = True
  410. if data["filter_negative_balances"]:
  411. if not all([v["amount_due"] >= 0.0 for v in values]):
  412. partners_to_remove.add(partner_id)
  413. for partner in partners_to_remove:
  414. del res[partner]
  415. partner_ids.remove(partner)
  416. return {
  417. "doc_ids": partner_ids,
  418. "doc_model": "res.partner",
  419. "docs": self.env["res.partner"].browse(partner_ids),
  420. "data": res,
  421. "company": self.env["res.company"].browse(company_id),
  422. "Currencies": currencies,
  423. "account_type": account_type,
  424. "bucket_labels": bucket_labels,
  425. "get_inv_addr": self._get_invoice_address,
  426. }