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.

761 lines
22 KiB

  1. # © 2016 Julien Coux (Camptocamp)
  2. # License AGPL-3.0 or later (http://www.gnu.org/licenses/agpl.html).
  3. from odoo import models, fields, api, _
  4. class OpenItemsReport(models.TransientModel):
  5. """ Here, we just define class fields.
  6. For methods, go more bottom at this file.
  7. The class hierarchy is :
  8. * OpenItemsReport
  9. ** OpenItemsReportAccount
  10. *** OpenItemsReportPartner
  11. **** OpenItemsReportMoveLine
  12. """
  13. _name = 'report_open_items'
  14. # Filters fields, used for data computation
  15. date_at = fields.Date()
  16. only_posted_moves = fields.Boolean()
  17. hide_account_balance_at_0 = fields.Boolean()
  18. company_id = fields.Many2one(comodel_name='res.company')
  19. filter_account_ids = fields.Many2many(comodel_name='account.account')
  20. filter_partner_ids = fields.Many2many(comodel_name='res.partner')
  21. # Flag fields, used for report display
  22. has_second_currency = fields.Boolean()
  23. # Data fields, used to browse report data
  24. account_ids = fields.One2many(
  25. comodel_name='report_open_items_account',
  26. inverse_name='report_id'
  27. )
  28. class OpenItemsReportAccount(models.TransientModel):
  29. _name = 'report_open_items_account'
  30. _order = 'code ASC'
  31. report_id = fields.Many2one(
  32. comodel_name='report_open_items',
  33. ondelete='cascade',
  34. index=True
  35. )
  36. # Data fields, used to keep link with real object
  37. account_id = fields.Many2one(
  38. 'account.account',
  39. index=True
  40. )
  41. # Data fields, used for report display
  42. code = fields.Char()
  43. name = fields.Char()
  44. final_amount_residual = fields.Float(digits=(16, 2))
  45. # Data fields, used to browse report data
  46. partner_ids = fields.One2many(
  47. comodel_name='report_open_items_partner',
  48. inverse_name='report_account_id'
  49. )
  50. class OpenItemsReportPartner(models.TransientModel):
  51. _name = 'report_open_items_partner'
  52. report_account_id = fields.Many2one(
  53. comodel_name='report_open_items_account',
  54. ondelete='cascade',
  55. index=True
  56. )
  57. # Data fields, used to keep link with real object
  58. partner_id = fields.Many2one(
  59. 'res.partner',
  60. index=True
  61. )
  62. # Data fields, used for report display
  63. name = fields.Char()
  64. final_amount_residual = fields.Float(digits=(16, 2))
  65. # Data fields, used to browse report data
  66. move_line_ids = fields.One2many(
  67. comodel_name='report_open_items_move_line',
  68. inverse_name='report_partner_id'
  69. )
  70. @api.model
  71. def _generate_order_by(self, order_spec, query):
  72. """Custom order to display "No partner allocated" at last position."""
  73. return """
  74. ORDER BY
  75. CASE
  76. WHEN "report_open_items_partner"."partner_id" IS NOT NULL
  77. THEN 0
  78. ELSE 1
  79. END,
  80. "report_open_items_partner"."name"
  81. """
  82. class OpenItemsReportMoveLine(models.TransientModel):
  83. _name = 'report_open_items_move_line'
  84. report_partner_id = fields.Many2one(
  85. comodel_name='report_open_items_partner',
  86. ondelete='cascade',
  87. index=True
  88. )
  89. # Data fields, used to keep link with real object
  90. move_line_id = fields.Many2one('account.move.line')
  91. # Data fields, used for report display
  92. date = fields.Date()
  93. date_due = fields.Date()
  94. entry = fields.Char()
  95. journal = fields.Char()
  96. account = fields.Char()
  97. partner = fields.Char()
  98. label = fields.Char()
  99. amount_total_due = fields.Float(digits=(16, 2))
  100. amount_residual = fields.Float(digits=(16, 2))
  101. currency_name = fields.Char()
  102. amount_total_due_currency = fields.Float(digits=(16, 2))
  103. amount_residual_currency = fields.Float(digits=(16, 2))
  104. class OpenItemsReportCompute(models.TransientModel):
  105. """ Here, we just define methods.
  106. For class fields, go more top at this file.
  107. """
  108. _inherit = 'report_open_items'
  109. @api.multi
  110. def print_report(self, report_type):
  111. self.ensure_one()
  112. self.compute_data_for_report()
  113. if report_type == 'xlsx':
  114. report_name = 'a_f_r.report_open_items_xlsx'
  115. else:
  116. report_name = 'account_financial_report.' \
  117. 'report_open_items_qweb'
  118. return self.env['ir.actions.report'].search(
  119. [('report_name', '=', report_name),
  120. ('report_type', '=', report_type)], limit=1).report_action(self)
  121. @api.multi
  122. def compute_data_for_report(self):
  123. self.ensure_one()
  124. # Compute report data
  125. self._inject_account_values()
  126. self._inject_partner_values()
  127. self._inject_line_values()
  128. self._inject_line_values(only_empty_partner_line=True)
  129. self._clean_partners_and_accounts()
  130. self._compute_partners_and_accounts_cumul()
  131. if self.hide_account_balance_at_0:
  132. self._clean_partners_and_accounts(
  133. only_delete_account_balance_at_0=True
  134. )
  135. # Compute display flag
  136. self._compute_has_second_currency()
  137. # Refresh cache because all data are computed with SQL requests
  138. self.refresh()
  139. def _inject_account_values(self):
  140. """Inject report values for report_open_items_account."""
  141. query_inject_account = """
  142. WITH
  143. accounts AS
  144. (
  145. SELECT
  146. a.id,
  147. a.code,
  148. a.name,
  149. a.user_type_id
  150. FROM
  151. account_account a
  152. INNER JOIN
  153. account_move_line ml ON a.id = ml.account_id AND ml.date <= %s
  154. """
  155. if self.filter_partner_ids:
  156. query_inject_account += """
  157. INNER JOIN
  158. res_partner p ON ml.partner_id = p.id
  159. """
  160. if self.only_posted_moves:
  161. query_inject_account += """
  162. INNER JOIN
  163. account_move m ON ml.move_id = m.id AND m.state = 'posted'
  164. """
  165. query_inject_account += """
  166. WHERE
  167. a.company_id = %s
  168. AND a.reconcile IS true
  169. """
  170. if self.filter_account_ids:
  171. query_inject_account += """
  172. AND
  173. a.id IN %s
  174. """
  175. if self.filter_partner_ids:
  176. query_inject_account += """
  177. AND
  178. p.id IN %s
  179. """
  180. query_inject_account += """
  181. GROUP BY
  182. a.id
  183. )
  184. INSERT INTO
  185. report_open_items_account
  186. (
  187. report_id,
  188. create_uid,
  189. create_date,
  190. account_id,
  191. code,
  192. name
  193. )
  194. SELECT
  195. %s AS report_id,
  196. %s AS create_uid,
  197. NOW() AS create_date,
  198. a.id AS account_id,
  199. a.code,
  200. a.name
  201. FROM
  202. accounts a
  203. """
  204. query_inject_account_params = (
  205. self.date_at,
  206. self.company_id.id,
  207. )
  208. if self.filter_account_ids:
  209. query_inject_account_params += (
  210. tuple(self.filter_account_ids.ids),
  211. )
  212. if self.filter_partner_ids:
  213. query_inject_account_params += (
  214. tuple(self.filter_partner_ids.ids),
  215. )
  216. query_inject_account_params += (
  217. self.id,
  218. self.env.uid,
  219. )
  220. self.env.cr.execute(query_inject_account, query_inject_account_params)
  221. def _inject_partner_values(self):
  222. """ Inject report values for report_open_items_partner. """
  223. # pylint: disable=sql-injection
  224. query_inject_partner = """
  225. WITH
  226. accounts_partners AS
  227. (
  228. SELECT
  229. ra.id AS report_account_id,
  230. a.id AS account_id,
  231. at.include_initial_balance AS include_initial_balance,
  232. p.id AS partner_id,
  233. COALESCE(
  234. CASE
  235. WHEN
  236. NULLIF(p.name, '') IS NOT NULL
  237. AND NULLIF(p.ref, '') IS NOT NULL
  238. THEN p.name || ' (' || p.ref || ')'
  239. ELSE p.name
  240. END,
  241. '""" + _('No partner allocated') + """'
  242. ) AS partner_name
  243. FROM
  244. report_open_items_account ra
  245. INNER JOIN
  246. account_account a ON ra.account_id = a.id
  247. INNER JOIN
  248. account_account_type at ON a.user_type_id = at.id
  249. INNER JOIN
  250. account_move_line ml ON a.id = ml.account_id AND ml.date <= %s
  251. """
  252. if self.only_posted_moves:
  253. query_inject_partner += """
  254. INNER JOIN
  255. account_move m ON ml.move_id = m.id AND m.state = 'posted'
  256. """
  257. query_inject_partner += """
  258. LEFT JOIN
  259. res_partner p ON ml.partner_id = p.id
  260. WHERE
  261. ra.report_id = %s
  262. """
  263. if self.filter_partner_ids:
  264. query_inject_partner += """
  265. AND
  266. p.id IN %s
  267. """
  268. query_inject_partner += """
  269. GROUP BY
  270. ra.id,
  271. a.id,
  272. p.id,
  273. at.include_initial_balance
  274. )
  275. INSERT INTO
  276. report_open_items_partner
  277. (
  278. report_account_id,
  279. create_uid,
  280. create_date,
  281. partner_id,
  282. name
  283. )
  284. SELECT
  285. ap.report_account_id,
  286. %s AS create_uid,
  287. NOW() AS create_date,
  288. ap.partner_id,
  289. ap.partner_name
  290. FROM
  291. accounts_partners ap
  292. """
  293. query_inject_partner_params = (
  294. self.date_at,
  295. self.id,
  296. )
  297. if self.filter_partner_ids:
  298. query_inject_partner_params += (
  299. tuple(self.filter_partner_ids.ids),
  300. )
  301. query_inject_partner_params += (
  302. self.env.uid,
  303. )
  304. self.env.cr.execute(query_inject_partner, query_inject_partner_params)
  305. def _get_line_sub_query_move_lines(self,
  306. only_empty_partner_line=False,
  307. positive_balance=True):
  308. """ Return subquery used to compute sum amounts on lines """
  309. sub_query = """
  310. SELECT
  311. ml.id,
  312. ml.balance,
  313. SUM(
  314. CASE
  315. WHEN ml_past.id IS NOT NULL
  316. THEN pr.amount
  317. ELSE NULL
  318. END
  319. ) AS partial_amount,
  320. ml.amount_currency,
  321. SUM(
  322. CASE
  323. WHEN ml_past.id IS NOT NULL
  324. THEN pr.amount_currency
  325. ELSE NULL
  326. END
  327. ) AS partial_amount_currency,
  328. ml.currency_id
  329. FROM
  330. report_open_items_partner rp
  331. INNER JOIN
  332. report_open_items_account ra
  333. ON rp.report_account_id = ra.id
  334. INNER JOIN
  335. account_move_line ml
  336. ON ra.account_id = ml.account_id
  337. """
  338. if not only_empty_partner_line:
  339. sub_query += """
  340. AND rp.partner_id = ml.partner_id
  341. """
  342. elif only_empty_partner_line:
  343. sub_query += """
  344. AND ml.partner_id IS NULL
  345. """
  346. if not positive_balance:
  347. sub_query += """
  348. LEFT JOIN
  349. account_partial_reconcile pr
  350. ON ml.balance < 0 AND pr.credit_move_id = ml.id
  351. LEFT JOIN
  352. account_move_line ml_future
  353. ON ml.balance < 0 AND pr.debit_move_id = ml_future.id
  354. AND ml_future.date >= %s
  355. LEFT JOIN
  356. account_move_line ml_past
  357. ON ml.balance < 0 AND pr.debit_move_id = ml_past.id
  358. AND ml_past.date < %s
  359. """
  360. else:
  361. sub_query += """
  362. LEFT JOIN
  363. account_partial_reconcile pr
  364. ON ml.balance > 0 AND pr.debit_move_id = ml.id
  365. LEFT JOIN
  366. account_move_line ml_future
  367. ON ml.balance > 0 AND pr.credit_move_id = ml_future.id
  368. AND ml_future.date >= %s
  369. LEFT JOIN
  370. account_move_line ml_past
  371. ON ml.balance > 0 AND pr.credit_move_id = ml_past.id
  372. AND ml_past.date < %s
  373. """
  374. sub_query += """
  375. WHERE
  376. ra.report_id = %s
  377. GROUP BY
  378. ml.id,
  379. ml.balance,
  380. ml.amount_currency
  381. HAVING
  382. (
  383. ml.full_reconcile_id IS NULL
  384. OR MAX(ml_future.id) IS NOT NULL
  385. )
  386. """
  387. return sub_query
  388. def _inject_line_values(self, only_empty_partner_line=False):
  389. """ Inject report values for report_open_items_move_line.
  390. The "only_empty_partner_line" value is used
  391. to compute data without partner.
  392. """
  393. query_inject_move_line = """
  394. WITH
  395. move_lines_amount AS
  396. (
  397. """
  398. query_inject_move_line += self._get_line_sub_query_move_lines(
  399. only_empty_partner_line=only_empty_partner_line,
  400. positive_balance=True
  401. )
  402. query_inject_move_line += """
  403. UNION
  404. """
  405. query_inject_move_line += self._get_line_sub_query_move_lines(
  406. only_empty_partner_line=only_empty_partner_line,
  407. positive_balance=False
  408. )
  409. query_inject_move_line += """
  410. ),
  411. move_lines AS
  412. (
  413. SELECT
  414. id,
  415. CASE
  416. WHEN SUM(partial_amount) > 0
  417. THEN
  418. CASE
  419. WHEN balance > 0
  420. THEN balance - SUM(partial_amount)
  421. ELSE balance + SUM(partial_amount)
  422. END
  423. ELSE balance
  424. END AS amount_residual,
  425. CASE
  426. WHEN SUM(partial_amount_currency) > 0
  427. THEN
  428. CASE
  429. WHEN amount_currency > 0
  430. THEN amount_currency - SUM(partial_amount_currency)
  431. ELSE amount_currency + SUM(partial_amount_currency)
  432. END
  433. ELSE amount_currency
  434. END AS amount_residual_currency,
  435. currency_id
  436. FROM
  437. move_lines_amount
  438. GROUP BY
  439. id,
  440. balance,
  441. amount_currency,
  442. currency_id
  443. )
  444. INSERT INTO
  445. report_open_items_move_line
  446. (
  447. report_partner_id,
  448. create_uid,
  449. create_date,
  450. move_line_id,
  451. date,
  452. date_due,
  453. entry,
  454. journal,
  455. account,
  456. partner,
  457. label,
  458. amount_total_due,
  459. amount_residual,
  460. currency_name,
  461. amount_total_due_currency,
  462. amount_residual_currency
  463. )
  464. SELECT
  465. rp.id AS report_partner_id,
  466. %s AS create_uid,
  467. NOW() AS create_date,
  468. ml.id AS move_line_id,
  469. ml.date,
  470. ml.date_maturity,
  471. m.name AS entry,
  472. j.code AS journal,
  473. a.code AS account,
  474. """
  475. if not only_empty_partner_line:
  476. query_inject_move_line += """
  477. CASE
  478. WHEN
  479. NULLIF(p.name, '') IS NOT NULL
  480. AND NULLIF(p.ref, '') IS NOT NULL
  481. THEN p.name || ' (' || p.ref || ')'
  482. ELSE p.name
  483. END AS partner,
  484. """
  485. elif only_empty_partner_line:
  486. query_inject_move_line += """
  487. '""" + _('No partner allocated') + """' AS partner,
  488. """
  489. query_inject_move_line += """
  490. CONCAT_WS(' - ', NULLIF(ml.ref, ''), NULLIF(ml.name, '')) AS label,
  491. ml.balance,
  492. ml2.amount_residual,
  493. c.name AS currency_name,
  494. ml.amount_currency,
  495. ml2.amount_residual_currency
  496. FROM
  497. report_open_items_partner rp
  498. INNER JOIN
  499. report_open_items_account ra ON rp.report_account_id = ra.id
  500. INNER JOIN
  501. account_move_line ml ON ra.account_id = ml.account_id
  502. INNER JOIN
  503. move_lines ml2
  504. ON ml.id = ml2.id
  505. AND ml2.amount_residual IS NOT NULL
  506. AND ml2.amount_residual != 0
  507. INNER JOIN
  508. account_move m ON ml.move_id = m.id
  509. INNER JOIN
  510. account_journal j ON ml.journal_id = j.id
  511. INNER JOIN
  512. account_account a ON ml.account_id = a.id
  513. """
  514. if not only_empty_partner_line:
  515. query_inject_move_line += """
  516. INNER JOIN
  517. res_partner p
  518. ON ml.partner_id = p.id AND rp.partner_id = p.id
  519. """
  520. query_inject_move_line += """
  521. LEFT JOIN
  522. account_full_reconcile fr ON ml.full_reconcile_id = fr.id
  523. LEFT JOIN
  524. res_currency c ON ml2.currency_id = c.id
  525. WHERE
  526. ra.report_id = %s
  527. AND
  528. ml.date <= %s
  529. """
  530. if self.only_posted_moves:
  531. query_inject_move_line += """
  532. AND
  533. m.state = 'posted'
  534. """
  535. if only_empty_partner_line:
  536. query_inject_move_line += """
  537. AND
  538. ml.partner_id IS NULL
  539. AND
  540. rp.partner_id IS NULL
  541. """
  542. if not only_empty_partner_line:
  543. query_inject_move_line += """
  544. ORDER BY
  545. a.code, p.name, ml.date, ml.id
  546. """
  547. elif only_empty_partner_line:
  548. query_inject_move_line += """
  549. ORDER BY
  550. a.code, ml.date, ml.id
  551. """
  552. self.env.cr.execute(
  553. query_inject_move_line,
  554. (self.date_at,
  555. self.date_at,
  556. self.id,
  557. self.date_at,
  558. self.date_at,
  559. self.id,
  560. self.env.uid,
  561. self.id,
  562. self.date_at,)
  563. )
  564. def _compute_partners_and_accounts_cumul(self):
  565. """ Compute cumulative amount for
  566. report_open_items_partner and report_open_items_account.
  567. """
  568. query_compute_partners_cumul = """
  569. UPDATE
  570. report_open_items_partner
  571. SET
  572. final_amount_residual =
  573. (
  574. SELECT
  575. SUM(rml.amount_residual) AS final_amount_residual
  576. FROM
  577. report_open_items_move_line rml
  578. WHERE
  579. rml.report_partner_id = report_open_items_partner.id
  580. )
  581. WHERE
  582. id IN
  583. (
  584. SELECT
  585. rp.id
  586. FROM
  587. report_open_items_account ra
  588. INNER JOIN
  589. report_open_items_partner rp
  590. ON ra.id = rp.report_account_id
  591. WHERE
  592. ra.report_id = %s
  593. )
  594. """
  595. params_compute_partners_cumul = (self.id,)
  596. self.env.cr.execute(query_compute_partners_cumul,
  597. params_compute_partners_cumul)
  598. query_compute_accounts_cumul = """
  599. UPDATE
  600. report_open_items_account
  601. SET
  602. final_amount_residual =
  603. (
  604. SELECT
  605. SUM(rp.final_amount_residual) AS final_amount_residual
  606. FROM
  607. report_open_items_partner rp
  608. WHERE
  609. rp.report_account_id = report_open_items_account.id
  610. )
  611. WHERE
  612. report_id = %s
  613. """
  614. params_compute_accounts_cumul = (self.id,)
  615. self.env.cr.execute(query_compute_accounts_cumul,
  616. params_compute_accounts_cumul)
  617. def _clean_partners_and_accounts(self,
  618. only_delete_account_balance_at_0=False):
  619. """ Delete empty data for
  620. report_open_items_partner and report_open_items_account.
  621. The "only_delete_account_balance_at_0" value is used
  622. to delete also the data with cumulative amounts at 0.
  623. """
  624. query_clean_partners = """
  625. DELETE FROM
  626. report_open_items_partner
  627. WHERE
  628. id IN
  629. (
  630. SELECT
  631. DISTINCT rp.id
  632. FROM
  633. report_open_items_account ra
  634. INNER JOIN
  635. report_open_items_partner rp
  636. ON ra.id = rp.report_account_id
  637. LEFT JOIN
  638. report_open_items_move_line rml
  639. ON rp.id = rml.report_partner_id
  640. WHERE
  641. ra.report_id = %s
  642. """
  643. if not only_delete_account_balance_at_0:
  644. query_clean_partners += """
  645. AND rml.id IS NULL
  646. """
  647. elif only_delete_account_balance_at_0:
  648. query_clean_partners += """
  649. AND (
  650. rp.final_amount_residual IS NULL
  651. OR rp.final_amount_residual = 0
  652. )
  653. """
  654. query_clean_partners += """
  655. )
  656. """
  657. params_clean_partners = (self.id,)
  658. self.env.cr.execute(query_clean_partners, params_clean_partners)
  659. query_clean_accounts = """
  660. DELETE FROM
  661. report_open_items_account
  662. WHERE
  663. id IN
  664. (
  665. SELECT
  666. DISTINCT ra.id
  667. FROM
  668. report_open_items_account ra
  669. LEFT JOIN
  670. report_open_items_partner rp
  671. ON ra.id = rp.report_account_id
  672. WHERE
  673. ra.report_id = %s
  674. """
  675. if not only_delete_account_balance_at_0:
  676. query_clean_accounts += """
  677. AND rp.id IS NULL
  678. """
  679. elif only_delete_account_balance_at_0:
  680. query_clean_accounts += """
  681. AND (
  682. ra.final_amount_residual IS NULL
  683. OR ra.final_amount_residual = 0
  684. )
  685. """
  686. query_clean_accounts += """
  687. )
  688. """
  689. params_clean_accounts = (self.id,)
  690. self.env.cr.execute(query_clean_accounts, params_clean_accounts)
  691. def _compute_has_second_currency(self):
  692. """ Compute "has_second_currency" flag which will used for display."""
  693. query_update_has_second_currency = """
  694. UPDATE
  695. report_open_items
  696. SET
  697. has_second_currency =
  698. (
  699. SELECT
  700. TRUE
  701. FROM
  702. report_open_items_move_line l
  703. INNER JOIN
  704. report_open_items_partner p
  705. ON l.report_partner_id = p.id
  706. INNER JOIN
  707. report_open_items_account a
  708. ON p.report_account_id = a.id
  709. WHERE
  710. a.report_id = %s
  711. AND l.currency_name IS NOT NULL
  712. LIMIT 1
  713. )
  714. WHERE id = %s
  715. """
  716. params = (self.id,) * 2
  717. self.env.cr.execute(query_update_has_second_currency, params)