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.

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