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.

724 lines
21 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. 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 _inject_line_values(self, only_empty_partner_line=False):
  306. """ Inject report values for report_open_items_qweb_move_line.
  307. The "only_empty_partner_line" value is used
  308. to compute data without partner.
  309. """
  310. query_inject_move_line = """
  311. WITH
  312. move_lines_amount AS
  313. (
  314. SELECT
  315. ml.id,
  316. ml.balance,
  317. SUM(
  318. CASE
  319. WHEN ml_past.id IS NOT NULL
  320. THEN pr.amount
  321. ELSE NULL
  322. END
  323. ) AS partial_amount,
  324. ml.amount_currency,
  325. SUM(
  326. CASE
  327. WHEN ml_past.id IS NOT NULL
  328. THEN pr.amount_currency
  329. ELSE NULL
  330. END
  331. ) AS partial_amount_currency
  332. FROM
  333. report_open_items_qweb_partner rp
  334. INNER JOIN
  335. report_open_items_qweb_account ra
  336. ON rp.report_account_id = ra.id
  337. INNER JOIN
  338. account_move_line ml
  339. ON ra.account_id = ml.account_id
  340. """
  341. if not only_empty_partner_line:
  342. query_inject_move_line += """
  343. AND rp.partner_id = ml.partner_id
  344. """
  345. elif only_empty_partner_line:
  346. query_inject_move_line += """
  347. AND ml.partner_id IS NULL
  348. """
  349. query_inject_move_line += """
  350. LEFT JOIN
  351. account_partial_reconcile pr
  352. ON ml.balance < 0 AND pr.credit_move_id = ml.id
  353. OR ml.balance > 0 AND pr.debit_move_id = ml.id
  354. LEFT JOIN
  355. account_move_line ml_future
  356. ON (
  357. ml.balance < 0 AND pr.debit_move_id = ml_future.id
  358. OR ml.balance > 0 AND pr.credit_move_id = ml_future.id
  359. )
  360. AND ml_future.date >= %s
  361. LEFT JOIN
  362. account_move_line ml_past
  363. ON (
  364. ml.balance < 0 AND pr.debit_move_id = ml_past.id
  365. OR ml.balance > 0 AND pr.credit_move_id = ml_past.id
  366. )
  367. AND ml_past.date < %s
  368. WHERE
  369. ra.report_id = %s
  370. GROUP BY
  371. ml.id,
  372. ml.balance,
  373. ml.amount_currency
  374. HAVING
  375. (
  376. ml.full_reconcile_id IS NULL
  377. OR MAX(ml_future.id) IS NOT NULL
  378. )
  379. ),
  380. move_lines AS
  381. (
  382. SELECT
  383. id,
  384. CASE
  385. WHEN SUM(partial_amount) > 0
  386. THEN
  387. CASE
  388. WHEN balance > 0
  389. THEN balance - SUM(partial_amount)
  390. ELSE balance + SUM(partial_amount)
  391. END
  392. ELSE balance
  393. END AS amount_residual,
  394. CASE
  395. WHEN SUM(partial_amount_currency) > 0
  396. THEN
  397. CASE
  398. WHEN amount_currency > 0
  399. THEN amount_currency - SUM(partial_amount_currency)
  400. ELSE amount_currency + SUM(partial_amount_currency)
  401. END
  402. ELSE amount_currency
  403. END AS amount_residual_currency
  404. FROM
  405. move_lines_amount
  406. GROUP BY
  407. id,
  408. balance,
  409. amount_currency
  410. )
  411. INSERT INTO
  412. report_open_items_qweb_move_line
  413. (
  414. report_partner_id,
  415. create_uid,
  416. create_date,
  417. move_line_id,
  418. date,
  419. date_due,
  420. entry,
  421. journal,
  422. account,
  423. partner,
  424. label,
  425. amount_total_due,
  426. amount_residual,
  427. currency_name,
  428. amount_total_due_currency,
  429. amount_residual_currency
  430. )
  431. SELECT
  432. rp.id AS report_partner_id,
  433. %s AS create_uid,
  434. NOW() AS create_date,
  435. ml.id AS move_line_id,
  436. ml.date,
  437. ml.date_maturity,
  438. m.name AS entry,
  439. j.code AS journal,
  440. a.code AS account,
  441. """
  442. if not only_empty_partner_line:
  443. query_inject_move_line += """
  444. CASE
  445. WHEN
  446. NULLIF(p.name, '') IS NOT NULL
  447. AND NULLIF(p.ref, '') IS NOT NULL
  448. THEN p.name || ' (' || p.ref || ')'
  449. ELSE p.name
  450. END AS partner,
  451. """
  452. elif only_empty_partner_line:
  453. query_inject_move_line += """
  454. '""" + _('No partner allocated') + """' AS partner,
  455. """
  456. query_inject_move_line += """
  457. CONCAT_WS(' - ', NULLIF(ml.ref, ''), NULLIF(ml.name, '')) AS label,
  458. ml.balance,
  459. ml2.amount_residual,
  460. c.name AS currency_name,
  461. ml.amount_currency,
  462. ml2.amount_residual_currency
  463. FROM
  464. report_open_items_qweb_partner rp
  465. INNER JOIN
  466. report_open_items_qweb_account ra ON rp.report_account_id = ra.id
  467. INNER JOIN
  468. account_move_line ml ON ra.account_id = ml.account_id
  469. INNER JOIN
  470. move_lines ml2
  471. ON ml.id = ml2.id
  472. AND ml2.amount_residual IS NOT NULL
  473. AND ml2.amount_residual != 0
  474. INNER JOIN
  475. account_move m ON ml.move_id = m.id
  476. INNER JOIN
  477. account_journal j ON ml.journal_id = j.id
  478. INNER JOIN
  479. account_account a ON ml.account_id = a.id
  480. """
  481. if not only_empty_partner_line:
  482. query_inject_move_line += """
  483. INNER JOIN
  484. res_partner p
  485. ON ml.partner_id = p.id AND rp.partner_id = p.id
  486. """
  487. query_inject_move_line += """
  488. LEFT JOIN
  489. account_full_reconcile fr ON ml.full_reconcile_id = fr.id
  490. LEFT JOIN
  491. res_currency c ON a.currency_id = c.id
  492. WHERE
  493. ra.report_id = %s
  494. AND
  495. ml.date <= %s
  496. """
  497. if self.only_posted_moves:
  498. query_inject_move_line += """
  499. AND
  500. m.state = 'posted'
  501. """
  502. if only_empty_partner_line:
  503. query_inject_move_line += """
  504. AND
  505. ml.partner_id IS NULL
  506. AND
  507. rp.partner_id IS NULL
  508. """
  509. if not only_empty_partner_line:
  510. query_inject_move_line += """
  511. ORDER BY
  512. a.code, p.name, ml.date, ml.id
  513. """
  514. elif only_empty_partner_line:
  515. query_inject_move_line += """
  516. ORDER BY
  517. a.code, ml.date, ml.id
  518. """
  519. self.env.cr.execute(
  520. query_inject_move_line,
  521. (self.date_at,
  522. self.date_at,
  523. self.id,
  524. self.env.uid,
  525. self.id,
  526. self.date_at,)
  527. )
  528. def _compute_partners_and_accounts_cumul(self):
  529. """ Compute cumulative amount for
  530. report_open_items_qweb_partner and report_open_items_qweb_account.
  531. """
  532. query_compute_partners_cumul = """
  533. UPDATE
  534. report_open_items_qweb_partner
  535. SET
  536. final_amount_residual =
  537. (
  538. SELECT
  539. SUM(rml.amount_residual) AS final_amount_residual
  540. FROM
  541. report_open_items_qweb_move_line rml
  542. WHERE
  543. rml.report_partner_id = report_open_items_qweb_partner.id
  544. )
  545. WHERE
  546. id IN
  547. (
  548. SELECT
  549. rp.id
  550. FROM
  551. report_open_items_qweb_account ra
  552. INNER JOIN
  553. report_open_items_qweb_partner rp
  554. ON ra.id = rp.report_account_id
  555. WHERE
  556. ra.report_id = %s
  557. )
  558. """
  559. params_compute_partners_cumul = (self.id,)
  560. self.env.cr.execute(query_compute_partners_cumul,
  561. params_compute_partners_cumul)
  562. query_compute_accounts_cumul = """
  563. UPDATE
  564. report_open_items_qweb_account
  565. SET
  566. final_amount_residual =
  567. (
  568. SELECT
  569. SUM(rp.final_amount_residual) AS final_amount_residual
  570. FROM
  571. report_open_items_qweb_partner rp
  572. WHERE
  573. rp.report_account_id = report_open_items_qweb_account.id
  574. )
  575. WHERE
  576. report_id = %s
  577. """
  578. params_compute_accounts_cumul = (self.id,)
  579. self.env.cr.execute(query_compute_accounts_cumul,
  580. params_compute_accounts_cumul)
  581. def _clean_partners_and_accounts(self,
  582. only_delete_account_balance_at_0=False):
  583. """ Delete empty data for
  584. report_open_items_qweb_partner and report_open_items_qweb_account.
  585. The "only_delete_account_balance_at_0" value is used
  586. to delete also the data with cumulative amounts at 0.
  587. """
  588. query_clean_partners = """
  589. DELETE FROM
  590. report_open_items_qweb_partner
  591. WHERE
  592. id IN
  593. (
  594. SELECT
  595. DISTINCT rp.id
  596. FROM
  597. report_open_items_qweb_account ra
  598. INNER JOIN
  599. report_open_items_qweb_partner rp
  600. ON ra.id = rp.report_account_id
  601. LEFT JOIN
  602. report_open_items_qweb_move_line rml
  603. ON rp.id = rml.report_partner_id
  604. WHERE
  605. ra.report_id = %s
  606. """
  607. if not only_delete_account_balance_at_0:
  608. query_clean_partners += """
  609. AND rml.id IS NULL
  610. """
  611. elif only_delete_account_balance_at_0:
  612. query_clean_partners += """
  613. AND (
  614. rp.final_amount_residual IS NULL
  615. OR rp.final_amount_residual = 0
  616. )
  617. """
  618. query_clean_partners += """
  619. )
  620. """
  621. params_clean_partners = (self.id,)
  622. self.env.cr.execute(query_clean_partners, params_clean_partners)
  623. query_clean_accounts = """
  624. DELETE FROM
  625. report_open_items_qweb_account
  626. WHERE
  627. id IN
  628. (
  629. SELECT
  630. DISTINCT ra.id
  631. FROM
  632. report_open_items_qweb_account ra
  633. LEFT JOIN
  634. report_open_items_qweb_partner rp
  635. ON ra.id = rp.report_account_id
  636. WHERE
  637. ra.report_id = %s
  638. """
  639. if not only_delete_account_balance_at_0:
  640. query_clean_accounts += """
  641. AND rp.id IS NULL
  642. """
  643. elif only_delete_account_balance_at_0:
  644. query_clean_accounts += """
  645. AND (
  646. ra.final_amount_residual IS NULL
  647. OR ra.final_amount_residual = 0
  648. )
  649. """
  650. query_clean_accounts += """
  651. )
  652. """
  653. params_clean_accounts = (self.id,)
  654. self.env.cr.execute(query_clean_accounts, params_clean_accounts)
  655. def _compute_has_second_currency(self):
  656. """ Compute "has_second_currency" flag which will used for display."""
  657. query_update_has_second_currency = """
  658. UPDATE
  659. report_open_items_qweb
  660. SET
  661. has_second_currency =
  662. (
  663. SELECT
  664. TRUE
  665. FROM
  666. report_open_items_qweb_move_line l
  667. INNER JOIN
  668. report_open_items_qweb_partner p
  669. ON l.report_partner_id = p.id
  670. INNER JOIN
  671. report_open_items_qweb_account a
  672. ON p.report_account_id = a.id
  673. WHERE
  674. a.report_id = %s
  675. AND l.currency_name IS NOT NULL
  676. LIMIT 1
  677. )
  678. WHERE id = %s
  679. """
  680. params = (self.id,) * 2
  681. self.env.cr.execute(query_update_has_second_currency, params)