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.

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