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.

1405 lines
43 KiB

8 years ago
8 years ago
  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 GeneralLedgerReport(models.TransientModel):
  6. """ Here, we just define class fields.
  7. For methods, go more bottom at this file.
  8. The class hierarchy is :
  9. * GeneralLedgerReport
  10. ** GeneralLedgerReportAccount
  11. *** GeneralLedgerReportMoveLine
  12. For non receivable/payable accounts
  13. For receivable/payable centralized accounts
  14. *** GeneralLedgerReportPartner
  15. For receivable/payable and not centralized accounts
  16. **** GeneralLedgerReportMoveLine
  17. For receivable/payable and not centralized accounts
  18. """
  19. _name = 'report_general_ledger_qweb'
  20. # Filters fields, used for data computation
  21. date_from = fields.Date()
  22. date_to = fields.Date()
  23. fy_start_date = fields.Date()
  24. only_posted_moves = fields.Boolean()
  25. hide_account_balance_at_0 = fields.Boolean()
  26. company_id = fields.Many2one(comodel_name='res.company')
  27. filter_account_ids = fields.Many2many(comodel_name='account.account')
  28. filter_partner_ids = fields.Many2many(comodel_name='res.partner')
  29. filter_cost_center_ids = fields.Many2many(
  30. comodel_name='account.analytic.account'
  31. )
  32. centralize = fields.Boolean()
  33. # Flag fields, used for report display
  34. has_second_currency = fields.Boolean()
  35. show_cost_center = fields.Boolean(
  36. default=lambda self: self.env.user.has_group(
  37. 'analytic.group_analytic_accounting'
  38. )
  39. )
  40. # Data fields, used to browse report data
  41. account_ids = fields.One2many(
  42. comodel_name='report_general_ledger_qweb_account',
  43. inverse_name='report_id'
  44. )
  45. # Compute of unaffected earnings account
  46. @api.depends('company_id')
  47. def _compute_unaffected_earnings_account(self):
  48. account_type = self.env.ref('account.data_unaffected_earnings')
  49. self.unaffected_earnings_account = self.env['account.account'].search(
  50. [
  51. ('user_type_id', '=', account_type.id),
  52. ('company_id', '=', self.company_id.id)
  53. ])
  54. unaffected_earnings_account = fields.Many2one(
  55. comodel_name='account.account',
  56. compute='_compute_unaffected_earnings_account',
  57. store=True
  58. )
  59. class GeneralLedgerReportAccount(models.TransientModel):
  60. _name = 'report_general_ledger_qweb_account'
  61. _order = 'code ASC'
  62. report_id = fields.Many2one(
  63. comodel_name='report_general_ledger_qweb',
  64. ondelete='cascade',
  65. index=True
  66. )
  67. # Data fields, used to keep link with real object
  68. account_id = fields.Many2one(
  69. 'account.account',
  70. index=True
  71. )
  72. # Data fields, used for report display
  73. code = fields.Char()
  74. name = fields.Char()
  75. initial_debit = fields.Float(digits=(16, 2))
  76. initial_credit = fields.Float(digits=(16, 2))
  77. initial_balance = fields.Float(digits=(16, 2))
  78. final_debit = fields.Float(digits=(16, 2))
  79. final_credit = fields.Float(digits=(16, 2))
  80. final_balance = fields.Float(digits=(16, 2))
  81. # Flag fields, used for report display and for data computation
  82. is_partner_account = fields.Boolean()
  83. # Data fields, used to browse report data
  84. move_line_ids = fields.One2many(
  85. comodel_name='report_general_ledger_qweb_move_line',
  86. inverse_name='report_account_id'
  87. )
  88. partner_ids = fields.One2many(
  89. comodel_name='report_general_ledger_qweb_partner',
  90. inverse_name='report_account_id'
  91. )
  92. class GeneralLedgerReportPartner(models.TransientModel):
  93. _name = 'report_general_ledger_qweb_partner'
  94. report_account_id = fields.Many2one(
  95. comodel_name='report_general_ledger_qweb_account',
  96. ondelete='cascade',
  97. index=True
  98. )
  99. # Data fields, used to keep link with real object
  100. partner_id = fields.Many2one(
  101. 'res.partner',
  102. index=True
  103. )
  104. # Data fields, used for report display
  105. name = fields.Char()
  106. initial_debit = fields.Float(digits=(16, 2))
  107. initial_credit = fields.Float(digits=(16, 2))
  108. initial_balance = fields.Float(digits=(16, 2))
  109. final_debit = fields.Float(digits=(16, 2))
  110. final_credit = fields.Float(digits=(16, 2))
  111. final_balance = fields.Float(digits=(16, 2))
  112. # Data fields, used to browse report data
  113. move_line_ids = fields.One2many(
  114. comodel_name='report_general_ledger_qweb_move_line',
  115. inverse_name='report_partner_id'
  116. )
  117. @api.model
  118. def _generate_order_by(self, order_spec, query):
  119. """Custom order to display "No partner allocated" at last position."""
  120. return """
  121. ORDER BY
  122. CASE
  123. WHEN "report_general_ledger_qweb_partner"."partner_id" IS NOT NULL
  124. THEN 0
  125. ELSE 1
  126. END,
  127. "report_general_ledger_qweb_partner"."name"
  128. """
  129. class GeneralLedgerReportMoveLine(models.TransientModel):
  130. _name = 'report_general_ledger_qweb_move_line'
  131. report_account_id = fields.Many2one(
  132. comodel_name='report_general_ledger_qweb_account',
  133. ondelete='cascade',
  134. index=True
  135. )
  136. report_partner_id = fields.Many2one(
  137. comodel_name='report_general_ledger_qweb_partner',
  138. ondelete='cascade',
  139. index=True
  140. )
  141. # Data fields, used to keep link with real object
  142. move_line_id = fields.Many2one('account.move.line')
  143. # Data fields, used for report display
  144. date = fields.Date()
  145. entry = fields.Char()
  146. journal = fields.Char()
  147. account = fields.Char()
  148. partner = fields.Char()
  149. label = fields.Char()
  150. cost_center = fields.Char()
  151. matching_number = fields.Char()
  152. debit = fields.Float(digits=(16, 2))
  153. credit = fields.Float(digits=(16, 2))
  154. cumul_balance = fields.Float(digits=(16, 2))
  155. currency_name = fields.Char()
  156. amount_currency = fields.Float(digits=(16, 2))
  157. class GeneralLedgerReportCompute(models.TransientModel):
  158. """ Here, we just define methods.
  159. For class fields, go more top at this file.
  160. """
  161. _inherit = 'report_general_ledger_qweb'
  162. @api.multi
  163. def print_report(self, xlsx_report=False):
  164. self.ensure_one()
  165. self.compute_data_for_report()
  166. if xlsx_report:
  167. report_name = 'account_financial_report_qweb.' \
  168. 'report_general_ledger_xlsx'
  169. else:
  170. report_name = 'account_financial_report_qweb.' \
  171. 'report_general_ledger_qweb'
  172. return self.env['report'].get_action(docids=self.ids,
  173. report_name=report_name)
  174. @api.multi
  175. def compute_data_for_report(self,
  176. with_line_details=True,
  177. with_partners=True
  178. ):
  179. self.ensure_one()
  180. # Compute report data
  181. self._inject_account_values()
  182. if with_partners:
  183. self._inject_partner_values()
  184. if not self.filter_partner_ids:
  185. self._inject_partner_values(only_empty_partner=True)
  186. # Add unaffected earnings account
  187. if (not self.filter_account_ids or
  188. self.unaffected_earnings_account.id in
  189. self.filter_account_ids.ids):
  190. self._inject_unaffected_earnings_account_values()
  191. # Call this function even if we don't want line details because,
  192. # we need to compute
  193. # at least the values for unaffected earnings account
  194. # In this case, only unaffected earnings account values are computed
  195. only_unaffected_earnings_account = not with_line_details
  196. self._inject_line_not_centralized_values(
  197. only_unaffected_earnings_account=only_unaffected_earnings_account
  198. )
  199. if with_line_details:
  200. self._inject_line_not_centralized_values(
  201. is_account_line=False,
  202. is_partner_line=True)
  203. self._inject_line_not_centralized_values(
  204. is_account_line=False,
  205. is_partner_line=True,
  206. only_empty_partner_line=True)
  207. if self.centralize:
  208. self._inject_line_centralized_values()
  209. # Complete unaffected earnings account
  210. if (not self.filter_account_ids or
  211. self.unaffected_earnings_account.id in
  212. self.filter_account_ids.ids):
  213. self._complete_unaffected_earnings_account_values()
  214. if with_line_details:
  215. # Compute display flag
  216. self._compute_has_second_currency()
  217. # Refresh cache because all data are computed with SQL requests
  218. self.refresh()
  219. def _get_account_sub_subquery_sum_amounts(
  220. self, include_initial_balance, date_included):
  221. """ Return subquery used to compute sum amounts on accounts """
  222. sub_subquery_sum_amounts = """
  223. SELECT
  224. a.id AS account_id,
  225. SUM(ml.debit) AS debit,
  226. SUM(ml.credit) AS credit,
  227. SUM(ml.balance) AS balance
  228. FROM
  229. accounts a
  230. INNER JOIN
  231. account_account_type at ON a.user_type_id = at.id
  232. INNER JOIN
  233. account_move_line ml
  234. ON a.id = ml.account_id
  235. """
  236. if date_included:
  237. sub_subquery_sum_amounts += """
  238. AND ml.date <= %s
  239. """
  240. else:
  241. sub_subquery_sum_amounts += """
  242. AND ml.date < %s
  243. """
  244. if not include_initial_balance:
  245. sub_subquery_sum_amounts += """
  246. AND at.include_initial_balance != TRUE AND ml.date >= %s
  247. """
  248. else:
  249. sub_subquery_sum_amounts += """
  250. AND at.include_initial_balance = TRUE
  251. """
  252. if self.only_posted_moves:
  253. sub_subquery_sum_amounts += """
  254. INNER JOIN
  255. account_move m ON ml.move_id = m.id AND m.state = 'posted'
  256. """
  257. if self.filter_cost_center_ids:
  258. sub_subquery_sum_amounts += """
  259. INNER JOIN
  260. account_analytic_account aa
  261. ON
  262. ml.analytic_account_id = aa.id
  263. AND aa.id IN %s
  264. """
  265. sub_subquery_sum_amounts += """
  266. GROUP BY
  267. a.id
  268. """
  269. return sub_subquery_sum_amounts
  270. def _get_final_account_sub_subquery_sum_amounts(self, date_included):
  271. """ Return final subquery used to compute sum amounts on accounts """
  272. subquery_sum_amounts = """
  273. SELECT
  274. sub.account_id AS account_id,
  275. SUM(COALESCE(sub.debit, 0.0)) AS debit,
  276. SUM(COALESCE(sub.credit, 0.0)) AS credit,
  277. SUM(COALESCE(sub.balance, 0.0)) AS balance
  278. FROM
  279. (
  280. """
  281. subquery_sum_amounts += self._get_account_sub_subquery_sum_amounts(
  282. include_initial_balance=False, date_included=date_included
  283. )
  284. subquery_sum_amounts += """
  285. UNION
  286. """
  287. subquery_sum_amounts += self._get_account_sub_subquery_sum_amounts(
  288. include_initial_balance=True, date_included=date_included
  289. )
  290. subquery_sum_amounts += """
  291. ) sub
  292. GROUP BY
  293. sub.account_id
  294. """
  295. return subquery_sum_amounts
  296. def _inject_account_values(self):
  297. """Inject report values for report_general_ledger_qweb_account."""
  298. query_inject_account = """
  299. WITH
  300. accounts AS
  301. (
  302. SELECT
  303. a.id,
  304. a.code,
  305. a.name,
  306. a.internal_type IN ('payable', 'receivable')
  307. AS is_partner_account,
  308. a.user_type_id
  309. FROM
  310. account_account a
  311. """
  312. if self.filter_partner_ids or self.filter_cost_center_ids:
  313. query_inject_account += """
  314. INNER JOIN
  315. account_move_line ml ON a.id = ml.account_id
  316. """
  317. if self.filter_partner_ids:
  318. query_inject_account += """
  319. INNER JOIN
  320. res_partner p ON ml.partner_id = p.id
  321. """
  322. if self.filter_cost_center_ids:
  323. query_inject_account += """
  324. INNER JOIN
  325. account_analytic_account aa
  326. ON
  327. ml.analytic_account_id = aa.id
  328. AND aa.id IN %s
  329. """
  330. query_inject_account += """
  331. WHERE
  332. a.company_id = %s
  333. AND a.id != %s
  334. """
  335. if self.filter_account_ids:
  336. query_inject_account += """
  337. AND
  338. a.id IN %s
  339. """
  340. if self.filter_partner_ids:
  341. query_inject_account += """
  342. AND
  343. p.id IN %s
  344. """
  345. if self.filter_partner_ids or self.filter_cost_center_ids:
  346. query_inject_account += """
  347. GROUP BY
  348. a.id
  349. """
  350. init_subquery = self._get_final_account_sub_subquery_sum_amounts(
  351. date_included=False
  352. )
  353. final_subquery = self._get_final_account_sub_subquery_sum_amounts(
  354. date_included=True
  355. )
  356. query_inject_account += """
  357. ),
  358. initial_sum_amounts AS ( """ + init_subquery + """ ),
  359. final_sum_amounts AS ( """ + final_subquery + """ )
  360. INSERT INTO
  361. report_general_ledger_qweb_account
  362. (
  363. report_id,
  364. create_uid,
  365. create_date,
  366. account_id,
  367. code,
  368. name,
  369. initial_debit,
  370. initial_credit,
  371. initial_balance,
  372. final_debit,
  373. final_credit,
  374. final_balance,
  375. is_partner_account
  376. )
  377. SELECT
  378. %s AS report_id,
  379. %s AS create_uid,
  380. NOW() AS create_date,
  381. a.id AS account_id,
  382. a.code,
  383. a.name,
  384. COALESCE(i.debit, 0.0) AS initial_debit,
  385. COALESCE(i.credit, 0.0) AS initial_credit,
  386. COALESCE(i.balance, 0.0) AS initial_balance,
  387. COALESCE(f.debit, 0.0) AS final_debit,
  388. COALESCE(f.credit, 0.0) AS final_credit,
  389. COALESCE(f.balance, 0.0) AS final_balance,
  390. a.is_partner_account
  391. FROM
  392. accounts a
  393. LEFT JOIN
  394. initial_sum_amounts i ON a.id = i.account_id
  395. LEFT JOIN
  396. final_sum_amounts f ON a.id = f.account_id
  397. WHERE
  398. (
  399. i.debit IS NOT NULL AND i.debit != 0
  400. OR i.credit IS NOT NULL AND i.credit != 0
  401. OR i.balance IS NOT NULL AND i.balance != 0
  402. OR f.debit IS NOT NULL AND f.debit != 0
  403. OR f.credit IS NOT NULL AND f.credit != 0
  404. OR f.balance IS NOT NULL AND f.balance != 0
  405. )
  406. """
  407. if self.hide_account_balance_at_0:
  408. query_inject_account += """
  409. AND
  410. f.balance IS NOT NULL AND f.balance != 0
  411. """
  412. query_inject_account_params = ()
  413. if self.filter_cost_center_ids:
  414. query_inject_account_params += (
  415. tuple(self.filter_cost_center_ids.ids),
  416. )
  417. query_inject_account_params += (
  418. self.company_id.id,
  419. self.unaffected_earnings_account.id,
  420. )
  421. if self.filter_account_ids:
  422. query_inject_account_params += (
  423. tuple(self.filter_account_ids.ids),
  424. )
  425. if self.filter_partner_ids:
  426. query_inject_account_params += (
  427. tuple(self.filter_partner_ids.ids),
  428. )
  429. query_inject_account_params += (
  430. self.date_from,
  431. self.fy_start_date,
  432. )
  433. if self.filter_cost_center_ids:
  434. query_inject_account_params += (
  435. tuple(self.filter_cost_center_ids.ids),
  436. )
  437. query_inject_account_params += (
  438. self.date_from,
  439. )
  440. if self.filter_cost_center_ids:
  441. query_inject_account_params += (
  442. tuple(self.filter_cost_center_ids.ids),
  443. )
  444. query_inject_account_params += (
  445. self.date_to,
  446. self.fy_start_date,
  447. )
  448. if self.filter_cost_center_ids:
  449. query_inject_account_params += (
  450. tuple(self.filter_cost_center_ids.ids),
  451. )
  452. query_inject_account_params += (
  453. self.date_to,
  454. )
  455. if self.filter_cost_center_ids:
  456. query_inject_account_params += (
  457. tuple(self.filter_cost_center_ids.ids),
  458. )
  459. query_inject_account_params += (
  460. self.id,
  461. self.env.uid,
  462. )
  463. self.env.cr.execute(query_inject_account, query_inject_account_params)
  464. def _get_partner_sub_subquery_sum_amounts(
  465. self, only_empty_partner, include_initial_balance, date_included
  466. ):
  467. """ Return subquery used to compute sum amounts on partners """
  468. sub_subquery_sum_amounts = """
  469. SELECT
  470. ap.account_id AS account_id,
  471. ap.partner_id AS partner_id,
  472. SUM(ml.debit) AS debit,
  473. SUM(ml.credit) AS credit,
  474. SUM(ml.balance) AS balance
  475. FROM
  476. accounts_partners ap
  477. INNER JOIN
  478. account_move_line ml
  479. ON ap.account_id = ml.account_id
  480. """
  481. if date_included:
  482. sub_subquery_sum_amounts += """
  483. AND ml.date <= %s
  484. """
  485. else:
  486. sub_subquery_sum_amounts += """
  487. AND ml.date < %s
  488. """
  489. if not only_empty_partner:
  490. sub_subquery_sum_amounts += """
  491. AND ap.partner_id = ml.partner_id
  492. """
  493. else:
  494. sub_subquery_sum_amounts += """
  495. AND ap.partner_id IS NULL AND ml.partner_id IS NULL
  496. """
  497. if not include_initial_balance:
  498. sub_subquery_sum_amounts += """
  499. AND ap.include_initial_balance != TRUE AND ml.date >= %s
  500. """
  501. else:
  502. sub_subquery_sum_amounts += """
  503. AND ap.include_initial_balance = TRUE
  504. """
  505. if self.only_posted_moves:
  506. sub_subquery_sum_amounts += """
  507. INNER JOIN
  508. account_move m ON ml.move_id = m.id AND m.state = 'posted'
  509. """
  510. if self.filter_cost_center_ids:
  511. sub_subquery_sum_amounts += """
  512. INNER JOIN
  513. account_analytic_account aa
  514. ON
  515. ml.analytic_account_id = aa.id
  516. AND aa.id IN %s
  517. """
  518. sub_subquery_sum_amounts += """
  519. GROUP BY
  520. ap.account_id, ap.partner_id
  521. """
  522. return sub_subquery_sum_amounts
  523. def _get_final_partner_sub_subquery_sum_amounts(self, only_empty_partner,
  524. date_included):
  525. """Return final subquery used to compute sum amounts on partners"""
  526. subquery_sum_amounts = """
  527. SELECT
  528. sub.account_id AS account_id,
  529. sub.partner_id AS partner_id,
  530. SUM(COALESCE(sub.debit, 0.0)) AS debit,
  531. SUM(COALESCE(sub.credit, 0.0)) AS credit,
  532. SUM(COALESCE(sub.balance, 0.0)) AS balance
  533. FROM
  534. (
  535. """
  536. subquery_sum_amounts += self._get_partner_sub_subquery_sum_amounts(
  537. only_empty_partner,
  538. include_initial_balance=False,
  539. date_included=date_included
  540. )
  541. subquery_sum_amounts += """
  542. UNION
  543. """
  544. subquery_sum_amounts += self._get_partner_sub_subquery_sum_amounts(
  545. only_empty_partner,
  546. include_initial_balance=True,
  547. date_included=date_included
  548. )
  549. subquery_sum_amounts += """
  550. ) sub
  551. GROUP BY
  552. sub.account_id, sub.partner_id
  553. """
  554. return subquery_sum_amounts
  555. def _inject_partner_values(self, only_empty_partner=False):
  556. """ Inject report values for report_general_ledger_qweb_partner.
  557. Only for "partner" accounts (payable and receivable).
  558. """
  559. query_inject_partner = """
  560. WITH
  561. accounts_partners AS
  562. (
  563. SELECT
  564. ra.id AS report_account_id,
  565. a.id AS account_id,
  566. at.include_initial_balance AS include_initial_balance,
  567. p.id AS partner_id,
  568. COALESCE(
  569. CASE
  570. WHEN
  571. NULLIF(p.name, '') IS NOT NULL
  572. AND NULLIF(p.ref, '') IS NOT NULL
  573. THEN p.name || ' (' || p.ref || ')'
  574. ELSE p.name
  575. END,
  576. '""" + _('No partner allocated') + """'
  577. ) AS partner_name
  578. FROM
  579. report_general_ledger_qweb_account ra
  580. INNER JOIN
  581. account_account a ON ra.account_id = a.id
  582. INNER JOIN
  583. account_account_type at ON a.user_type_id = at.id
  584. INNER JOIN
  585. account_move_line ml ON a.id = ml.account_id
  586. LEFT JOIN
  587. res_partner p ON ml.partner_id = p.id
  588. """
  589. if self.filter_cost_center_ids:
  590. query_inject_partner += """
  591. INNER JOIN
  592. account_analytic_account aa
  593. ON
  594. ml.analytic_account_id = aa.id
  595. AND aa.id IN %s
  596. """
  597. query_inject_partner += """
  598. WHERE
  599. ra.report_id = %s
  600. AND
  601. ra.is_partner_account = TRUE
  602. """
  603. if not only_empty_partner:
  604. query_inject_partner += """
  605. AND
  606. p.id IS NOT NULL
  607. """
  608. else:
  609. query_inject_partner += """
  610. AND
  611. p.id IS NULL
  612. """
  613. query_inject_partner += """
  614. """
  615. if self.centralize:
  616. query_inject_partner += """
  617. AND (a.centralized IS NULL OR a.centralized != TRUE)
  618. """
  619. if self.filter_partner_ids:
  620. query_inject_partner += """
  621. AND
  622. p.id IN %s
  623. """
  624. init_subquery = self._get_final_partner_sub_subquery_sum_amounts(
  625. only_empty_partner,
  626. date_included=False
  627. )
  628. final_subquery = self._get_final_partner_sub_subquery_sum_amounts(
  629. only_empty_partner,
  630. date_included=True
  631. )
  632. query_inject_partner += """
  633. GROUP BY
  634. ra.id,
  635. a.id,
  636. p.id,
  637. at.include_initial_balance
  638. ),
  639. initial_sum_amounts AS ( """ + init_subquery + """ ),
  640. final_sum_amounts AS ( """ + final_subquery + """ )
  641. INSERT INTO
  642. report_general_ledger_qweb_partner
  643. (
  644. report_account_id,
  645. create_uid,
  646. create_date,
  647. partner_id,
  648. name,
  649. initial_debit,
  650. initial_credit,
  651. initial_balance,
  652. final_debit,
  653. final_credit,
  654. final_balance
  655. )
  656. SELECT
  657. ap.report_account_id,
  658. %s AS create_uid,
  659. NOW() AS create_date,
  660. ap.partner_id,
  661. ap.partner_name,
  662. COALESCE(i.debit, 0.0) AS initial_debit,
  663. COALESCE(i.credit, 0.0) AS initial_credit,
  664. COALESCE(i.balance, 0.0) AS initial_balance,
  665. COALESCE(f.debit, 0.0) AS final_debit,
  666. COALESCE(f.credit, 0.0) AS final_credit,
  667. COALESCE(f.balance, 0.0) AS final_balance
  668. FROM
  669. accounts_partners ap
  670. LEFT JOIN
  671. initial_sum_amounts i
  672. ON
  673. (
  674. """
  675. if not only_empty_partner:
  676. query_inject_partner += """
  677. ap.partner_id = i.partner_id
  678. """
  679. else:
  680. query_inject_partner += """
  681. ap.partner_id IS NULL AND i.partner_id IS NULL
  682. """
  683. query_inject_partner += """
  684. )
  685. AND ap.account_id = i.account_id
  686. LEFT JOIN
  687. final_sum_amounts f
  688. ON
  689. (
  690. """
  691. if not only_empty_partner:
  692. query_inject_partner += """
  693. ap.partner_id = f.partner_id
  694. """
  695. else:
  696. query_inject_partner += """
  697. ap.partner_id IS NULL AND f.partner_id IS NULL
  698. """
  699. query_inject_partner += """
  700. )
  701. AND ap.account_id = f.account_id
  702. WHERE
  703. (
  704. i.debit IS NOT NULL AND i.debit != 0
  705. OR i.credit IS NOT NULL AND i.credit != 0
  706. OR i.balance IS NOT NULL AND i.balance != 0
  707. OR f.debit IS NOT NULL AND f.debit != 0
  708. OR f.credit IS NOT NULL AND f.credit != 0
  709. OR f.balance IS NOT NULL AND f.balance != 0
  710. )
  711. """
  712. if self.hide_account_balance_at_0:
  713. query_inject_partner += """
  714. AND
  715. f.balance IS NOT NULL AND f.balance != 0
  716. """
  717. query_inject_partner_params = ()
  718. if self.filter_cost_center_ids:
  719. query_inject_partner_params += (
  720. tuple(self.filter_cost_center_ids.ids),
  721. )
  722. query_inject_partner_params += (
  723. self.id,
  724. )
  725. if self.filter_partner_ids:
  726. query_inject_partner_params += (
  727. tuple(self.filter_partner_ids.ids),
  728. )
  729. query_inject_partner_params += (
  730. self.date_from,
  731. self.fy_start_date,
  732. )
  733. if self.filter_cost_center_ids:
  734. query_inject_partner_params += (
  735. tuple(self.filter_cost_center_ids.ids),
  736. )
  737. query_inject_partner_params += (
  738. self.date_from,
  739. )
  740. if self.filter_cost_center_ids:
  741. query_inject_partner_params += (
  742. tuple(self.filter_cost_center_ids.ids),
  743. )
  744. query_inject_partner_params += (
  745. self.date_to,
  746. self.fy_start_date,
  747. )
  748. if self.filter_cost_center_ids:
  749. query_inject_partner_params += (
  750. tuple(self.filter_cost_center_ids.ids),
  751. )
  752. query_inject_partner_params += (
  753. self.date_to,
  754. )
  755. if self.filter_cost_center_ids:
  756. query_inject_partner_params += (
  757. tuple(self.filter_cost_center_ids.ids),
  758. )
  759. query_inject_partner_params += (
  760. self.env.uid,
  761. )
  762. self.env.cr.execute(query_inject_partner, query_inject_partner_params)
  763. def _inject_line_not_centralized_values(
  764. self,
  765. is_account_line=True,
  766. is_partner_line=False,
  767. only_empty_partner_line=False,
  768. only_unaffected_earnings_account=False):
  769. """ Inject report values for report_general_ledger_qweb_move_line.
  770. If centralized option have been chosen,
  771. only non centralized accounts are computed.
  772. In function of `is_account_line` and `is_partner_line` values,
  773. the move_line link is made either with account or either with partner.
  774. The "only_empty_partner_line" value is used
  775. to compute data without partner.
  776. """
  777. query_inject_move_line = """
  778. INSERT INTO
  779. report_general_ledger_qweb_move_line
  780. (
  781. """
  782. if is_account_line:
  783. query_inject_move_line += """
  784. report_account_id,
  785. """
  786. elif is_partner_line:
  787. query_inject_move_line += """
  788. report_partner_id,
  789. """
  790. query_inject_move_line += """
  791. create_uid,
  792. create_date,
  793. move_line_id,
  794. date,
  795. entry,
  796. journal,
  797. account,
  798. partner,
  799. label,
  800. cost_center,
  801. matching_number,
  802. debit,
  803. credit,
  804. cumul_balance,
  805. currency_name,
  806. amount_currency
  807. )
  808. SELECT
  809. """
  810. if is_account_line:
  811. query_inject_move_line += """
  812. ra.id AS report_account_id,
  813. """
  814. elif is_partner_line:
  815. query_inject_move_line += """
  816. rp.id AS report_partner_id,
  817. """
  818. query_inject_move_line += """
  819. %s AS create_uid,
  820. NOW() AS create_date,
  821. ml.id AS move_line_id,
  822. ml.date,
  823. m.name AS entry,
  824. j.code AS journal,
  825. a.code AS account,
  826. """
  827. if not only_empty_partner_line:
  828. query_inject_move_line += """
  829. CASE
  830. WHEN
  831. NULLIF(p.name, '') IS NOT NULL
  832. AND NULLIF(p.ref, '') IS NOT NULL
  833. THEN p.name || ' (' || p.ref || ')'
  834. ELSE p.name
  835. END AS partner,
  836. """
  837. elif only_empty_partner_line:
  838. query_inject_move_line += """
  839. '""" + _('No partner allocated') + """' AS partner,
  840. """
  841. query_inject_move_line += """
  842. CONCAT_WS(' - ', NULLIF(ml.ref, ''), NULLIF(ml.name, '')) AS label,
  843. aa.name AS cost_center,
  844. fr.name AS matching_number,
  845. ml.debit,
  846. ml.credit,
  847. """
  848. if is_account_line:
  849. query_inject_move_line += """
  850. ra.initial_balance + (
  851. SUM(ml.balance)
  852. OVER (PARTITION BY a.code
  853. ORDER BY a.code, ml.date, ml.id)
  854. ) AS cumul_balance,
  855. """
  856. elif is_partner_line and not only_empty_partner_line:
  857. query_inject_move_line += """
  858. rp.initial_balance + (
  859. SUM(ml.balance)
  860. OVER (PARTITION BY a.code, p.name
  861. ORDER BY a.code, p.name, ml.date, ml.id)
  862. ) AS cumul_balance,
  863. """
  864. elif is_partner_line and only_empty_partner_line:
  865. query_inject_move_line += """
  866. rp.initial_balance + (
  867. SUM(ml.balance)
  868. OVER (PARTITION BY a.code
  869. ORDER BY a.code, ml.date, ml.id)
  870. ) AS cumul_balance,
  871. """
  872. query_inject_move_line += """
  873. c.name AS currency_name,
  874. ml.amount_currency
  875. FROM
  876. """
  877. if is_account_line:
  878. query_inject_move_line += """
  879. report_general_ledger_qweb_account ra
  880. """
  881. elif is_partner_line:
  882. query_inject_move_line += """
  883. report_general_ledger_qweb_partner rp
  884. INNER JOIN
  885. report_general_ledger_qweb_account ra ON rp.report_account_id = ra.id
  886. """
  887. query_inject_move_line += """
  888. INNER JOIN
  889. account_move_line ml ON ra.account_id = ml.account_id
  890. INNER JOIN
  891. account_move m ON ml.move_id = m.id
  892. INNER JOIN
  893. account_journal j ON ml.journal_id = j.id
  894. INNER JOIN
  895. account_account a ON ml.account_id = a.id
  896. """
  897. if is_account_line:
  898. query_inject_move_line += """
  899. LEFT JOIN
  900. res_partner p ON ml.partner_id = p.id
  901. """
  902. elif is_partner_line and not only_empty_partner_line:
  903. query_inject_move_line += """
  904. INNER JOIN
  905. res_partner p
  906. ON ml.partner_id = p.id AND rp.partner_id = p.id
  907. """
  908. query_inject_move_line += """
  909. LEFT JOIN
  910. account_full_reconcile fr ON ml.full_reconcile_id = fr.id
  911. LEFT JOIN
  912. res_currency c ON a.currency_id = c.id
  913. """
  914. if self.filter_cost_center_ids:
  915. query_inject_move_line += """
  916. INNER JOIN
  917. account_analytic_account aa
  918. ON
  919. ml.analytic_account_id = aa.id
  920. AND aa.id IN %s
  921. """
  922. else:
  923. query_inject_move_line += """
  924. LEFT JOIN
  925. account_analytic_account aa ON ml.analytic_account_id = aa.id
  926. """
  927. query_inject_move_line += """
  928. WHERE
  929. ra.report_id = %s
  930. AND
  931. """
  932. if only_unaffected_earnings_account:
  933. query_inject_move_line += """
  934. a.id = %s
  935. AND
  936. """
  937. if is_account_line:
  938. query_inject_move_line += """
  939. (ra.is_partner_account IS NULL OR ra.is_partner_account != TRUE)
  940. """
  941. elif is_partner_line:
  942. query_inject_move_line += """
  943. ra.is_partner_account = TRUE
  944. """
  945. if self.centralize:
  946. query_inject_move_line += """
  947. AND
  948. (a.centralized IS NULL OR a.centralized != TRUE)
  949. """
  950. query_inject_move_line += """
  951. AND
  952. ml.date BETWEEN %s AND %s
  953. """
  954. if self.only_posted_moves:
  955. query_inject_move_line += """
  956. AND
  957. m.state = 'posted'
  958. """
  959. if only_empty_partner_line:
  960. query_inject_move_line += """
  961. AND
  962. ml.partner_id IS NULL
  963. AND
  964. rp.partner_id IS NULL
  965. """
  966. if is_account_line:
  967. query_inject_move_line += """
  968. ORDER BY
  969. a.code, ml.date, ml.id
  970. """
  971. elif is_partner_line and not only_empty_partner_line:
  972. query_inject_move_line += """
  973. ORDER BY
  974. a.code, p.name, ml.date, ml.id
  975. """
  976. elif is_partner_line and only_empty_partner_line:
  977. query_inject_move_line += """
  978. ORDER BY
  979. a.code, ml.date, ml.id
  980. """
  981. query_inject_move_line_params = (
  982. self.env.uid,
  983. )
  984. if self.filter_cost_center_ids:
  985. query_inject_move_line_params += (
  986. tuple(self.filter_cost_center_ids.ids),
  987. )
  988. query_inject_move_line_params += (
  989. self.id,
  990. )
  991. if only_unaffected_earnings_account:
  992. query_inject_move_line_params += (
  993. self.unaffected_earnings_account.id,
  994. )
  995. query_inject_move_line_params += (
  996. self.date_from,
  997. self.date_to,
  998. )
  999. self.env.cr.execute(
  1000. query_inject_move_line,
  1001. query_inject_move_line_params
  1002. )
  1003. def _inject_line_centralized_values(self):
  1004. """ Inject report values for report_general_ledger_qweb_move_line.
  1005. Only centralized accounts are computed.
  1006. """
  1007. query_inject_move_line_centralized = """
  1008. WITH
  1009. move_lines AS
  1010. (
  1011. SELECT
  1012. ml.account_id,
  1013. (
  1014. DATE_TRUNC('month', ml.date) + interval '1 month'
  1015. - interval '1 day'
  1016. )::date AS date,
  1017. SUM(ml.debit) AS debit,
  1018. SUM(ml.credit) AS credit,
  1019. SUM(ml.balance) AS balance
  1020. FROM
  1021. report_general_ledger_qweb_account ra
  1022. INNER JOIN
  1023. account_move_line ml ON ra.account_id = ml.account_id
  1024. INNER JOIN
  1025. account_move m ON ml.move_id = m.id
  1026. INNER JOIN
  1027. account_account a ON ml.account_id = a.id
  1028. """
  1029. if self.filter_cost_center_ids:
  1030. query_inject_move_line_centralized += """
  1031. INNER JOIN
  1032. account_analytic_account aa
  1033. ON
  1034. ml.analytic_account_id = aa.id
  1035. AND aa.id IN %s
  1036. """
  1037. query_inject_move_line_centralized += """
  1038. WHERE
  1039. ra.report_id = %s
  1040. AND
  1041. a.centralized = TRUE
  1042. AND
  1043. ml.date BETWEEN %s AND %s
  1044. """
  1045. if self.only_posted_moves:
  1046. query_inject_move_line_centralized += """
  1047. AND
  1048. m.state = 'posted'
  1049. """
  1050. query_inject_move_line_centralized += """
  1051. GROUP BY
  1052. ra.id, ml.account_id, a.code, 2
  1053. )
  1054. INSERT INTO
  1055. report_general_ledger_qweb_move_line
  1056. (
  1057. report_account_id,
  1058. create_uid,
  1059. create_date,
  1060. date,
  1061. account,
  1062. label,
  1063. debit,
  1064. credit,
  1065. cumul_balance
  1066. )
  1067. SELECT
  1068. ra.id AS report_account_id,
  1069. %s AS create_uid,
  1070. NOW() AS create_date,
  1071. ml.date,
  1072. a.code AS account,
  1073. '""" + _('Centralized Entries') + """' AS label,
  1074. ml.debit AS debit,
  1075. ml.credit AS credit,
  1076. ra.initial_balance + (
  1077. SUM(ml.balance)
  1078. OVER (PARTITION BY a.code ORDER BY ml.date)
  1079. ) AS cumul_balance
  1080. FROM
  1081. report_general_ledger_qweb_account ra
  1082. INNER JOIN
  1083. move_lines ml ON ra.account_id = ml.account_id
  1084. INNER JOIN
  1085. account_account a ON ml.account_id = a.id
  1086. LEFT JOIN
  1087. res_currency c ON a.currency_id = c.id
  1088. WHERE
  1089. ra.report_id = %s
  1090. AND
  1091. (a.centralized IS NOT NULL AND a.centralized = TRUE)
  1092. ORDER BY
  1093. a.code, ml.date
  1094. """
  1095. query_inject_move_line_centralized_params = ()
  1096. if self.filter_cost_center_ids:
  1097. query_inject_move_line_centralized_params += (
  1098. tuple(self.filter_cost_center_ids.ids),
  1099. )
  1100. query_inject_move_line_centralized_params += (
  1101. self.id,
  1102. self.date_from,
  1103. self.date_to,
  1104. self.env.uid,
  1105. self.id,
  1106. )
  1107. self.env.cr.execute(
  1108. query_inject_move_line_centralized,
  1109. query_inject_move_line_centralized_params
  1110. )
  1111. def _compute_has_second_currency(self):
  1112. """ Compute "has_second_currency" flag which will used for display."""
  1113. query_update_has_second_currency = """
  1114. UPDATE
  1115. report_general_ledger_qweb
  1116. SET
  1117. has_second_currency =
  1118. (
  1119. SELECT
  1120. TRUE
  1121. FROM
  1122. report_general_ledger_qweb_move_line l
  1123. INNER JOIN
  1124. report_general_ledger_qweb_account a
  1125. ON l.report_account_id = a.id
  1126. WHERE
  1127. a.report_id = %s
  1128. AND l.currency_name IS NOT NULL
  1129. LIMIT 1
  1130. )
  1131. OR
  1132. (
  1133. SELECT
  1134. TRUE
  1135. FROM
  1136. report_general_ledger_qweb_move_line l
  1137. INNER JOIN
  1138. report_general_ledger_qweb_partner p
  1139. ON l.report_partner_id = p.id
  1140. INNER JOIN
  1141. report_general_ledger_qweb_account a
  1142. ON p.report_account_id = a.id
  1143. WHERE
  1144. a.report_id = %s
  1145. AND l.currency_name IS NOT NULL
  1146. LIMIT 1
  1147. )
  1148. WHERE id = %s
  1149. """
  1150. params = (self.id,) * 3
  1151. self.env.cr.execute(query_update_has_second_currency, params)
  1152. def _get_unaffected_earnings_account_sub_subquery_sum_amounts(
  1153. self, include_initial_balance
  1154. ):
  1155. """ Return subquery used to compute sum amounts on
  1156. unaffected earnings accounts """
  1157. sub_subquery_sum_amounts = """
  1158. SELECT
  1159. SUM(ml.balance) AS balance
  1160. FROM
  1161. account_account a
  1162. INNER JOIN
  1163. account_account_type at ON a.user_type_id = at.id
  1164. INNER JOIN
  1165. account_move_line ml
  1166. ON a.id = ml.account_id
  1167. AND ml.date < %s
  1168. """
  1169. if not include_initial_balance:
  1170. sub_subquery_sum_amounts += """
  1171. AND NOT(at.include_initial_balance != TRUE AND ml.date >= %s)
  1172. """
  1173. else:
  1174. sub_subquery_sum_amounts += """
  1175. AND at.include_initial_balance = FALSE
  1176. """
  1177. if self.only_posted_moves:
  1178. sub_subquery_sum_amounts += """
  1179. INNER JOIN
  1180. account_move m ON ml.move_id = m.id AND m.state = 'posted'
  1181. """
  1182. if self.filter_cost_center_ids:
  1183. sub_subquery_sum_amounts += """
  1184. INNER JOIN
  1185. account_analytic_account aa
  1186. ON
  1187. ml.analytic_account_id = aa.id
  1188. AND aa.id IN %s
  1189. """
  1190. sub_subquery_sum_amounts += """
  1191. WHERE
  1192. a.company_id =%s
  1193. AND a.id != %s
  1194. """
  1195. return sub_subquery_sum_amounts
  1196. def _inject_unaffected_earnings_account_values(self):
  1197. """Inject the report values of the unaffected earnings account
  1198. for report_general_ledger_qweb_account."""
  1199. subquery_sum_amounts = """
  1200. SELECT
  1201. SUM(COALESCE(sub.balance, 0.0)) AS balance
  1202. FROM
  1203. (
  1204. """
  1205. subquery_sum_amounts += \
  1206. self._get_unaffected_earnings_account_sub_subquery_sum_amounts(
  1207. include_initial_balance=False
  1208. )
  1209. subquery_sum_amounts += """
  1210. UNION
  1211. """
  1212. subquery_sum_amounts += \
  1213. self._get_unaffected_earnings_account_sub_subquery_sum_amounts(
  1214. include_initial_balance=True
  1215. )
  1216. subquery_sum_amounts += """
  1217. ) sub
  1218. """
  1219. query_inject_account = """
  1220. WITH
  1221. initial_sum_amounts AS ( """ + subquery_sum_amounts + """ )
  1222. INSERT INTO
  1223. report_general_ledger_qweb_account
  1224. (
  1225. report_id,
  1226. create_uid,
  1227. create_date,
  1228. account_id,
  1229. code,
  1230. name,
  1231. is_partner_account,
  1232. initial_balance
  1233. )
  1234. SELECT
  1235. %s AS report_id,
  1236. %s AS create_uid,
  1237. NOW() AS create_date,
  1238. a.id AS account_id,
  1239. a.code,
  1240. a.name,
  1241. False AS is_partner_account,
  1242. COALESCE(i.balance, 0.0) AS initial_balance
  1243. FROM
  1244. account_account a,
  1245. initial_sum_amounts i
  1246. WHERE
  1247. a.company_id = %s
  1248. AND a.id = %s
  1249. """
  1250. query_inject_account_params = (
  1251. self.date_from,
  1252. self.fy_start_date,
  1253. )
  1254. if self.filter_cost_center_ids:
  1255. query_inject_account_params += (
  1256. tuple(self.filter_cost_center_ids.ids),
  1257. )
  1258. query_inject_account_params += (
  1259. self.company_id.id,
  1260. self.unaffected_earnings_account.id,
  1261. )
  1262. query_inject_account_params += (
  1263. self.date_from,
  1264. )
  1265. if self.filter_cost_center_ids:
  1266. query_inject_account_params += (
  1267. tuple(self.filter_cost_center_ids.ids),
  1268. )
  1269. query_inject_account_params += (
  1270. self.company_id.id,
  1271. self.unaffected_earnings_account.id,
  1272. )
  1273. query_inject_account_params += (
  1274. self.id,
  1275. self.env.uid,
  1276. self.company_id.id,
  1277. self.unaffected_earnings_account.id,
  1278. )
  1279. self.env.cr.execute(query_inject_account,
  1280. query_inject_account_params)
  1281. def _complete_unaffected_earnings_account_values(self):
  1282. """Complete the report values of the unaffected earnings account
  1283. for report_general_ledger_qweb_account."""
  1284. query_update_unaffected_earnings_account_values = """
  1285. WITH
  1286. sum_amounts AS
  1287. (
  1288. SELECT
  1289. SUM(COALESCE(rml.debit, 0.0)) AS debit,
  1290. SUM(COALESCE(rml.credit, 0.0)) AS credit,
  1291. SUM(
  1292. COALESCE(rml.debit, 0.0) -
  1293. COALESCE(rml.credit, 0.0)
  1294. ) + ra.initial_balance AS balance
  1295. FROM
  1296. report_general_ledger_qweb_account ra
  1297. LEFT JOIN
  1298. report_general_ledger_qweb_move_line rml
  1299. ON ra.id = rml.report_account_id
  1300. WHERE
  1301. ra.report_id = %s
  1302. AND ra.account_id = %s
  1303. GROUP BY
  1304. ra.id
  1305. )
  1306. UPDATE
  1307. report_general_ledger_qweb_account ra
  1308. SET
  1309. initial_debit = 0.0,
  1310. initial_credit = 0.0,
  1311. final_debit = sum_amounts.debit,
  1312. final_credit = sum_amounts.credit,
  1313. final_balance = sum_amounts.balance
  1314. FROM
  1315. sum_amounts
  1316. WHERE
  1317. ra.report_id = %s
  1318. AND ra.account_id = %s
  1319. """
  1320. params = (
  1321. self.id,
  1322. self.unaffected_earnings_account.id,
  1323. self.id,
  1324. self.unaffected_earnings_account.id,
  1325. )
  1326. self.env.cr.execute(
  1327. query_update_unaffected_earnings_account_values,
  1328. params
  1329. )