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.

1767 lines
57 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. _inherit = 'report_qweb_abstract'
  21. # Filters fields, used for data computation
  22. date_from = fields.Date()
  23. date_to = fields.Date()
  24. fy_start_date = fields.Date()
  25. only_posted_moves = fields.Boolean()
  26. hide_account_at_0 = fields.Boolean()
  27. foreign_currency = fields.Boolean()
  28. show_analytic_tags = fields.Boolean()
  29. company_id = fields.Many2one(comodel_name='res.company')
  30. filter_account_ids = fields.Many2many(comodel_name='account.account')
  31. filter_partner_ids = fields.Many2many(comodel_name='res.partner')
  32. filter_journal_ids = fields.Many2many(comodel_name='account.journal')
  33. filter_cost_center_ids = fields.Many2many(
  34. comodel_name='account.analytic.account'
  35. )
  36. filter_analytic_tag_ids = fields.Many2many(
  37. comodel_name='account.analytic.tag',
  38. )
  39. centralize = fields.Boolean()
  40. # Flag fields, used for report display
  41. show_cost_center = fields.Boolean(
  42. default=lambda self: self.env.user.has_group(
  43. 'analytic.group_analytic_accounting'
  44. )
  45. )
  46. # Data fields, used to browse report data
  47. account_ids = fields.One2many(
  48. comodel_name='report_general_ledger_qweb_account',
  49. inverse_name='report_id'
  50. )
  51. # Compute of unaffected earnings account
  52. @api.depends('company_id')
  53. def _compute_unaffected_earnings_account(self):
  54. account_type = self.env.ref('account.data_unaffected_earnings')
  55. self.unaffected_earnings_account = self.env['account.account'].search(
  56. [
  57. ('user_type_id', '=', account_type.id),
  58. ('company_id', '=', self.company_id.id)
  59. ])
  60. unaffected_earnings_account = fields.Many2one(
  61. comodel_name='account.account',
  62. compute='_compute_unaffected_earnings_account',
  63. store=True
  64. )
  65. class GeneralLedgerReportAccount(models.TransientModel):
  66. _name = 'report_general_ledger_qweb_account'
  67. _inherit = 'report_qweb_abstract'
  68. _order = 'code ASC'
  69. report_id = fields.Many2one(
  70. comodel_name='report_general_ledger_qweb',
  71. ondelete='cascade',
  72. index=True
  73. )
  74. # Data fields, used to keep link with real object
  75. account_id = fields.Many2one(
  76. 'account.account',
  77. index=True
  78. )
  79. # Data fields, used for report display
  80. code = fields.Char()
  81. name = fields.Char()
  82. initial_debit = fields.Float(digits=(16, 2))
  83. initial_credit = fields.Float(digits=(16, 2))
  84. initial_balance = fields.Float(digits=(16, 2))
  85. currency_id = fields.Many2one(comodel_name='res.currency')
  86. initial_balance_foreign_currency = fields.Float(digits=(16, 2))
  87. final_debit = fields.Float(digits=(16, 2))
  88. final_credit = fields.Float(digits=(16, 2))
  89. final_balance = fields.Float(digits=(16, 2))
  90. final_balance_foreign_currency = fields.Float(digits=(16, 2))
  91. # Flag fields, used for report display and for data computation
  92. is_partner_account = fields.Boolean()
  93. # Data fields, used to browse report data
  94. move_line_ids = fields.One2many(
  95. comodel_name='report_general_ledger_qweb_move_line',
  96. inverse_name='report_account_id'
  97. )
  98. partner_ids = fields.One2many(
  99. comodel_name='report_general_ledger_qweb_partner',
  100. inverse_name='report_account_id'
  101. )
  102. class GeneralLedgerReportPartner(models.TransientModel):
  103. _name = 'report_general_ledger_qweb_partner'
  104. _inherit = 'report_qweb_abstract'
  105. report_account_id = fields.Many2one(
  106. comodel_name='report_general_ledger_qweb_account',
  107. ondelete='cascade',
  108. index=True
  109. )
  110. # Data fields, used to keep link with real object
  111. partner_id = fields.Many2one(
  112. 'res.partner',
  113. index=True
  114. )
  115. # Data fields, used for report display
  116. name = fields.Char()
  117. initial_debit = fields.Float(digits=(16, 2))
  118. initial_credit = fields.Float(digits=(16, 2))
  119. initial_balance = fields.Float(digits=(16, 2))
  120. currency_id = fields.Many2one(comodel_name='res.currency')
  121. initial_balance_foreign_currency = fields.Float(digits=(16, 2))
  122. final_debit = fields.Float(digits=(16, 2))
  123. final_credit = fields.Float(digits=(16, 2))
  124. final_balance = fields.Float(digits=(16, 2))
  125. final_balance_foreign_currency = fields.Float(digits=(16, 2))
  126. # Data fields, used to browse report data
  127. move_line_ids = fields.One2many(
  128. comodel_name='report_general_ledger_qweb_move_line',
  129. inverse_name='report_partner_id'
  130. )
  131. @api.model
  132. def _generate_order_by(self, order_spec, query):
  133. """Custom order to display "No partner allocated" at last position."""
  134. return """
  135. ORDER BY
  136. CASE
  137. WHEN "report_general_ledger_qweb_partner"."partner_id" IS NOT NULL
  138. THEN 0
  139. ELSE 1
  140. END,
  141. "report_general_ledger_qweb_partner"."name"
  142. """
  143. class GeneralLedgerReportMoveLine(models.TransientModel):
  144. _name = 'report_general_ledger_qweb_move_line'
  145. _inherit = 'report_qweb_abstract'
  146. report_account_id = fields.Many2one(
  147. comodel_name='report_general_ledger_qweb_account',
  148. ondelete='cascade',
  149. index=True
  150. )
  151. report_partner_id = fields.Many2one(
  152. comodel_name='report_general_ledger_qweb_partner',
  153. ondelete='cascade',
  154. index=True
  155. )
  156. # Data fields, used to keep link with real object
  157. move_line_id = fields.Many2one('account.move.line')
  158. matched_ml_id = fields.Many2one("account.full.reconcile")
  159. # Data fields, used for report display
  160. date = fields.Date()
  161. entry = fields.Char()
  162. journal = fields.Char()
  163. account = fields.Char()
  164. taxes_description = fields.Char()
  165. partner = fields.Char()
  166. label = fields.Char()
  167. cost_center = fields.Char()
  168. tags = fields.Char()
  169. debit = fields.Float(digits=(16, 2))
  170. credit = fields.Float(digits=(16, 2))
  171. cumul_balance = fields.Float(digits=(16, 2))
  172. currency_id = fields.Many2one(comodel_name='res.currency')
  173. amount_currency = fields.Float(digits=(16, 2))
  174. class GeneralLedgerReportCompute(models.TransientModel):
  175. """ Here, we just define methods.
  176. For class fields, go more top at this file.
  177. """
  178. _inherit = 'report_general_ledger_qweb'
  179. @api.multi
  180. def print_report(self, report_type):
  181. self.ensure_one()
  182. if report_type == 'xlsx':
  183. report_name = 'account_financial_report_qweb.' \
  184. 'report_general_ledger_xlsx'
  185. else:
  186. report_name = 'account_financial_report_qweb.' \
  187. 'report_general_ledger_qweb'
  188. return self.env['report'].get_action(docids=self.ids,
  189. report_name=report_name)
  190. def _get_html(self):
  191. result = {}
  192. rcontext = {}
  193. context = dict(self.env.context)
  194. report = self.browse(context.get('active_id'))
  195. if report:
  196. rcontext['o'] = report
  197. result['html'] = self.env.ref(
  198. 'account_financial_report_qweb.'
  199. 'report_general_ledger_html').render(rcontext)
  200. return result
  201. @api.model
  202. def get_html(self, given_context=None):
  203. return self._get_html()
  204. @api.multi
  205. def compute_data_for_report(
  206. self, with_line_details=True, with_partners=True):
  207. self.ensure_one()
  208. # Compute report data
  209. self._inject_account_values()
  210. if with_partners:
  211. self._inject_partner_values()
  212. if not self.filter_partner_ids:
  213. self._inject_partner_values(only_empty_partner=True)
  214. # Add unaffected earnings account
  215. if (not self.filter_account_ids or
  216. self.unaffected_earnings_account.id in
  217. self.filter_account_ids.ids):
  218. self._inject_unaffected_earnings_account_values()
  219. # Call this function even if we don't want line details because,
  220. # we need to compute
  221. # at least the values for unaffected earnings account
  222. # In this case, only unaffected earnings account values are computed
  223. only_unaffected_earnings_account = not with_line_details
  224. self._inject_line_not_centralized_values(
  225. only_unaffected_earnings_account=only_unaffected_earnings_account
  226. )
  227. if with_line_details:
  228. self._inject_line_not_centralized_values(
  229. is_account_line=False,
  230. is_partner_line=True)
  231. self._inject_line_not_centralized_values(
  232. is_account_line=False,
  233. is_partner_line=True,
  234. only_empty_partner_line=True)
  235. if self.centralize:
  236. self._inject_line_centralized_values()
  237. if self.show_analytic_tags:
  238. # Compute analytic tags
  239. self._compute_analytic_tags()
  240. # Refresh cache because all data are computed with SQL requests
  241. self.invalidate_cache()
  242. def _get_account_sub_subquery_sum_amounts(
  243. self, include_initial_balance, date_included):
  244. """ Return subquery used to compute sum amounts on accounts """
  245. sub_subquery_sum_amounts = """
  246. SELECT
  247. a.id AS account_id,
  248. SUM(ROUND(ml.debit, 2)) AS debit,
  249. SUM(ROUND(ml.credit,2)) AS credit,
  250. SUM(ROUND(ml.balance,2)) AS balance,
  251. c.id AS currency_id,
  252. CASE
  253. WHEN c.id IS NOT NULL
  254. THEN SUM(ROUND(ml.amount_currency, 2))
  255. ELSE NULL
  256. END AS balance_currency
  257. FROM
  258. accounts a
  259. INNER JOIN
  260. account_account_type at ON a.user_type_id = at.id
  261. INNER JOIN
  262. account_move_line ml
  263. ON a.id = ml.account_id
  264. """
  265. if date_included:
  266. sub_subquery_sum_amounts += """
  267. AND ml.date <= %s
  268. """
  269. else:
  270. sub_subquery_sum_amounts += """
  271. AND ml.date < %s
  272. """
  273. if not include_initial_balance:
  274. sub_subquery_sum_amounts += """
  275. AND at.include_initial_balance != TRUE AND ml.date >= %s
  276. """
  277. else:
  278. sub_subquery_sum_amounts += """
  279. AND at.include_initial_balance = TRUE
  280. """
  281. if self.only_posted_moves:
  282. sub_subquery_sum_amounts += """
  283. INNER JOIN
  284. account_move m ON ml.move_id = m.id AND m.state = 'posted'
  285. """
  286. if self.filter_cost_center_ids:
  287. sub_subquery_sum_amounts += """
  288. INNER JOIN
  289. account_analytic_account aa
  290. ON
  291. ml.analytic_account_id = aa.id
  292. AND aa.id IN %s
  293. """
  294. if self.filter_analytic_tag_ids:
  295. sub_subquery_sum_amounts += """
  296. INNER JOIN
  297. move_lines_on_tags ON ml.id = move_lines_on_tags.ml_id
  298. """
  299. sub_subquery_sum_amounts += """
  300. LEFT JOIN
  301. res_currency c ON a.currency_id = c.id
  302. """
  303. sub_subquery_sum_amounts += """
  304. GROUP BY
  305. a.id, c.id
  306. """
  307. return sub_subquery_sum_amounts
  308. def _get_final_account_sub_subquery_sum_amounts(self, date_included):
  309. """ Return final subquery used to compute sum amounts on accounts """
  310. subquery_sum_amounts = """
  311. SELECT
  312. sub.account_id AS account_id,
  313. SUM(ROUND(COALESCE(sub.debit, 0.0), 2)) AS debit,
  314. SUM(ROUND(COALESCE(sub.credit, 0.0), 2)) AS credit,
  315. SUM(ROUND(COALESCE(sub.balance, 0.0), 2)) AS balance,
  316. MAX(sub.currency_id) AS currency_id,
  317. SUM(ROUND(COALESCE(sub.balance_currency, 0.0), 2)) AS balance_currency
  318. FROM
  319. (
  320. """
  321. subquery_sum_amounts += self._get_account_sub_subquery_sum_amounts(
  322. include_initial_balance=False, date_included=date_included
  323. )
  324. subquery_sum_amounts += """
  325. UNION
  326. """
  327. subquery_sum_amounts += self._get_account_sub_subquery_sum_amounts(
  328. include_initial_balance=True, date_included=date_included
  329. )
  330. subquery_sum_amounts += """
  331. ) sub
  332. GROUP BY
  333. sub.account_id
  334. """
  335. return subquery_sum_amounts
  336. def _inject_account_values(self):
  337. """Inject report values for report_general_ledger_qweb_account."""
  338. query_inject_account = """
  339. WITH
  340. accounts AS
  341. (
  342. SELECT
  343. a.id,
  344. a.code,
  345. a.name,
  346. a.internal_type IN ('payable', 'receivable')
  347. AS is_partner_account,
  348. a.user_type_id,
  349. a.currency_id
  350. FROM
  351. account_account a
  352. """
  353. if (
  354. self.filter_partner_ids or
  355. self.filter_cost_center_ids or
  356. self.filter_analytic_tag_ids
  357. ):
  358. query_inject_account += """
  359. INNER JOIN
  360. account_move_line ml ON a.id = ml.account_id
  361. """
  362. if self.filter_partner_ids:
  363. query_inject_account += """
  364. INNER JOIN
  365. res_partner p ON ml.partner_id = p.id
  366. """
  367. if self.filter_cost_center_ids:
  368. query_inject_account += """
  369. INNER JOIN
  370. account_analytic_account aa
  371. ON
  372. ml.analytic_account_id = aa.id
  373. AND aa.id IN %s
  374. """
  375. if self.filter_analytic_tag_ids:
  376. query_inject_account += """
  377. INNER JOIN
  378. account_analytic_tag_account_move_line_rel atml
  379. ON atml.account_move_line_id = ml.id
  380. INNER JOIN
  381. account_analytic_tag aat
  382. ON
  383. atml.account_analytic_tag_id = aat.id
  384. AND aat.id IN %s
  385. """
  386. query_inject_account += """
  387. WHERE
  388. a.company_id = %s
  389. AND a.id != %s
  390. """
  391. if self.filter_account_ids:
  392. query_inject_account += """
  393. AND
  394. a.id IN %s
  395. """
  396. if self.filter_partner_ids:
  397. query_inject_account += """
  398. AND
  399. p.id IN %s
  400. """
  401. if (
  402. self.filter_partner_ids or
  403. self.filter_cost_center_ids or
  404. self.filter_analytic_tag_ids
  405. ):
  406. query_inject_account += """
  407. GROUP BY
  408. a.id
  409. """
  410. query_inject_account += """
  411. ),
  412. """
  413. if self.filter_analytic_tag_ids:
  414. query_inject_account += """
  415. move_lines_on_tags AS
  416. (
  417. SELECT
  418. DISTINCT ml.id AS ml_id
  419. FROM
  420. accounts a
  421. INNER JOIN
  422. account_move_line ml
  423. ON a.id = ml.account_id
  424. INNER JOIN
  425. account_analytic_tag_account_move_line_rel atml
  426. ON atml.account_move_line_id = ml.id
  427. INNER JOIN
  428. account_analytic_tag aat
  429. ON
  430. atml.account_analytic_tag_id = aat.id
  431. WHERE
  432. aat.id IN %s
  433. ),
  434. """
  435. init_subquery = self._get_final_account_sub_subquery_sum_amounts(
  436. date_included=False
  437. )
  438. final_subquery = self._get_final_account_sub_subquery_sum_amounts(
  439. date_included=True
  440. )
  441. query_inject_account += """
  442. initial_sum_amounts AS ( """ + init_subquery + """ ),
  443. final_sum_amounts AS ( """ + final_subquery + """ )
  444. INSERT INTO
  445. report_general_ledger_qweb_account
  446. (
  447. report_id,
  448. create_uid,
  449. create_date,
  450. account_id,
  451. code,
  452. name,
  453. initial_debit,
  454. initial_credit,
  455. initial_balance,
  456. currency_id,
  457. initial_balance_foreign_currency,
  458. final_debit,
  459. final_credit,
  460. final_balance,
  461. final_balance_foreign_currency,
  462. is_partner_account
  463. )
  464. SELECT
  465. %s AS report_id,
  466. %s AS create_uid,
  467. NOW() AS create_date,
  468. a.id AS account_id,
  469. a.code,
  470. a.name,
  471. COALESCE(i.debit, 0.0) AS initial_debit,
  472. COALESCE(i.credit, 0.0) AS initial_credit,
  473. COALESCE(i.balance, 0.0) AS initial_balance,
  474. c.id AS currency_id,
  475. COALESCE(i.balance_currency, 0.0) AS initial_balance_foreign_currency,
  476. COALESCE(f.debit, 0.0) AS final_debit,
  477. COALESCE(f.credit, 0.0) AS final_credit,
  478. COALESCE(f.balance, 0.0) AS final_balance,
  479. COALESCE(f.balance_currency, 0.0) AS final_balance_foreign_currency,
  480. a.is_partner_account
  481. FROM
  482. accounts a
  483. LEFT JOIN
  484. initial_sum_amounts i ON a.id = i.account_id
  485. LEFT JOIN
  486. final_sum_amounts f ON a.id = f.account_id
  487. LEFT JOIN
  488. res_currency c ON c.id = a.currency_id
  489. WHERE
  490. (
  491. i.debit IS NOT NULL AND i.debit != 0
  492. OR i.credit IS NOT NULL AND i.credit != 0
  493. OR i.balance IS NOT NULL AND i.balance != 0
  494. OR f.debit IS NOT NULL AND f.debit != 0
  495. OR f.credit IS NOT NULL AND f.credit != 0
  496. OR f.balance IS NOT NULL AND f.balance != 0
  497. )
  498. """
  499. if self.hide_account_at_0:
  500. query_inject_account += """
  501. AND
  502. f.balance IS NOT NULL AND f.balance != 0
  503. """
  504. query_inject_account_params = ()
  505. if self.filter_cost_center_ids:
  506. query_inject_account_params += (
  507. tuple(self.filter_cost_center_ids.ids),
  508. )
  509. if self.filter_analytic_tag_ids:
  510. query_inject_account_params += (
  511. tuple(self.filter_analytic_tag_ids.ids),
  512. )
  513. query_inject_account_params += (
  514. self.company_id.id,
  515. self.unaffected_earnings_account.id,
  516. )
  517. if self.filter_account_ids:
  518. query_inject_account_params += (
  519. tuple(self.filter_account_ids.ids),
  520. )
  521. if self.filter_partner_ids:
  522. query_inject_account_params += (
  523. tuple(self.filter_partner_ids.ids),
  524. )
  525. if self.filter_analytic_tag_ids:
  526. query_inject_account_params += (
  527. tuple(self.filter_analytic_tag_ids.ids),
  528. )
  529. query_inject_account_params += (
  530. self.date_from,
  531. self.fy_start_date,
  532. )
  533. if self.filter_cost_center_ids:
  534. query_inject_account_params += (
  535. tuple(self.filter_cost_center_ids.ids),
  536. )
  537. query_inject_account_params += (
  538. self.date_from,
  539. )
  540. if self.filter_cost_center_ids:
  541. query_inject_account_params += (
  542. tuple(self.filter_cost_center_ids.ids),
  543. )
  544. query_inject_account_params += (
  545. self.date_to,
  546. self.fy_start_date,
  547. )
  548. if self.filter_cost_center_ids:
  549. query_inject_account_params += (
  550. tuple(self.filter_cost_center_ids.ids),
  551. )
  552. query_inject_account_params += (
  553. self.date_to,
  554. )
  555. if self.filter_cost_center_ids:
  556. query_inject_account_params += (
  557. tuple(self.filter_cost_center_ids.ids),
  558. )
  559. query_inject_account_params += (
  560. self.id,
  561. self.env.uid,
  562. )
  563. self.env.cr.execute(query_inject_account, query_inject_account_params)
  564. def _get_partner_sub_subquery_sum_amounts(
  565. self, only_empty_partner, include_initial_balance, date_included
  566. ):
  567. """ Return subquery used to compute sum amounts on partners """
  568. sub_subquery_sum_amounts = """
  569. SELECT
  570. ap.account_id AS account_id,
  571. ap.partner_id AS partner_id,
  572. SUM(ROUND(ml.debit,2)) AS debit,
  573. SUM(ROUND(ml.credit,2)) AS credit,
  574. SUM(ROUND(ml.balance,2)) AS balance,
  575. c.id as currency_id,
  576. CASE
  577. WHEN c.id IS NOT NULL
  578. THEN SUM(ROUND(ml.amount_currency,2))
  579. ELSE NULL
  580. END AS balance_currency
  581. FROM
  582. accounts_partners ap
  583. INNER JOIN account_account ac
  584. ON ac.id = ap.account_id
  585. LEFT JOIN
  586. res_currency c ON ac.currency_id = c.id
  587. INNER JOIN
  588. account_move_line ml
  589. ON ap.account_id = ml.account_id
  590. """
  591. if date_included:
  592. sub_subquery_sum_amounts += """
  593. AND ml.date <= %s
  594. """
  595. else:
  596. sub_subquery_sum_amounts += """
  597. AND ml.date < %s
  598. """
  599. if not only_empty_partner:
  600. sub_subquery_sum_amounts += """
  601. AND ap.partner_id = ml.partner_id
  602. """
  603. else:
  604. sub_subquery_sum_amounts += """
  605. AND ap.partner_id IS NULL AND ml.partner_id IS NULL
  606. """
  607. if not include_initial_balance:
  608. sub_subquery_sum_amounts += """
  609. AND ap.include_initial_balance != TRUE AND ml.date >= %s
  610. """
  611. else:
  612. sub_subquery_sum_amounts += """
  613. AND ap.include_initial_balance = TRUE
  614. """
  615. if self.only_posted_moves:
  616. sub_subquery_sum_amounts += """
  617. INNER JOIN
  618. account_move m ON ml.move_id = m.id AND m.state = 'posted'
  619. """
  620. if self.filter_cost_center_ids:
  621. sub_subquery_sum_amounts += """
  622. INNER JOIN
  623. account_analytic_account aa
  624. ON
  625. ml.analytic_account_id = aa.id
  626. AND aa.id IN %s
  627. """
  628. if self.filter_analytic_tag_ids:
  629. sub_subquery_sum_amounts += """
  630. INNER JOIN
  631. move_lines_on_tags ON ml.id = move_lines_on_tags.ml_id
  632. """
  633. sub_subquery_sum_amounts += """
  634. GROUP BY
  635. ap.account_id, ap.partner_id, c.id
  636. """
  637. return sub_subquery_sum_amounts
  638. def _get_final_partner_sub_subquery_sum_amounts(self, only_empty_partner,
  639. date_included):
  640. """Return final subquery used to compute sum amounts on partners"""
  641. subquery_sum_amounts = """
  642. SELECT
  643. sub.account_id AS account_id,
  644. sub.partner_id AS partner_id,
  645. SUM(ROUND(COALESCE(sub.debit, 0.0), 2)) AS debit,
  646. SUM(ROUND(COALESCE(sub.credit, 0.0), 2)) AS credit,
  647. SUM(ROUND(COALESCE(sub.balance, 0.0), 2)) AS balance,
  648. MAX(sub.currency_id) AS currency_id,
  649. SUM(ROUND(COALESCE(sub.balance_currency, 0.0), 2))
  650. AS balance_currency
  651. FROM
  652. (
  653. """
  654. subquery_sum_amounts += self._get_partner_sub_subquery_sum_amounts(
  655. only_empty_partner,
  656. include_initial_balance=False,
  657. date_included=date_included
  658. )
  659. subquery_sum_amounts += """
  660. UNION
  661. """
  662. subquery_sum_amounts += self._get_partner_sub_subquery_sum_amounts(
  663. only_empty_partner,
  664. include_initial_balance=True,
  665. date_included=date_included
  666. )
  667. subquery_sum_amounts += """
  668. ) sub
  669. GROUP BY
  670. sub.account_id, sub.partner_id
  671. """
  672. return subquery_sum_amounts
  673. def _inject_partner_values(self, only_empty_partner=False):
  674. """ Inject report values for report_general_ledger_qweb_partner.
  675. Only for "partner" accounts (payable and receivable).
  676. """
  677. # pylint: disable=sql-injection
  678. query_inject_partner = """
  679. WITH
  680. accounts_partners AS
  681. (
  682. SELECT
  683. ra.id AS report_account_id,
  684. a.id AS account_id,
  685. at.include_initial_balance AS include_initial_balance,
  686. p.id AS partner_id,
  687. COALESCE(
  688. CASE
  689. WHEN
  690. NULLIF(p.name, '') IS NOT NULL
  691. AND NULLIF(p.ref, '') IS NOT NULL
  692. THEN p.name || ' (' || p.ref || ')'
  693. ELSE p.name
  694. END,
  695. '""" + _('No partner allocated') + """'
  696. ) AS partner_name
  697. FROM
  698. report_general_ledger_qweb_account ra
  699. INNER JOIN
  700. account_account a ON ra.account_id = a.id
  701. INNER JOIN
  702. account_account_type at ON a.user_type_id = at.id
  703. INNER JOIN
  704. account_move_line ml ON a.id = ml.account_id
  705. LEFT JOIN
  706. res_partner p ON ml.partner_id = p.id
  707. """
  708. if self.filter_cost_center_ids:
  709. query_inject_partner += """
  710. INNER JOIN
  711. account_analytic_account aa
  712. ON
  713. ml.analytic_account_id = aa.id
  714. AND aa.id IN %s
  715. """
  716. if self.filter_analytic_tag_ids:
  717. query_inject_partner += """
  718. INNER JOIN
  719. account_analytic_tag_account_move_line_rel atml
  720. ON atml.account_move_line_id = ml.id
  721. INNER JOIN
  722. account_analytic_tag aat
  723. ON
  724. atml.account_analytic_tag_id = aat.id
  725. AND aat.id IN %s
  726. """
  727. query_inject_partner += """
  728. WHERE
  729. ra.report_id = %s
  730. AND
  731. ra.is_partner_account = TRUE
  732. """
  733. if not only_empty_partner:
  734. query_inject_partner += """
  735. AND
  736. p.id IS NOT NULL
  737. """
  738. else:
  739. query_inject_partner += """
  740. AND
  741. p.id IS NULL
  742. """
  743. query_inject_partner += """
  744. """
  745. if self.centralize:
  746. query_inject_partner += """
  747. AND (a.centralized IS NULL OR a.centralized != TRUE)
  748. """
  749. if self.filter_partner_ids:
  750. query_inject_partner += """
  751. AND
  752. p.id IN %s
  753. """
  754. init_subquery = self._get_final_partner_sub_subquery_sum_amounts(
  755. only_empty_partner,
  756. date_included=False
  757. )
  758. final_subquery = self._get_final_partner_sub_subquery_sum_amounts(
  759. only_empty_partner,
  760. date_included=True
  761. )
  762. query_inject_partner += """
  763. GROUP BY
  764. ra.id,
  765. a.id,
  766. p.id,
  767. at.include_initial_balance
  768. ),
  769. """
  770. if self.filter_analytic_tag_ids:
  771. query_inject_partner += """
  772. move_lines_on_tags AS
  773. (
  774. SELECT
  775. DISTINCT ml.id AS ml_id
  776. FROM
  777. accounts_partners ap
  778. INNER JOIN
  779. account_move_line ml
  780. ON ap.account_id = ml.account_id
  781. INNER JOIN
  782. account_analytic_tag_account_move_line_rel atml
  783. ON atml.account_move_line_id = ml.id
  784. INNER JOIN
  785. account_analytic_tag aat
  786. ON
  787. atml.account_analytic_tag_id = aat.id
  788. WHERE
  789. aat.id IN %s
  790. ),
  791. """
  792. query_inject_partner += """
  793. initial_sum_amounts AS ( """ + init_subquery + """ ),
  794. final_sum_amounts AS ( """ + final_subquery + """ )
  795. INSERT INTO
  796. report_general_ledger_qweb_partner
  797. (
  798. report_account_id,
  799. create_uid,
  800. create_date,
  801. partner_id,
  802. name,
  803. initial_debit,
  804. initial_credit,
  805. initial_balance,
  806. currency_id,
  807. initial_balance_foreign_currency,
  808. final_debit,
  809. final_credit,
  810. final_balance,
  811. final_balance_foreign_currency
  812. )
  813. SELECT
  814. ap.report_account_id,
  815. %s AS create_uid,
  816. NOW() AS create_date,
  817. ap.partner_id,
  818. ap.partner_name,
  819. COALESCE(i.debit, 0.0) AS initial_debit,
  820. COALESCE(i.credit, 0.0) AS initial_credit,
  821. COALESCE(i.balance, 0.0) AS initial_balance,
  822. i.currency_id AS currency_id,
  823. COALESCE(i.balance_currency, 0.0) AS initial_balance_foreign_currency,
  824. COALESCE(f.debit, 0.0) AS final_debit,
  825. COALESCE(f.credit, 0.0) AS final_credit,
  826. COALESCE(f.balance, 0.0) AS final_balance,
  827. COALESCE(f.balance_currency, 0.0) AS final_balance_foreign_currency
  828. FROM
  829. accounts_partners ap
  830. LEFT JOIN
  831. initial_sum_amounts i
  832. ON
  833. (
  834. """
  835. if not only_empty_partner:
  836. query_inject_partner += """
  837. ap.partner_id = i.partner_id
  838. """
  839. else:
  840. query_inject_partner += """
  841. ap.partner_id IS NULL AND i.partner_id IS NULL
  842. """
  843. query_inject_partner += """
  844. )
  845. AND ap.account_id = i.account_id
  846. LEFT JOIN
  847. final_sum_amounts f
  848. ON
  849. (
  850. """
  851. if not only_empty_partner:
  852. query_inject_partner += """
  853. ap.partner_id = f.partner_id
  854. """
  855. else:
  856. query_inject_partner += """
  857. ap.partner_id IS NULL AND f.partner_id IS NULL
  858. """
  859. query_inject_partner += """
  860. )
  861. AND ap.account_id = f.account_id
  862. WHERE
  863. (
  864. i.debit IS NOT NULL AND i.debit != 0
  865. OR i.credit IS NOT NULL AND i.credit != 0
  866. OR i.balance IS NOT NULL AND i.balance != 0
  867. OR f.debit IS NOT NULL AND f.debit != 0
  868. OR f.credit IS NOT NULL AND f.credit != 0
  869. OR f.balance IS NOT NULL AND f.balance != 0
  870. )
  871. """
  872. if self.hide_account_at_0:
  873. query_inject_partner += """
  874. AND
  875. f.balance IS NOT NULL AND f.balance != 0
  876. """
  877. query_inject_partner_params = ()
  878. if self.filter_cost_center_ids:
  879. query_inject_partner_params += (
  880. tuple(self.filter_cost_center_ids.ids),
  881. )
  882. if self.filter_analytic_tag_ids:
  883. query_inject_partner_params += (
  884. tuple(self.filter_analytic_tag_ids.ids),
  885. )
  886. query_inject_partner_params += (
  887. self.id,
  888. )
  889. if self.filter_partner_ids:
  890. query_inject_partner_params += (
  891. tuple(self.filter_partner_ids.ids),
  892. )
  893. if self.filter_analytic_tag_ids:
  894. query_inject_partner_params += (
  895. tuple(self.filter_analytic_tag_ids.ids),
  896. )
  897. query_inject_partner_params += (
  898. self.date_from,
  899. self.fy_start_date,
  900. )
  901. if self.filter_cost_center_ids:
  902. query_inject_partner_params += (
  903. tuple(self.filter_cost_center_ids.ids),
  904. )
  905. query_inject_partner_params += (
  906. self.date_from,
  907. )
  908. if self.filter_cost_center_ids:
  909. query_inject_partner_params += (
  910. tuple(self.filter_cost_center_ids.ids),
  911. )
  912. query_inject_partner_params += (
  913. self.date_to,
  914. self.fy_start_date,
  915. )
  916. if self.filter_cost_center_ids:
  917. query_inject_partner_params += (
  918. tuple(self.filter_cost_center_ids.ids),
  919. )
  920. query_inject_partner_params += (
  921. self.date_to,
  922. )
  923. if self.filter_cost_center_ids:
  924. query_inject_partner_params += (
  925. tuple(self.filter_cost_center_ids.ids),
  926. )
  927. query_inject_partner_params += (
  928. self.env.uid,
  929. )
  930. self.env.cr.execute(query_inject_partner, query_inject_partner_params)
  931. def _inject_line_not_centralized_values(
  932. self,
  933. is_account_line=True,
  934. is_partner_line=False,
  935. only_empty_partner_line=False,
  936. only_unaffected_earnings_account=False):
  937. """ Inject report values for report_general_ledger_qweb_move_line.
  938. If centralized option have been chosen,
  939. only non centralized accounts are computed.
  940. In function of `is_account_line` and `is_partner_line` values,
  941. the move_line link is made either with account or either with partner.
  942. The "only_empty_partner_line" value is used
  943. to compute data without partner.
  944. """
  945. query_inject_move_line = ""
  946. if self.filter_analytic_tag_ids:
  947. query_inject_move_line += """
  948. WITH
  949. move_lines_on_tags AS
  950. (
  951. SELECT
  952. DISTINCT ml.id AS ml_id
  953. FROM
  954. """
  955. if is_account_line:
  956. query_inject_move_line += """
  957. report_general_ledger_qweb_account ra
  958. """
  959. elif is_partner_line:
  960. query_inject_move_line += """
  961. report_general_ledger_qweb_partner rp
  962. INNER JOIN
  963. report_general_ledger_qweb_account ra
  964. ON rp.report_account_id = ra.id
  965. """
  966. query_inject_move_line += """
  967. INNER JOIN
  968. account_move_line ml
  969. ON ra.account_id = ml.account_id
  970. INNER JOIN
  971. account_analytic_tag_account_move_line_rel atml
  972. ON atml.account_move_line_id = ml.id
  973. INNER JOIN
  974. account_analytic_tag aat
  975. ON
  976. atml.account_analytic_tag_id = aat.id
  977. WHERE
  978. ra.report_id = %s
  979. AND
  980. aat.id IN %s
  981. )
  982. """
  983. query_inject_move_line += """
  984. INSERT INTO
  985. report_general_ledger_qweb_move_line
  986. (
  987. """
  988. if is_account_line:
  989. query_inject_move_line += """
  990. report_account_id,
  991. """
  992. elif is_partner_line:
  993. query_inject_move_line += """
  994. report_partner_id,
  995. """
  996. query_inject_move_line += """
  997. create_uid,
  998. create_date,
  999. move_line_id,
  1000. matched_ml_id,
  1001. date,
  1002. entry,
  1003. journal,
  1004. account,
  1005. taxes_description,
  1006. partner,
  1007. label,
  1008. cost_center,
  1009. debit,
  1010. credit,
  1011. cumul_balance,
  1012. currency_id,
  1013. amount_currency
  1014. )
  1015. SELECT
  1016. """
  1017. if is_account_line:
  1018. query_inject_move_line += """
  1019. ra.id AS report_account_id,
  1020. """
  1021. elif is_partner_line:
  1022. query_inject_move_line += """
  1023. rp.id AS report_partner_id,
  1024. """
  1025. query_inject_move_line += """
  1026. %s AS create_uid,
  1027. NOW() AS create_date,
  1028. ml.id AS move_line_id,
  1029. fr.id AS matched_ml_id,
  1030. ml.date,
  1031. m.name AS entry,
  1032. j.code AS journal,
  1033. a.code AS account,
  1034. CASE
  1035. WHEN
  1036. ml.tax_line_id is not null
  1037. THEN
  1038. COALESCE(at.description, at.name)
  1039. WHEN
  1040. ml.tax_line_id is null
  1041. THEN
  1042. (SELECT
  1043. array_to_string(
  1044. array_agg(COALESCE(at.description, at.name)
  1045. ), ', ')
  1046. FROM
  1047. account_move_line_account_tax_rel aml_at_rel
  1048. LEFT JOIN
  1049. account_tax at on (at.id = aml_at_rel.account_tax_id)
  1050. WHERE
  1051. aml_at_rel.account_move_line_id = ml.id)
  1052. ELSE
  1053. ''
  1054. END as taxes_description,
  1055. """
  1056. if not only_empty_partner_line:
  1057. query_inject_move_line += """
  1058. CASE
  1059. WHEN
  1060. NULLIF(p.name, '') IS NOT NULL
  1061. AND NULLIF(p.ref, '') IS NOT NULL
  1062. THEN p.name || ' (' || p.ref || ')'
  1063. ELSE p.name
  1064. END AS partner,
  1065. """
  1066. elif only_empty_partner_line:
  1067. query_inject_move_line += """
  1068. '""" + _('No partner allocated') + """' AS partner,
  1069. """
  1070. query_inject_move_line += """
  1071. CONCAT_WS(' - ', NULLIF(ml.ref, ''), NULLIF(ml.name, '')) AS label,
  1072. aa.name AS cost_center,
  1073. ml.debit,
  1074. ml.credit,
  1075. """
  1076. if is_account_line:
  1077. query_inject_move_line += """
  1078. ra.initial_balance + (
  1079. SUM(ROUND(ml.balance, 2))
  1080. OVER (PARTITION BY a.code
  1081. ORDER BY a.code, ml.date, ml.id)
  1082. ) AS cumul_balance,
  1083. """
  1084. elif is_partner_line and not only_empty_partner_line:
  1085. query_inject_move_line += """
  1086. rp.initial_balance + (
  1087. SUM(ROUND(ml.balance, 2))
  1088. OVER (PARTITION BY a.code, p.name
  1089. ORDER BY a.code, p.name, ml.date, ml.id)
  1090. ) AS cumul_balance,
  1091. """
  1092. elif is_partner_line and only_empty_partner_line:
  1093. query_inject_move_line += """
  1094. rp.initial_balance + (
  1095. SUM(ROUND(ml.balance, 2))
  1096. OVER (PARTITION BY a.code
  1097. ORDER BY a.code, ml.date, ml.id)
  1098. ) AS cumul_balance,
  1099. """
  1100. query_inject_move_line += """
  1101. c.id AS currency_id,
  1102. ml.amount_currency
  1103. FROM
  1104. """
  1105. if is_account_line:
  1106. query_inject_move_line += """
  1107. report_general_ledger_qweb_account ra
  1108. """
  1109. elif is_partner_line:
  1110. query_inject_move_line += """
  1111. report_general_ledger_qweb_partner rp
  1112. INNER JOIN
  1113. report_general_ledger_qweb_account ra ON rp.report_account_id = ra.id
  1114. """
  1115. query_inject_move_line += """
  1116. INNER JOIN
  1117. account_move_line ml ON ra.account_id = ml.account_id
  1118. INNER JOIN
  1119. account_move m ON ml.move_id = m.id
  1120. INNER JOIN
  1121. account_journal j ON ml.journal_id = j.id
  1122. INNER JOIN
  1123. account_account a ON ml.account_id = a.id
  1124. LEFT JOIN
  1125. account_tax at ON ml.tax_line_id = at.id
  1126. """
  1127. if is_account_line:
  1128. query_inject_move_line += """
  1129. LEFT JOIN
  1130. res_partner p ON ml.partner_id = p.id
  1131. """
  1132. elif is_partner_line and not only_empty_partner_line:
  1133. query_inject_move_line += """
  1134. INNER JOIN
  1135. res_partner p
  1136. ON ml.partner_id = p.id AND rp.partner_id = p.id
  1137. """
  1138. query_inject_move_line += """
  1139. LEFT JOIN
  1140. account_full_reconcile fr ON ml.full_reconcile_id = fr.id
  1141. LEFT JOIN
  1142. res_currency c ON ml.currency_id = c.id
  1143. """
  1144. if self.filter_cost_center_ids:
  1145. query_inject_move_line += """
  1146. INNER JOIN
  1147. account_analytic_account aa
  1148. ON
  1149. ml.analytic_account_id = aa.id
  1150. AND aa.id IN %s
  1151. """
  1152. else:
  1153. query_inject_move_line += """
  1154. LEFT JOIN
  1155. account_analytic_account aa ON ml.analytic_account_id = aa.id
  1156. """
  1157. if self.filter_analytic_tag_ids:
  1158. query_inject_move_line += """
  1159. INNER JOIN
  1160. move_lines_on_tags ON ml.id = move_lines_on_tags.ml_id
  1161. """
  1162. query_inject_move_line += """
  1163. WHERE
  1164. ra.report_id = %s
  1165. AND
  1166. """
  1167. if only_unaffected_earnings_account:
  1168. query_inject_move_line += """
  1169. a.id = %s
  1170. AND
  1171. """
  1172. if is_account_line:
  1173. query_inject_move_line += """
  1174. (ra.is_partner_account IS NULL OR ra.is_partner_account != TRUE)
  1175. """
  1176. elif is_partner_line:
  1177. query_inject_move_line += """
  1178. ra.is_partner_account = TRUE
  1179. """
  1180. if self.centralize:
  1181. query_inject_move_line += """
  1182. AND
  1183. (a.centralized IS NULL OR a.centralized != TRUE)
  1184. """
  1185. query_inject_move_line += """
  1186. AND
  1187. ml.date BETWEEN %s AND %s
  1188. """
  1189. if self.only_posted_moves:
  1190. query_inject_move_line += """
  1191. AND
  1192. m.state = 'posted'
  1193. """
  1194. if only_empty_partner_line:
  1195. query_inject_move_line += """
  1196. AND
  1197. ml.partner_id IS NULL
  1198. AND
  1199. rp.partner_id IS NULL
  1200. """
  1201. if self.filter_journal_ids:
  1202. query_inject_move_line += """
  1203. AND
  1204. j.id IN %s
  1205. """
  1206. if is_account_line:
  1207. query_inject_move_line += """
  1208. ORDER BY
  1209. a.code, ml.date, ml.id
  1210. """
  1211. elif is_partner_line and not only_empty_partner_line:
  1212. query_inject_move_line += """
  1213. ORDER BY
  1214. a.code, p.name, ml.date, ml.id
  1215. """
  1216. elif is_partner_line and only_empty_partner_line:
  1217. query_inject_move_line += """
  1218. ORDER BY
  1219. a.code, ml.date, ml.id
  1220. """
  1221. query_inject_move_line_params = ()
  1222. if self.filter_analytic_tag_ids:
  1223. query_inject_move_line_params += (
  1224. self.id,
  1225. tuple(self.filter_analytic_tag_ids.ids),
  1226. )
  1227. query_inject_move_line_params += (
  1228. self.env.uid,
  1229. )
  1230. if self.filter_cost_center_ids:
  1231. query_inject_move_line_params += (
  1232. tuple(self.filter_cost_center_ids.ids),
  1233. )
  1234. query_inject_move_line_params += (
  1235. self.id,
  1236. )
  1237. if only_unaffected_earnings_account:
  1238. query_inject_move_line_params += (
  1239. self.unaffected_earnings_account.id,
  1240. )
  1241. query_inject_move_line_params += (
  1242. self.date_from,
  1243. self.date_to,
  1244. )
  1245. if self.filter_journal_ids:
  1246. query_inject_move_line_params += (tuple(
  1247. self.filter_journal_ids.ids,
  1248. ),)
  1249. self.env.cr.execute(
  1250. query_inject_move_line,
  1251. query_inject_move_line_params
  1252. )
  1253. def _inject_line_centralized_values(self):
  1254. """ Inject report values for report_general_ledger_qweb_move_line.
  1255. Only centralized accounts are computed.
  1256. """
  1257. if self.filter_analytic_tag_ids:
  1258. query_inject_move_line_centralized = """
  1259. WITH
  1260. move_lines_on_tags AS
  1261. (
  1262. SELECT
  1263. DISTINCT ml.id AS ml_id
  1264. FROM
  1265. report_general_ledger_qweb_account ra
  1266. INNER JOIN
  1267. account_move_line ml
  1268. ON ra.account_id = ml.account_id
  1269. INNER JOIN
  1270. account_analytic_tag_account_move_line_rel atml
  1271. ON atml.account_move_line_id = ml.id
  1272. INNER JOIN
  1273. account_analytic_tag aat
  1274. ON
  1275. atml.account_analytic_tag_id = aat.id
  1276. WHERE
  1277. ra.report_id = %s
  1278. AND
  1279. aat.id IN %s
  1280. ),
  1281. """
  1282. else:
  1283. query_inject_move_line_centralized = """
  1284. WITH
  1285. """
  1286. query_inject_move_line_centralized += """
  1287. move_lines AS
  1288. (
  1289. SELECT
  1290. ml.account_id,
  1291. (
  1292. DATE_TRUNC('month', ml.date) + interval '1 month'
  1293. - interval '1 day'
  1294. )::date AS date,
  1295. SUM(ROUND(ml.debit, 2)) AS debit,
  1296. SUM(ROUND(ml.credit, 2)) AS credit,
  1297. SUM(ROUND(ml.balance, 2)) AS balance,
  1298. ml.currency_id AS currency_id,
  1299. ml.journal_id as journal_id
  1300. FROM
  1301. report_general_ledger_qweb_account ra
  1302. INNER JOIN
  1303. account_move_line ml ON ra.account_id = ml.account_id
  1304. INNER JOIN
  1305. account_move m ON ml.move_id = m.id
  1306. INNER JOIN
  1307. account_account a ON ml.account_id = a.id
  1308. """
  1309. if self.filter_cost_center_ids:
  1310. query_inject_move_line_centralized += """
  1311. INNER JOIN
  1312. account_analytic_account aa
  1313. ON
  1314. ml.analytic_account_id = aa.id
  1315. AND aa.id IN %s
  1316. """
  1317. if self.filter_analytic_tag_ids:
  1318. query_inject_move_line_centralized += """
  1319. INNER JOIN
  1320. move_lines_on_tags ON ml.id = move_lines_on_tags.ml_id
  1321. """
  1322. query_inject_move_line_centralized += """
  1323. WHERE
  1324. ra.report_id = %s
  1325. AND
  1326. a.centralized = TRUE
  1327. AND
  1328. ml.date BETWEEN %s AND %s
  1329. """
  1330. if self.only_posted_moves:
  1331. query_inject_move_line_centralized += """
  1332. AND
  1333. m.state = 'posted'
  1334. """
  1335. query_inject_move_line_centralized += """
  1336. GROUP BY
  1337. ra.id, ml.account_id, a.code, 2, ml.currency_id, ml.journal_id
  1338. )
  1339. INSERT INTO
  1340. report_general_ledger_qweb_move_line
  1341. (
  1342. report_account_id,
  1343. create_uid,
  1344. create_date,
  1345. date,
  1346. account,
  1347. journal,
  1348. label,
  1349. debit,
  1350. credit,
  1351. cumul_balance
  1352. )
  1353. SELECT
  1354. ra.id AS report_account_id,
  1355. %s AS create_uid,
  1356. NOW() AS create_date,
  1357. ml.date,
  1358. a.code AS account,
  1359. j.code as journal,
  1360. '""" + _('Centralized Entries') + """' AS label,
  1361. ml.debit AS debit,
  1362. ml.credit AS credit,
  1363. ra.initial_balance + (
  1364. SUM(ROUND(ml.balance, 2))
  1365. OVER (PARTITION BY a.code ORDER BY ml.date)
  1366. ) AS cumul_balance
  1367. FROM
  1368. report_general_ledger_qweb_account ra
  1369. INNER JOIN
  1370. move_lines ml ON ra.account_id = ml.account_id
  1371. INNER JOIN
  1372. account_account a ON ml.account_id = a.id
  1373. INNER JOIN
  1374. account_journal j ON ml.journal_id = j.id
  1375. LEFT JOIN
  1376. res_currency c ON ml.currency_id = c.id
  1377. WHERE
  1378. ra.report_id = %s
  1379. AND
  1380. (a.centralized IS NOT NULL AND a.centralized = TRUE)
  1381. """
  1382. if self.filter_journal_ids:
  1383. query_inject_move_line_centralized += """
  1384. AND
  1385. j.id in %s
  1386. """
  1387. query_inject_move_line_centralized += """
  1388. ORDER BY
  1389. a.code, ml.date
  1390. """
  1391. query_inject_move_line_centralized_params = ()
  1392. if self.filter_analytic_tag_ids:
  1393. query_inject_move_line_centralized_params += (
  1394. self.id,
  1395. tuple(self.filter_analytic_tag_ids.ids),
  1396. )
  1397. if self.filter_cost_center_ids:
  1398. query_inject_move_line_centralized_params += (
  1399. tuple(self.filter_cost_center_ids.ids),
  1400. )
  1401. query_inject_move_line_centralized_params += (
  1402. self.id,
  1403. self.date_from,
  1404. self.date_to,
  1405. self.env.uid,
  1406. self.id,
  1407. )
  1408. if self.filter_journal_ids:
  1409. query_inject_move_line_centralized_params += (tuple(
  1410. self.filter_journal_ids.ids,
  1411. ),)
  1412. self.env.cr.execute(
  1413. query_inject_move_line_centralized,
  1414. query_inject_move_line_centralized_params
  1415. )
  1416. def _compute_analytic_tags(self):
  1417. """ Compute "tags" column"""
  1418. query_update_analytic_tags = """
  1419. UPDATE
  1420. report_general_ledger_qweb_move_line
  1421. SET
  1422. tags = tags_values.tags
  1423. FROM
  1424. (
  1425. (
  1426. SELECT
  1427. rml.id AS report_id,
  1428. array_to_string(array_agg(t.name ORDER BY t.name), ',') AS tags
  1429. FROM
  1430. account_move_line ml
  1431. INNER JOIN
  1432. report_general_ledger_qweb_move_line rml
  1433. ON ml.id = rml.move_line_id
  1434. INNER JOIN
  1435. report_general_ledger_qweb_account ra
  1436. ON rml.report_account_id = ra.id
  1437. INNER JOIN
  1438. account_analytic_tag_account_move_line_rel tml
  1439. ON ml.id = tml.account_move_line_id
  1440. INNER JOIN
  1441. account_analytic_tag t
  1442. ON tml.account_analytic_tag_id = t.id
  1443. WHERE
  1444. ra.report_id = %(report_id)s
  1445. GROUP BY
  1446. rml.id,
  1447. ml.id
  1448. )
  1449. UNION
  1450. (
  1451. SELECT
  1452. rml.id AS report_id,
  1453. array_to_string(array_agg(t.name ORDER BY t.name), ',') AS tags
  1454. FROM
  1455. account_move_line ml
  1456. INNER JOIN
  1457. report_general_ledger_qweb_move_line rml
  1458. ON ml.id = rml.move_line_id
  1459. INNER JOIN
  1460. report_general_ledger_qweb_partner rp
  1461. ON rml.report_partner_id = rp.id
  1462. INNER JOIN
  1463. report_general_ledger_qweb_account ra
  1464. ON rp.report_account_id = ra.id
  1465. INNER JOIN
  1466. account_analytic_tag_account_move_line_rel tml
  1467. ON ml.id = tml.account_move_line_id
  1468. INNER JOIN
  1469. account_analytic_tag t
  1470. ON tml.account_analytic_tag_id = t.id
  1471. WHERE
  1472. ra.report_id = %(report_id)s
  1473. GROUP BY
  1474. rml.id,
  1475. ml.id
  1476. )
  1477. ) AS tags_values
  1478. WHERE
  1479. report_general_ledger_qweb_move_line.id = tags_values.report_id
  1480. """
  1481. params = {
  1482. 'report_id': self.id,
  1483. }
  1484. self.env.cr.execute(query_update_analytic_tags, params)
  1485. def _inject_unaffected_earnings_account_values(self):
  1486. """Inject the report values of the unaffected earnings account
  1487. for report_general_ledger_qweb_account."""
  1488. # Fetch the profit and loss accounts
  1489. query_unaffected_earnings_account_ids = """
  1490. SELECT a.id
  1491. FROM account_account as a
  1492. INNER JOIN account_account_type as at
  1493. ON at.id = a.user_type_id
  1494. WHERE at.include_initial_balance = FALSE
  1495. """
  1496. self.env.cr.execute(query_unaffected_earnings_account_ids)
  1497. pl_account_ids = [r[0] for r in self.env.cr.fetchall()]
  1498. unaffected_earnings_account_ids = \
  1499. pl_account_ids + [self.unaffected_earnings_account.id]
  1500. # Fetch the current fiscal year start date
  1501. date = fields.Datetime.from_string(self.date_from)
  1502. res = self.company_id.compute_fiscalyear_dates(date)
  1503. fy_start_date = res['date_from']
  1504. query_select_previous_fy_unaffected_earnings_params = {
  1505. 'date_to': fy_start_date,
  1506. 'company_id': self.company_id.id,
  1507. 'account_ids': tuple(unaffected_earnings_account_ids),
  1508. 'analytic_tag_ids': tuple(self.filter_analytic_tag_ids.ids),
  1509. }
  1510. query_select_previous_fy_unaffected_earnings = ''
  1511. q_analytic_tags = ''
  1512. if self.filter_analytic_tag_ids:
  1513. q_analytic_tags = """
  1514. WITH move_lines_on_tags AS
  1515. (
  1516. SELECT
  1517. DISTINCT ml.id AS ml_id
  1518. FROM
  1519. account_account a
  1520. INNER JOIN
  1521. account_move_line ml
  1522. ON a.id = ml.account_id
  1523. INNER JOIN
  1524. account_analytic_tag_account_move_line_rel atml
  1525. ON atml.account_move_line_id = ml.id
  1526. INNER JOIN
  1527. account_analytic_tag aat
  1528. ON
  1529. atml.account_analytic_tag_id = aat.id
  1530. WHERE
  1531. aat.id IN %(analytic_tag_ids)s
  1532. )
  1533. """
  1534. query_select_previous_fy_unaffected_earnings += q_analytic_tags
  1535. query_select_previous_fy_unaffected_earnings += """
  1536. SELECT sum(ROUND(ml.balance, 2)) as balance
  1537. FROM account_move_line as ml
  1538. INNER JOIN account_move as am
  1539. ON am.id = ml.move_id
  1540. INNER JOIN account_journal j
  1541. ON am.journal_id = j.id
  1542. """
  1543. if self.filter_cost_center_ids:
  1544. query_select_previous_fy_unaffected_earnings += """
  1545. INNER JOIN account_analytic_account aa
  1546. ON ml.analytic_account_id = aa.id
  1547. AND aa.id IN %(cost_center_ids)s
  1548. """
  1549. query_select_previous_fy_unaffected_earnings_params[
  1550. 'cost_center_ids'] = tuple(self.filter_cost_center_ids.ids)
  1551. if self.filter_analytic_tag_ids:
  1552. query_select_previous_fy_unaffected_earnings += """
  1553. INNER JOIN move_lines_on_tags ON ml.id =
  1554. move_lines_on_tags.ml_id
  1555. """
  1556. query_select_previous_fy_unaffected_earnings += """
  1557. WHERE ml.date < %(date_to)s
  1558. AND ml.company_id = %(company_id)s
  1559. AND ml.account_id IN %(account_ids)s
  1560. """
  1561. if self.filter_journal_ids:
  1562. query_select_previous_fy_unaffected_earnings += """
  1563. AND j.id IN %(journal_ids)s
  1564. """
  1565. query_select_previous_fy_unaffected_earnings_params[
  1566. 'journal_ids'] = tuple(self.filter_journal_ids.ids)
  1567. if self.only_posted_moves:
  1568. query_select_previous_fy_unaffected_earnings += """
  1569. AND am.state = 'posted'
  1570. """
  1571. self.env.cr.execute(
  1572. query_select_previous_fy_unaffected_earnings,
  1573. query_select_previous_fy_unaffected_earnings_params)
  1574. res = self.env.cr.fetchone()
  1575. unaffected_earnings_initial_balance = res[0] or 0.0
  1576. # Now select the current period unaffected earnings,
  1577. # excluding the current period P&L.
  1578. query_select_period_unaffected_earnings_params = {
  1579. 'date_from': self.date_from,
  1580. 'date_to': self.date_to,
  1581. 'company_id': self.company_id.id,
  1582. 'unaffected_earnings_id': self.unaffected_earnings_account.id,
  1583. 'analytic_tag_ids': tuple(self.filter_analytic_tag_ids.ids),
  1584. }
  1585. query_select_period_unaffected_earnings = ''
  1586. if self.filter_analytic_tag_ids:
  1587. query_select_period_unaffected_earnings += q_analytic_tags
  1588. query_select_period_unaffected_earnings += """
  1589. SELECT
  1590. sum(ROUND(ml.debit, 2)) as sum_debit,
  1591. sum(ROUND(ml.credit, 2)) as sum_credit,
  1592. sum(ROUND(ml.balance, 2)) as balance
  1593. FROM account_move_line as ml
  1594. INNER JOIN account_move as am
  1595. ON am.id = ml.move_id
  1596. INNER JOIN account_journal j
  1597. ON am.journal_id = j.id
  1598. """
  1599. if self.filter_cost_center_ids:
  1600. query_select_period_unaffected_earnings += """
  1601. INNER JOIN account_analytic_account aa
  1602. ON ml.analytic_account_id = aa.id
  1603. AND aa.id IN %(cost_center_ids)s
  1604. """
  1605. query_select_period_unaffected_earnings_params[
  1606. 'cost_center_ids'] = tuple(self.filter_cost_center_ids.ids)
  1607. if self.filter_analytic_tag_ids:
  1608. query_select_period_unaffected_earnings += """
  1609. INNER JOIN move_lines_on_tags
  1610. ON ml.id = move_lines_on_tags.ml_id
  1611. """
  1612. query_select_period_unaffected_earnings += """
  1613. WHERE am.date >= %(date_from)s
  1614. AND ml.date <= %(date_to)s
  1615. AND ml.company_id = %(company_id)s
  1616. AND ml.account_id = %(unaffected_earnings_id)s
  1617. """
  1618. if self.filter_journal_ids:
  1619. query_select_period_unaffected_earnings += """
  1620. AND j.id IN %(journal_ids)s
  1621. """
  1622. query_select_period_unaffected_earnings_params[
  1623. 'journal_ids'] = tuple(self.filter_journal_ids.ids)
  1624. if self.only_posted_moves:
  1625. query_select_period_unaffected_earnings += """
  1626. AND am.state = 'posted'
  1627. """
  1628. self.env.cr.execute(query_select_period_unaffected_earnings,
  1629. query_select_period_unaffected_earnings_params)
  1630. res = self.env.cr.fetchone()
  1631. unaffected_earnings_period_debit = res[0] or 0.0
  1632. unaffected_earnings_period_credit = res[1] or 0.0
  1633. unaffected_earnings_period_balance = res[2] or 0.0
  1634. # pylint: disable=sql-injection
  1635. query_inject_account = """
  1636. INSERT INTO
  1637. report_general_ledger_qweb_account (
  1638. report_id,
  1639. create_uid,
  1640. create_date,
  1641. account_id,
  1642. code,
  1643. name,
  1644. is_partner_account,
  1645. initial_debit,
  1646. initial_credit,
  1647. initial_balance,
  1648. final_debit,
  1649. final_credit,
  1650. final_balance
  1651. )
  1652. VALUES (
  1653. %(report_id)s,
  1654. %(user_id)s,
  1655. NOW(),
  1656. %(account_id)s,
  1657. %(code)s,
  1658. %(name)s,
  1659. False,
  1660. %(initial_debit)s,
  1661. %(initial_credit)s,
  1662. %(initial_balance)s,
  1663. %(final_debit)s,
  1664. %(final_credit)s,
  1665. %(final_balance)s
  1666. )
  1667. """
  1668. initial_debit = unaffected_earnings_initial_balance >= 0 and \
  1669. unaffected_earnings_initial_balance or 0
  1670. initial_credit = unaffected_earnings_initial_balance < 0 and \
  1671. -1 * unaffected_earnings_initial_balance or 0
  1672. final_balance = unaffected_earnings_initial_balance + \
  1673. unaffected_earnings_period_balance
  1674. query_inject_account_params = {
  1675. 'report_id': self.id,
  1676. 'user_id': self.env.uid,
  1677. 'account_id': self.unaffected_earnings_account.id,
  1678. 'code': self.unaffected_earnings_account.code,
  1679. 'name': self.unaffected_earnings_account.name,
  1680. 'initial_debit': initial_debit,
  1681. 'initial_credit': initial_credit,
  1682. 'initial_balance': unaffected_earnings_initial_balance,
  1683. 'final_debit': initial_debit + unaffected_earnings_period_debit,
  1684. 'final_credit': initial_credit + unaffected_earnings_period_credit,
  1685. 'final_balance': final_balance,
  1686. }
  1687. self.env.cr.execute(query_inject_account,
  1688. query_inject_account_params)