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.

607 lines
18 KiB

  1. # -*- coding: utf-8 -*-
  2. # © 2016 Julien Coux (Camptocamp)
  3. # License AGPL-3.0 or later (http://www.gnu.org/licenses/agpl.html).
  4. from openerp import models, fields, api
  5. class AgedPartnerBalanceReport(models.TransientModel):
  6. """ Here, we just define class fields.
  7. For methods, go more bottom at this file.
  8. The class hierarchy is :
  9. * AgedPartnerBalanceReport
  10. ** AgedPartnerBalanceReportAccount
  11. *** AgedPartnerBalanceReportPartner
  12. **** AgedPartnerBalanceReportLine
  13. **** AgedPartnerBalanceReportMoveLine
  14. If "show_move_line_details" is selected
  15. """
  16. _name = 'report_aged_partner_balance_qweb'
  17. # Filters fields, used for data computation
  18. date_at = fields.Date()
  19. only_posted_moves = fields.Boolean()
  20. company_id = fields.Many2one(comodel_name='res.company')
  21. filter_account_ids = fields.Many2many(comodel_name='account.account')
  22. filter_partner_ids = fields.Many2many(comodel_name='res.partner')
  23. show_move_line_details = fields.Boolean()
  24. # Open Items Report Data fields, used as base for compute the data reports
  25. open_items_id = fields.Many2one(comodel_name='report_open_items_qweb')
  26. # Data fields, used to browse report data
  27. account_ids = fields.One2many(
  28. comodel_name='report_aged_partner_balance_qweb_account',
  29. inverse_name='report_id'
  30. )
  31. class AgedPartnerBalanceReportAccount(models.TransientModel):
  32. _name = 'report_aged_partner_balance_qweb_account'
  33. _order = 'code ASC'
  34. report_id = fields.Many2one(
  35. comodel_name='report_aged_partner_balance_qweb',
  36. ondelete='cascade',
  37. index=True
  38. )
  39. # Data fields, used to keep link with real object
  40. account_id = fields.Many2one(
  41. 'account.account',
  42. index=True
  43. )
  44. # Data fields, used for report display
  45. code = fields.Char()
  46. name = fields.Char()
  47. cumul_amount_residual = fields.Float(digits=(16, 2))
  48. cumul_current = fields.Float(digits=(16, 2))
  49. cumul_age_30_days = fields.Float(digits=(16, 2))
  50. cumul_age_60_days = fields.Float(digits=(16, 2))
  51. cumul_age_90_days = fields.Float(digits=(16, 2))
  52. cumul_age_120_days = fields.Float(digits=(16, 2))
  53. cumul_older = fields.Float(digits=(16, 2))
  54. percent_current = fields.Float(digits=(16, 2))
  55. percent_age_30_days = fields.Float(digits=(16, 2))
  56. percent_age_60_days = fields.Float(digits=(16, 2))
  57. percent_age_90_days = fields.Float(digits=(16, 2))
  58. percent_age_120_days = fields.Float(digits=(16, 2))
  59. percent_older = fields.Float(digits=(16, 2))
  60. # Data fields, used to browse report data
  61. partner_ids = fields.One2many(
  62. comodel_name='report_aged_partner_balance_qweb_partner',
  63. inverse_name='report_account_id'
  64. )
  65. class AgedPartnerBalanceReportPartner(models.TransientModel):
  66. _name = 'report_aged_partner_balance_qweb_partner'
  67. report_account_id = fields.Many2one(
  68. comodel_name='report_aged_partner_balance_qweb_account',
  69. ondelete='cascade',
  70. index=True
  71. )
  72. # Data fields, used to keep link with real object
  73. partner_id = fields.Many2one(
  74. 'res.partner',
  75. index=True
  76. )
  77. # Data fields, used for report display
  78. name = fields.Char()
  79. # Data fields, used to browse report data
  80. move_line_ids = fields.One2many(
  81. comodel_name='report_aged_partner_balance_qweb_move_line',
  82. inverse_name='report_partner_id'
  83. )
  84. line_ids = fields.One2many(
  85. comodel_name='report_aged_partner_balance_qweb_line',
  86. inverse_name='report_partner_id'
  87. )
  88. @api.model
  89. def _generate_order_by(self, order_spec, query):
  90. """Custom order to display "No partner allocated" at last position."""
  91. return """
  92. ORDER BY
  93. CASE
  94. WHEN
  95. "report_aged_partner_balance_qweb_partner"."partner_id" IS NOT NULL
  96. THEN 0
  97. ELSE 1
  98. END,
  99. "report_aged_partner_balance_qweb_partner"."name"
  100. """
  101. class AgedPartnerBalanceReportLine(models.TransientModel):
  102. _name = 'report_aged_partner_balance_qweb_line'
  103. report_partner_id = fields.Many2one(
  104. comodel_name='report_aged_partner_balance_qweb_partner',
  105. ondelete='cascade',
  106. index=True
  107. )
  108. # Data fields, used for report display
  109. partner = fields.Char()
  110. amount_residual = fields.Float(digits=(16, 2))
  111. current = fields.Float(digits=(16, 2))
  112. age_30_days = fields.Float(digits=(16, 2))
  113. age_60_days = fields.Float(digits=(16, 2))
  114. age_90_days = fields.Float(digits=(16, 2))
  115. age_120_days = fields.Float(digits=(16, 2))
  116. older = fields.Float(digits=(16, 2))
  117. class AgedPartnerBalanceReportMoveLine(models.TransientModel):
  118. _name = 'report_aged_partner_balance_qweb_move_line'
  119. report_partner_id = fields.Many2one(
  120. comodel_name='report_aged_partner_balance_qweb_partner',
  121. ondelete='cascade',
  122. index=True
  123. )
  124. # Data fields, used to keep link with real object
  125. move_line_id = fields.Many2one('account.move.line')
  126. # Data fields, used for report display
  127. date = fields.Date()
  128. date_due = fields.Date()
  129. entry = fields.Char()
  130. journal = fields.Char()
  131. account = fields.Char()
  132. partner = fields.Char()
  133. label = fields.Char()
  134. amount_residual = fields.Float(digits=(16, 2))
  135. current = fields.Float(digits=(16, 2))
  136. age_30_days = fields.Float(digits=(16, 2))
  137. age_60_days = fields.Float(digits=(16, 2))
  138. age_90_days = fields.Float(digits=(16, 2))
  139. age_120_days = fields.Float(digits=(16, 2))
  140. older = fields.Float(digits=(16, 2))
  141. class AgedPartnerBalanceReportCompute(models.TransientModel):
  142. """ Here, we just define methods.
  143. For class fields, go more top at this file.
  144. """
  145. _inherit = 'report_aged_partner_balance_qweb'
  146. @api.multi
  147. def print_report(self, xlsx_report=False):
  148. self.ensure_one()
  149. self.compute_data_for_report()
  150. if xlsx_report:
  151. report_name = 'account_financial_report_qweb.' \
  152. 'report_aged_partner_balance_xlsx'
  153. else:
  154. report_name = 'account_financial_report_qweb.' \
  155. 'report_aged_partner_balance_qweb'
  156. return self.env['report'].get_action(records=self,
  157. report_name=report_name)
  158. def _prepare_report_open_items(self):
  159. self.ensure_one()
  160. return {
  161. 'date_at': self.date_at,
  162. 'only_posted_moves': self.only_posted_moves,
  163. 'company_id': self.company_id.id,
  164. 'filter_account_ids': [(6, 0, self.filter_account_ids.ids)],
  165. 'filter_partner_ids': [(6, 0, self.filter_partner_ids.ids)],
  166. }
  167. @api.multi
  168. def compute_data_for_report(self):
  169. self.ensure_one()
  170. # Compute Open Items Report Data.
  171. # The data of Aged Partner Balance Report
  172. # are based on Open Items Report data.
  173. model = self.env['report_open_items_qweb']
  174. self.open_items_id = model.create(self._prepare_report_open_items())
  175. self.open_items_id.compute_data_for_report()
  176. # Compute report data
  177. self._inject_account_values()
  178. self._inject_partner_values()
  179. self._inject_line_values()
  180. self._inject_line_values(only_empty_partner_line=True)
  181. if self.show_move_line_details:
  182. self._inject_move_line_values()
  183. self._inject_move_line_values(only_empty_partner_line=True)
  184. self._compute_accounts_cumul()
  185. # Refresh cache because all data are computed with SQL requests
  186. self.refresh()
  187. def _inject_account_values(self):
  188. """Inject report values for report_aged_partner_balance_qweb_account"""
  189. query_inject_account = """
  190. INSERT INTO
  191. report_aged_partner_balance_qweb_account
  192. (
  193. report_id,
  194. create_uid,
  195. create_date,
  196. account_id,
  197. code,
  198. name
  199. )
  200. SELECT
  201. %s AS report_id,
  202. %s AS create_uid,
  203. NOW() AS create_date,
  204. rao.account_id,
  205. rao.code,
  206. rao.name
  207. FROM
  208. report_open_items_qweb_account rao
  209. WHERE
  210. rao.report_id = %s
  211. """
  212. query_inject_account_params = (
  213. self.id,
  214. self.env.uid,
  215. self.open_items_id.id,
  216. )
  217. self.env.cr.execute(query_inject_account, query_inject_account_params)
  218. def _inject_partner_values(self):
  219. """Inject report values for report_aged_partner_balance_qweb_partner"""
  220. query_inject_partner = """
  221. INSERT INTO
  222. report_aged_partner_balance_qweb_partner
  223. (
  224. report_account_id,
  225. create_uid,
  226. create_date,
  227. partner_id,
  228. name
  229. )
  230. SELECT
  231. ra.id AS report_account_id,
  232. %s AS create_uid,
  233. NOW() AS create_date,
  234. rpo.partner_id,
  235. rpo.name
  236. FROM
  237. report_open_items_qweb_partner rpo
  238. INNER JOIN
  239. report_open_items_qweb_account rao ON rpo.report_account_id = rao.id
  240. INNER JOIN
  241. report_aged_partner_balance_qweb_account ra ON rao.code = ra.code
  242. WHERE
  243. rao.report_id = %s
  244. AND ra.report_id = %s
  245. """
  246. query_inject_partner_params = (
  247. self.env.uid,
  248. self.open_items_id.id,
  249. self.id,
  250. )
  251. self.env.cr.execute(query_inject_partner, query_inject_partner_params)
  252. def _inject_line_values(self, only_empty_partner_line=False):
  253. """ Inject report values for report_aged_partner_balance_qweb_line.
  254. The "only_empty_partner_line" value is used
  255. to compute data without partner.
  256. """
  257. query_inject_line = """
  258. WITH
  259. date_range AS
  260. (
  261. SELECT
  262. %s AS date_current,
  263. DATE %s - INTEGER '30' AS date_less_30_days,
  264. DATE %s - INTEGER '60' AS date_less_60_days,
  265. DATE %s - INTEGER '90' AS date_less_90_days,
  266. DATE %s - INTEGER '120' AS date_less_120_days,
  267. DATE %s - INTEGER '150' AS date_older
  268. )
  269. INSERT INTO
  270. report_aged_partner_balance_qweb_line
  271. (
  272. report_partner_id,
  273. partner,
  274. amount_residual,
  275. current,
  276. age_30_days,
  277. age_60_days,
  278. age_90_days,
  279. age_120_days,
  280. older
  281. )
  282. SELECT
  283. rp.id AS report_partner_id,
  284. rp.name,
  285. SUM(rlo.amount_residual) AS amount_residual,
  286. SUM(
  287. CASE
  288. WHEN rlo.date_due > date_range.date_less_30_days
  289. THEN rlo.amount_residual
  290. END
  291. ) AS current,
  292. SUM(
  293. CASE
  294. WHEN
  295. rlo.date_due > date_range.date_less_60_days
  296. AND rlo.date_due <= date_range.date_less_30_days
  297. THEN rlo.amount_residual
  298. END
  299. ) AS age_30_days,
  300. SUM(
  301. CASE
  302. WHEN
  303. rlo.date_due > date_range.date_less_90_days
  304. AND rlo.date_due <= date_range.date_less_60_days
  305. THEN rlo.amount_residual
  306. END
  307. ) AS age_60_days,
  308. SUM(
  309. CASE
  310. WHEN
  311. rlo.date_due > date_range.date_less_120_days
  312. AND rlo.date_due <= date_range.date_less_90_days
  313. THEN rlo.amount_residual
  314. END
  315. ) AS age_90_days,
  316. SUM(
  317. CASE
  318. WHEN
  319. rlo.date_due > date_range.date_older
  320. AND rlo.date_due <= date_range.date_less_120_days
  321. THEN rlo.amount_residual
  322. END
  323. ) AS age_120_days,
  324. SUM(
  325. CASE
  326. WHEN rlo.date_due <= date_range.date_older
  327. THEN rlo.amount_residual
  328. END
  329. ) AS older
  330. FROM
  331. date_range,
  332. report_open_items_qweb_move_line rlo
  333. INNER JOIN
  334. report_open_items_qweb_partner rpo ON rlo.report_partner_id = rpo.id
  335. INNER JOIN
  336. report_open_items_qweb_account rao ON rpo.report_account_id = rao.id
  337. INNER JOIN
  338. report_aged_partner_balance_qweb_account ra ON rao.code = ra.code
  339. INNER JOIN
  340. report_aged_partner_balance_qweb_partner rp
  341. ON
  342. ra.id = rp.report_account_id
  343. """
  344. if not only_empty_partner_line:
  345. query_inject_line += """
  346. AND rpo.partner_id = rp.partner_id
  347. """
  348. elif only_empty_partner_line:
  349. query_inject_line += """
  350. AND rpo.partner_id IS NULL
  351. AND rp.partner_id IS NULL
  352. """
  353. query_inject_line += """
  354. WHERE
  355. rao.report_id = %s
  356. AND ra.report_id = %s
  357. GROUP BY
  358. rp.id
  359. """
  360. query_inject_line_params = (self.date_at,) * 6
  361. query_inject_line_params += (
  362. self.open_items_id.id,
  363. self.id,
  364. )
  365. self.env.cr.execute(query_inject_line, query_inject_line_params)
  366. def _inject_move_line_values(self, only_empty_partner_line=False):
  367. """ Inject report values for report_aged_partner_balance_qweb_move_line
  368. The "only_empty_partner_line" value is used
  369. to compute data without partner.
  370. """
  371. query_inject_move_line = """
  372. WITH
  373. date_range AS
  374. (
  375. SELECT
  376. %s AS date_current,
  377. DATE %s - INTEGER '30' AS date_less_30_days,
  378. DATE %s - INTEGER '60' AS date_less_60_days,
  379. DATE %s - INTEGER '90' AS date_less_90_days,
  380. DATE %s - INTEGER '120' AS date_less_120_days,
  381. DATE %s - INTEGER '150' AS date_older
  382. )
  383. INSERT INTO
  384. report_aged_partner_balance_qweb_move_line
  385. (
  386. report_partner_id,
  387. date,
  388. date_due,
  389. entry,
  390. journal,
  391. account,
  392. partner,
  393. label,
  394. amount_residual,
  395. current,
  396. age_30_days,
  397. age_60_days,
  398. age_90_days,
  399. age_120_days,
  400. older
  401. )
  402. SELECT
  403. rp.id AS report_partner_id,
  404. rlo.date,
  405. rlo.date_due,
  406. rlo.entry,
  407. rlo.journal,
  408. rlo.account,
  409. rlo.partner,
  410. rlo.label,
  411. rlo.amount_residual AS amount_residual,
  412. CASE
  413. WHEN rlo.date_due > date_range.date_less_30_days
  414. THEN rlo.amount_residual
  415. END AS current,
  416. CASE
  417. WHEN
  418. rlo.date_due > date_range.date_less_60_days
  419. AND rlo.date_due <= date_range.date_less_30_days
  420. THEN rlo.amount_residual
  421. END AS age_30_days,
  422. CASE
  423. WHEN
  424. rlo.date_due > date_range.date_less_90_days
  425. AND rlo.date_due <= date_range.date_less_60_days
  426. THEN rlo.amount_residual
  427. END AS age_60_days,
  428. CASE
  429. WHEN
  430. rlo.date_due > date_range.date_less_120_days
  431. AND rlo.date_due <= date_range.date_less_90_days
  432. THEN rlo.amount_residual
  433. END AS age_90_days,
  434. CASE
  435. WHEN
  436. rlo.date_due > date_range.date_older
  437. AND rlo.date_due <= date_range.date_less_120_days
  438. THEN rlo.amount_residual
  439. END AS age_120_days,
  440. CASE
  441. WHEN rlo.date_due <= date_range.date_older
  442. THEN rlo.amount_residual
  443. END AS older
  444. FROM
  445. date_range,
  446. report_open_items_qweb_move_line rlo
  447. INNER JOIN
  448. report_open_items_qweb_partner rpo ON rlo.report_partner_id = rpo.id
  449. INNER JOIN
  450. report_open_items_qweb_account rao ON rpo.report_account_id = rao.id
  451. INNER JOIN
  452. report_aged_partner_balance_qweb_account ra ON rao.code = ra.code
  453. INNER JOIN
  454. report_aged_partner_balance_qweb_partner rp
  455. ON
  456. ra.id = rp.report_account_id
  457. """
  458. if not only_empty_partner_line:
  459. query_inject_move_line += """
  460. AND rpo.partner_id = rp.partner_id
  461. """
  462. elif only_empty_partner_line:
  463. query_inject_move_line += """
  464. AND rpo.partner_id IS NULL
  465. AND rp.partner_id IS NULL
  466. """
  467. query_inject_move_line += """
  468. WHERE
  469. rao.report_id = %s
  470. AND ra.report_id = %s
  471. """
  472. query_inject_move_line_params = (self.date_at,) * 6
  473. query_inject_move_line_params += (
  474. self.open_items_id.id,
  475. self.id,
  476. )
  477. self.env.cr.execute(query_inject_move_line,
  478. query_inject_move_line_params)
  479. def _compute_accounts_cumul(self):
  480. """ Compute cumulative amount for
  481. report_aged_partner_balance_qweb_account.
  482. """
  483. query_compute_accounts_cumul = """
  484. WITH
  485. cumuls AS
  486. (
  487. SELECT
  488. ra.id AS report_account_id,
  489. SUM(rl.amount_residual) AS cumul_amount_residual,
  490. SUM(rl.current) AS cumul_current,
  491. SUM(rl.age_30_days) AS cumul_age_30_days,
  492. SUM(rl.age_60_days) AS cumul_age_60_days,
  493. SUM(rl.age_90_days) AS cumul_age_90_days,
  494. SUM(rl.age_120_days) AS cumul_age_120_days,
  495. SUM(rl.older) AS cumul_older
  496. FROM
  497. report_aged_partner_balance_qweb_line rl
  498. INNER JOIN
  499. report_aged_partner_balance_qweb_partner rp
  500. ON rl.report_partner_id = rp.id
  501. INNER JOIN
  502. report_aged_partner_balance_qweb_account ra
  503. ON rp.report_account_id = ra.id
  504. WHERE
  505. ra.report_id = %s
  506. GROUP BY
  507. ra.id
  508. )
  509. UPDATE
  510. report_aged_partner_balance_qweb_account
  511. SET
  512. cumul_amount_residual = c.cumul_amount_residual,
  513. cumul_current = c.cumul_current,
  514. cumul_age_30_days = c.cumul_age_30_days,
  515. cumul_age_60_days = c.cumul_age_60_days,
  516. cumul_age_90_days = c.cumul_age_90_days,
  517. cumul_age_120_days = c.cumul_age_120_days,
  518. cumul_older = c.cumul_older,
  519. percent_current =
  520. CASE
  521. WHEN c.cumul_amount_residual != 0
  522. THEN 100 * c.cumul_current / c.cumul_amount_residual
  523. END,
  524. percent_age_30_days =
  525. CASE
  526. WHEN c.cumul_amount_residual != 0
  527. THEN 100 * c.cumul_age_30_days / c.cumul_amount_residual
  528. END,
  529. percent_age_60_days =
  530. CASE
  531. WHEN c.cumul_amount_residual != 0
  532. THEN 100 * c.cumul_age_60_days / c.cumul_amount_residual
  533. END,
  534. percent_age_90_days =
  535. CASE
  536. WHEN c.cumul_amount_residual != 0
  537. THEN 100 * c.cumul_age_90_days / c.cumul_amount_residual
  538. END,
  539. percent_age_120_days =
  540. CASE
  541. WHEN c.cumul_amount_residual != 0
  542. THEN 100 * c.cumul_age_120_days / c.cumul_amount_residual
  543. END,
  544. percent_older =
  545. CASE
  546. WHEN c.cumul_amount_residual != 0
  547. THEN 100 * c.cumul_older / c.cumul_amount_residual
  548. END
  549. FROM
  550. cumuls c
  551. WHERE
  552. id = c.report_account_id
  553. """
  554. params_compute_accounts_cumul = (self.id,)
  555. self.env.cr.execute(query_compute_accounts_cumul,
  556. params_compute_accounts_cumul)