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.

763 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 openerp 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(records=self,
  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.internal_type IN ('payable', 'receivable')
  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. COALESCE(tr.value, a.name) AS name
  202. FROM
  203. accounts a
  204. LEFT JOIN
  205. ir_translation tr ON a.id = tr.res_id
  206. AND tr.lang = %s
  207. AND tr.type = 'model'
  208. AND tr.name = 'account.account,name'
  209. """
  210. query_inject_account_params = (
  211. self.date_at,
  212. self.company_id.id,
  213. )
  214. if self.filter_account_ids:
  215. query_inject_account_params += (
  216. tuple(self.filter_account_ids.ids),
  217. )
  218. if self.filter_partner_ids:
  219. query_inject_account_params += (
  220. tuple(self.filter_partner_ids.ids),
  221. )
  222. query_inject_account_params += (
  223. self.id,
  224. self.env.uid,
  225. self.env.lang,
  226. )
  227. self.env.cr.execute(query_inject_account, query_inject_account_params)
  228. def _inject_partner_values(self):
  229. """ Inject report values for report_open_items_qweb_partner. """
  230. query_inject_partner = """
  231. WITH
  232. accounts_partners AS
  233. (
  234. SELECT
  235. ra.id AS report_account_id,
  236. a.id AS account_id,
  237. at.include_initial_balance AS include_initial_balance,
  238. p.id AS partner_id,
  239. COALESCE(
  240. CASE
  241. WHEN
  242. NULLIF(p.name, '') IS NOT NULL
  243. AND NULLIF(p.ref, '') IS NOT NULL
  244. THEN p.name || ' (' || p.ref || ')'
  245. ELSE p.name
  246. END,
  247. '""" + _('No partner allocated') + """'
  248. ) AS partner_name
  249. FROM
  250. report_open_items_qweb_account ra
  251. INNER JOIN
  252. account_account a ON ra.account_id = a.id
  253. INNER JOIN
  254. account_account_type at ON a.user_type_id = at.id
  255. INNER JOIN
  256. account_move_line ml ON a.id = ml.account_id AND ml.date <= %s
  257. """
  258. if self.only_posted_moves:
  259. query_inject_partner += """
  260. INNER JOIN
  261. account_move m ON ml.move_id = m.id AND m.state = 'posted'
  262. """
  263. query_inject_partner += """
  264. LEFT JOIN
  265. res_partner p ON ml.partner_id = p.id
  266. WHERE
  267. ra.report_id = %s
  268. """
  269. if self.filter_partner_ids:
  270. query_inject_partner += """
  271. AND
  272. p.id IN %s
  273. """
  274. query_inject_partner += """
  275. GROUP BY
  276. ra.id,
  277. a.id,
  278. p.id,
  279. at.include_initial_balance
  280. )
  281. INSERT INTO
  282. report_open_items_qweb_partner
  283. (
  284. report_account_id,
  285. create_uid,
  286. create_date,
  287. partner_id,
  288. name
  289. )
  290. SELECT
  291. ap.report_account_id,
  292. %s AS create_uid,
  293. NOW() AS create_date,
  294. ap.partner_id,
  295. ap.partner_name
  296. FROM
  297. accounts_partners ap
  298. """
  299. query_inject_partner_params = (
  300. self.date_at,
  301. self.id,
  302. )
  303. if self.filter_partner_ids:
  304. query_inject_partner_params += (
  305. tuple(self.filter_partner_ids.ids),
  306. )
  307. query_inject_partner_params += (
  308. self.env.uid,
  309. )
  310. self.env.cr.execute(query_inject_partner, query_inject_partner_params)
  311. def _get_line_sub_query_move_lines(self,
  312. only_empty_partner_line=False,
  313. positive_balance=True):
  314. """ Return subquery used to compute sum amounts on lines """
  315. sub_query = """
  316. SELECT
  317. ml.id,
  318. ml.balance,
  319. SUM(
  320. CASE
  321. WHEN ml_past.id IS NOT NULL
  322. THEN pr.amount
  323. ELSE NULL
  324. END
  325. ) AS partial_amount,
  326. ml.amount_currency,
  327. SUM(
  328. CASE
  329. WHEN ml_past.id IS NOT NULL
  330. THEN pr.amount_currency
  331. ELSE NULL
  332. END
  333. ) AS partial_amount_currency
  334. FROM
  335. report_open_items_qweb_partner rp
  336. INNER JOIN
  337. report_open_items_qweb_account ra
  338. ON rp.report_account_id = ra.id
  339. INNER JOIN
  340. account_move_line ml
  341. ON ra.account_id = ml.account_id
  342. """
  343. if not only_empty_partner_line:
  344. sub_query += """
  345. AND rp.partner_id = ml.partner_id
  346. """
  347. elif only_empty_partner_line:
  348. sub_query += """
  349. AND ml.partner_id IS NULL
  350. """
  351. if not positive_balance:
  352. sub_query += """
  353. LEFT JOIN
  354. account_partial_reconcile pr
  355. ON ml.balance < 0 AND pr.credit_move_id = ml.id
  356. LEFT JOIN
  357. account_move_line ml_future
  358. ON ml.balance < 0 AND pr.debit_move_id = ml_future.id
  359. AND ml_future.date >= %s
  360. LEFT JOIN
  361. account_move_line ml_past
  362. ON ml.balance < 0 AND pr.debit_move_id = ml_past.id
  363. AND ml_past.date < %s
  364. """
  365. else:
  366. sub_query += """
  367. LEFT JOIN
  368. account_partial_reconcile pr
  369. ON ml.balance > 0 AND pr.debit_move_id = ml.id
  370. LEFT JOIN
  371. account_move_line ml_future
  372. ON ml.balance > 0 AND pr.credit_move_id = ml_future.id
  373. AND ml_future.date >= %s
  374. LEFT JOIN
  375. account_move_line ml_past
  376. ON ml.balance > 0 AND pr.credit_move_id = ml_past.id
  377. AND ml_past.date < %s
  378. """
  379. sub_query += """
  380. WHERE
  381. ra.report_id = %s
  382. GROUP BY
  383. ml.id,
  384. ml.balance,
  385. ml.amount_currency
  386. HAVING
  387. (
  388. ml.full_reconcile_id IS NULL
  389. OR MAX(ml_future.id) IS NOT NULL
  390. )
  391. """
  392. return sub_query
  393. def _inject_line_values(self, only_empty_partner_line=False):
  394. """ Inject report values for report_open_items_qweb_move_line.
  395. The "only_empty_partner_line" value is used
  396. to compute data without partner.
  397. """
  398. query_inject_move_line = """
  399. WITH
  400. move_lines_amount AS
  401. (
  402. """
  403. query_inject_move_line += self._get_line_sub_query_move_lines(
  404. only_empty_partner_line=only_empty_partner_line,
  405. positive_balance=True
  406. )
  407. query_inject_move_line += """
  408. UNION
  409. """
  410. query_inject_move_line += self._get_line_sub_query_move_lines(
  411. only_empty_partner_line=only_empty_partner_line,
  412. positive_balance=False
  413. )
  414. query_inject_move_line += """
  415. ),
  416. move_lines AS
  417. (
  418. SELECT
  419. id,
  420. CASE
  421. WHEN SUM(partial_amount) > 0
  422. THEN
  423. CASE
  424. WHEN balance > 0
  425. THEN balance - SUM(partial_amount)
  426. ELSE balance + SUM(partial_amount)
  427. END
  428. ELSE balance
  429. END AS amount_residual,
  430. CASE
  431. WHEN SUM(partial_amount_currency) > 0
  432. THEN
  433. CASE
  434. WHEN amount_currency > 0
  435. THEN amount_currency - SUM(partial_amount_currency)
  436. ELSE amount_currency + SUM(partial_amount_currency)
  437. END
  438. ELSE amount_currency
  439. END AS amount_residual_currency
  440. FROM
  441. move_lines_amount
  442. GROUP BY
  443. id,
  444. balance,
  445. amount_currency
  446. )
  447. INSERT INTO
  448. report_open_items_qweb_move_line
  449. (
  450. report_partner_id,
  451. create_uid,
  452. create_date,
  453. move_line_id,
  454. date,
  455. date_due,
  456. entry,
  457. journal,
  458. account,
  459. partner,
  460. label,
  461. amount_total_due,
  462. amount_residual,
  463. currency_name,
  464. amount_total_due_currency,
  465. amount_residual_currency
  466. )
  467. SELECT
  468. rp.id AS report_partner_id,
  469. %s AS create_uid,
  470. NOW() AS create_date,
  471. ml.id AS move_line_id,
  472. ml.date,
  473. ml.date_maturity,
  474. m.name AS entry,
  475. j.code AS journal,
  476. a.code AS account,
  477. """
  478. if not only_empty_partner_line:
  479. query_inject_move_line += """
  480. CASE
  481. WHEN
  482. NULLIF(p.name, '') IS NOT NULL
  483. AND NULLIF(p.ref, '') IS NOT NULL
  484. THEN p.name || ' (' || p.ref || ')'
  485. ELSE p.name
  486. END AS partner,
  487. """
  488. elif only_empty_partner_line:
  489. query_inject_move_line += """
  490. '""" + _('No partner allocated') + """' AS partner,
  491. """
  492. query_inject_move_line += """
  493. CONCAT_WS(' - ', NULLIF(ml.ref, ''), NULLIF(ml.name, '')) AS label,
  494. ml.balance,
  495. ml2.amount_residual,
  496. c.name AS currency_name,
  497. ml.amount_currency,
  498. ml2.amount_residual_currency
  499. FROM
  500. report_open_items_qweb_partner rp
  501. INNER JOIN
  502. report_open_items_qweb_account ra ON rp.report_account_id = ra.id
  503. INNER JOIN
  504. account_move_line ml ON ra.account_id = ml.account_id
  505. INNER JOIN
  506. move_lines ml2
  507. ON ml.id = ml2.id
  508. AND ml2.amount_residual IS NOT NULL
  509. AND ml2.amount_residual != 0
  510. INNER JOIN
  511. account_move m ON ml.move_id = m.id
  512. INNER JOIN
  513. account_journal j ON ml.journal_id = j.id
  514. INNER JOIN
  515. account_account a ON ml.account_id = a.id
  516. """
  517. if not only_empty_partner_line:
  518. query_inject_move_line += """
  519. INNER JOIN
  520. res_partner p
  521. ON ml.partner_id = p.id AND rp.partner_id = p.id
  522. """
  523. query_inject_move_line += """
  524. LEFT JOIN
  525. account_full_reconcile fr ON ml.full_reconcile_id = fr.id
  526. LEFT JOIN
  527. res_currency c ON a.currency_id = c.id
  528. WHERE
  529. ra.report_id = %s
  530. AND
  531. ml.date <= %s
  532. """
  533. if self.only_posted_moves:
  534. query_inject_move_line += """
  535. AND
  536. m.state = 'posted'
  537. """
  538. if only_empty_partner_line:
  539. query_inject_move_line += """
  540. AND
  541. ml.partner_id IS NULL
  542. AND
  543. rp.partner_id IS NULL
  544. """
  545. if not only_empty_partner_line:
  546. query_inject_move_line += """
  547. ORDER BY
  548. a.code, p.name, ml.date, ml.id
  549. """
  550. elif only_empty_partner_line:
  551. query_inject_move_line += """
  552. ORDER BY
  553. a.code, ml.date, ml.id
  554. """
  555. self.env.cr.execute(
  556. query_inject_move_line,
  557. (self.date_at,
  558. self.date_at,
  559. self.id,
  560. self.date_at,
  561. self.date_at,
  562. self.id,
  563. self.env.uid,
  564. self.id,
  565. self.date_at,)
  566. )
  567. def _compute_partners_and_accounts_cumul(self):
  568. """ Compute cumulative amount for
  569. report_open_items_qweb_partner and report_open_items_qweb_account.
  570. """
  571. query_compute_partners_cumul = """
  572. UPDATE
  573. report_open_items_qweb_partner
  574. SET
  575. final_amount_residual =
  576. (
  577. SELECT
  578. SUM(rml.amount_residual) AS final_amount_residual
  579. FROM
  580. report_open_items_qweb_move_line rml
  581. WHERE
  582. rml.report_partner_id = report_open_items_qweb_partner.id
  583. )
  584. WHERE
  585. id IN
  586. (
  587. SELECT
  588. rp.id
  589. FROM
  590. report_open_items_qweb_account ra
  591. INNER JOIN
  592. report_open_items_qweb_partner rp
  593. ON ra.id = rp.report_account_id
  594. WHERE
  595. ra.report_id = %s
  596. )
  597. """
  598. params_compute_partners_cumul = (self.id,)
  599. self.env.cr.execute(query_compute_partners_cumul,
  600. params_compute_partners_cumul)
  601. query_compute_accounts_cumul = """
  602. UPDATE
  603. report_open_items_qweb_account
  604. SET
  605. final_amount_residual =
  606. (
  607. SELECT
  608. SUM(rp.final_amount_residual) AS final_amount_residual
  609. FROM
  610. report_open_items_qweb_partner rp
  611. WHERE
  612. rp.report_account_id = report_open_items_qweb_account.id
  613. )
  614. WHERE
  615. report_id = %s
  616. """
  617. params_compute_accounts_cumul = (self.id,)
  618. self.env.cr.execute(query_compute_accounts_cumul,
  619. params_compute_accounts_cumul)
  620. def _clean_partners_and_accounts(self,
  621. only_delete_account_balance_at_0=False):
  622. """ Delete empty data for
  623. report_open_items_qweb_partner and report_open_items_qweb_account.
  624. The "only_delete_account_balance_at_0" value is used
  625. to delete also the data with cumulative amounts at 0.
  626. """
  627. query_clean_partners = """
  628. DELETE FROM
  629. report_open_items_qweb_partner
  630. WHERE
  631. id IN
  632. (
  633. SELECT
  634. DISTINCT rp.id
  635. FROM
  636. report_open_items_qweb_account ra
  637. INNER JOIN
  638. report_open_items_qweb_partner rp
  639. ON ra.id = rp.report_account_id
  640. LEFT JOIN
  641. report_open_items_qweb_move_line rml
  642. ON rp.id = rml.report_partner_id
  643. WHERE
  644. ra.report_id = %s
  645. """
  646. if not only_delete_account_balance_at_0:
  647. query_clean_partners += """
  648. AND rml.id IS NULL
  649. """
  650. elif only_delete_account_balance_at_0:
  651. query_clean_partners += """
  652. AND (
  653. rp.final_amount_residual IS NULL
  654. OR rp.final_amount_residual = 0
  655. )
  656. """
  657. query_clean_partners += """
  658. )
  659. """
  660. params_clean_partners = (self.id,)
  661. self.env.cr.execute(query_clean_partners, params_clean_partners)
  662. query_clean_accounts = """
  663. DELETE FROM
  664. report_open_items_qweb_account
  665. WHERE
  666. id IN
  667. (
  668. SELECT
  669. DISTINCT ra.id
  670. FROM
  671. report_open_items_qweb_account ra
  672. LEFT JOIN
  673. report_open_items_qweb_partner rp
  674. ON ra.id = rp.report_account_id
  675. WHERE
  676. ra.report_id = %s
  677. """
  678. if not only_delete_account_balance_at_0:
  679. query_clean_accounts += """
  680. AND rp.id IS NULL
  681. """
  682. elif only_delete_account_balance_at_0:
  683. query_clean_accounts += """
  684. AND (
  685. ra.final_amount_residual IS NULL
  686. OR ra.final_amount_residual = 0
  687. )
  688. """
  689. query_clean_accounts += """
  690. )
  691. """
  692. params_clean_accounts = (self.id,)
  693. self.env.cr.execute(query_clean_accounts, params_clean_accounts)
  694. def _compute_has_second_currency(self):
  695. """ Compute "has_second_currency" flag which will used for display."""
  696. query_update_has_second_currency = """
  697. UPDATE
  698. report_open_items_qweb
  699. SET
  700. has_second_currency =
  701. (
  702. SELECT
  703. TRUE
  704. FROM
  705. report_open_items_qweb_move_line l
  706. INNER JOIN
  707. report_open_items_qweb_partner p
  708. ON l.report_partner_id = p.id
  709. INNER JOIN
  710. report_open_items_qweb_account a
  711. ON p.report_account_id = a.id
  712. WHERE
  713. a.report_id = %s
  714. AND l.currency_name IS NOT NULL
  715. LIMIT 1
  716. )
  717. WHERE id = %s
  718. """
  719. params = (self.id,) * 2
  720. self.env.cr.execute(query_update_has_second_currency, params)