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.

1766 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(ml.debit) AS debit,
  249. SUM(ml.credit) AS credit,
  250. SUM(ml.balance) AS balance,
  251. c.id AS currency_id,
  252. CASE
  253. WHEN c.id IS NOT NULL
  254. THEN SUM(ml.amount_currency)
  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(COALESCE(sub.debit, 0.0)) AS debit,
  314. SUM(COALESCE(sub.credit, 0.0)) AS credit,
  315. SUM(COALESCE(sub.balance, 0.0)) AS balance,
  316. MAX(sub.currency_id) AS currency_id,
  317. SUM(COALESCE(sub.balance_currency, 0.0)) 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(ml.debit) AS debit,
  573. SUM(ml.credit) AS credit,
  574. SUM(ml.balance) AS balance,
  575. c.id as currency_id,
  576. CASE
  577. WHEN c.id IS NOT NULL
  578. THEN SUM(ml.amount_currency)
  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(COALESCE(sub.debit, 0.0)) AS debit,
  646. SUM(COALESCE(sub.credit, 0.0)) AS credit,
  647. SUM(COALESCE(sub.balance, 0.0)) AS balance,
  648. MAX(sub.currency_id) AS currency_id,
  649. SUM(COALESCE(sub.balance_currency, 0.0)) AS balance_currency
  650. FROM
  651. (
  652. """
  653. subquery_sum_amounts += self._get_partner_sub_subquery_sum_amounts(
  654. only_empty_partner,
  655. include_initial_balance=False,
  656. date_included=date_included
  657. )
  658. subquery_sum_amounts += """
  659. UNION
  660. """
  661. subquery_sum_amounts += self._get_partner_sub_subquery_sum_amounts(
  662. only_empty_partner,
  663. include_initial_balance=True,
  664. date_included=date_included
  665. )
  666. subquery_sum_amounts += """
  667. ) sub
  668. GROUP BY
  669. sub.account_id, sub.partner_id
  670. """
  671. return subquery_sum_amounts
  672. def _inject_partner_values(self, only_empty_partner=False):
  673. """ Inject report values for report_general_ledger_qweb_partner.
  674. Only for "partner" accounts (payable and receivable).
  675. """
  676. # pylint: disable=sql-injection
  677. query_inject_partner = """
  678. WITH
  679. accounts_partners AS
  680. (
  681. SELECT
  682. ra.id AS report_account_id,
  683. a.id AS account_id,
  684. at.include_initial_balance AS include_initial_balance,
  685. p.id AS partner_id,
  686. COALESCE(
  687. CASE
  688. WHEN
  689. NULLIF(p.name, '') IS NOT NULL
  690. AND NULLIF(p.ref, '') IS NOT NULL
  691. THEN p.name || ' (' || p.ref || ')'
  692. ELSE p.name
  693. END,
  694. '""" + _('No partner allocated') + """'
  695. ) AS partner_name
  696. FROM
  697. report_general_ledger_qweb_account ra
  698. INNER JOIN
  699. account_account a ON ra.account_id = a.id
  700. INNER JOIN
  701. account_account_type at ON a.user_type_id = at.id
  702. INNER JOIN
  703. account_move_line ml ON a.id = ml.account_id
  704. LEFT JOIN
  705. res_partner p ON ml.partner_id = p.id
  706. """
  707. if self.filter_cost_center_ids:
  708. query_inject_partner += """
  709. INNER JOIN
  710. account_analytic_account aa
  711. ON
  712. ml.analytic_account_id = aa.id
  713. AND aa.id IN %s
  714. """
  715. if self.filter_analytic_tag_ids:
  716. query_inject_partner += """
  717. INNER JOIN
  718. account_analytic_tag_account_move_line_rel atml
  719. ON atml.account_move_line_id = ml.id
  720. INNER JOIN
  721. account_analytic_tag aat
  722. ON
  723. atml.account_analytic_tag_id = aat.id
  724. AND aat.id IN %s
  725. """
  726. query_inject_partner += """
  727. WHERE
  728. ra.report_id = %s
  729. AND
  730. ra.is_partner_account = TRUE
  731. """
  732. if not only_empty_partner:
  733. query_inject_partner += """
  734. AND
  735. p.id IS NOT NULL
  736. """
  737. else:
  738. query_inject_partner += """
  739. AND
  740. p.id IS NULL
  741. """
  742. query_inject_partner += """
  743. """
  744. if self.centralize:
  745. query_inject_partner += """
  746. AND (a.centralized IS NULL OR a.centralized != TRUE)
  747. """
  748. if self.filter_partner_ids:
  749. query_inject_partner += """
  750. AND
  751. p.id IN %s
  752. """
  753. init_subquery = self._get_final_partner_sub_subquery_sum_amounts(
  754. only_empty_partner,
  755. date_included=False
  756. )
  757. final_subquery = self._get_final_partner_sub_subquery_sum_amounts(
  758. only_empty_partner,
  759. date_included=True
  760. )
  761. query_inject_partner += """
  762. GROUP BY
  763. ra.id,
  764. a.id,
  765. p.id,
  766. at.include_initial_balance
  767. ),
  768. """
  769. if self.filter_analytic_tag_ids:
  770. query_inject_partner += """
  771. move_lines_on_tags AS
  772. (
  773. SELECT
  774. DISTINCT ml.id AS ml_id
  775. FROM
  776. accounts_partners ap
  777. INNER JOIN
  778. account_move_line ml
  779. ON ap.account_id = ml.account_id
  780. INNER JOIN
  781. account_analytic_tag_account_move_line_rel atml
  782. ON atml.account_move_line_id = ml.id
  783. INNER JOIN
  784. account_analytic_tag aat
  785. ON
  786. atml.account_analytic_tag_id = aat.id
  787. WHERE
  788. aat.id IN %s
  789. ),
  790. """
  791. query_inject_partner += """
  792. initial_sum_amounts AS ( """ + init_subquery + """ ),
  793. final_sum_amounts AS ( """ + final_subquery + """ )
  794. INSERT INTO
  795. report_general_ledger_qweb_partner
  796. (
  797. report_account_id,
  798. create_uid,
  799. create_date,
  800. partner_id,
  801. name,
  802. initial_debit,
  803. initial_credit,
  804. initial_balance,
  805. currency_id,
  806. initial_balance_foreign_currency,
  807. final_debit,
  808. final_credit,
  809. final_balance,
  810. final_balance_foreign_currency
  811. )
  812. SELECT
  813. ap.report_account_id,
  814. %s AS create_uid,
  815. NOW() AS create_date,
  816. ap.partner_id,
  817. ap.partner_name,
  818. COALESCE(i.debit, 0.0) AS initial_debit,
  819. COALESCE(i.credit, 0.0) AS initial_credit,
  820. COALESCE(i.balance, 0.0) AS initial_balance,
  821. i.currency_id AS currency_id,
  822. COALESCE(i.balance_currency, 0.0) AS initial_balance_foreign_currency,
  823. COALESCE(f.debit, 0.0) AS final_debit,
  824. COALESCE(f.credit, 0.0) AS final_credit,
  825. COALESCE(f.balance, 0.0) AS final_balance,
  826. COALESCE(f.balance_currency, 0.0) AS final_balance_foreign_currency
  827. FROM
  828. accounts_partners ap
  829. LEFT JOIN
  830. initial_sum_amounts i
  831. ON
  832. (
  833. """
  834. if not only_empty_partner:
  835. query_inject_partner += """
  836. ap.partner_id = i.partner_id
  837. """
  838. else:
  839. query_inject_partner += """
  840. ap.partner_id IS NULL AND i.partner_id IS NULL
  841. """
  842. query_inject_partner += """
  843. )
  844. AND ap.account_id = i.account_id
  845. LEFT JOIN
  846. final_sum_amounts f
  847. ON
  848. (
  849. """
  850. if not only_empty_partner:
  851. query_inject_partner += """
  852. ap.partner_id = f.partner_id
  853. """
  854. else:
  855. query_inject_partner += """
  856. ap.partner_id IS NULL AND f.partner_id IS NULL
  857. """
  858. query_inject_partner += """
  859. )
  860. AND ap.account_id = f.account_id
  861. WHERE
  862. (
  863. i.debit IS NOT NULL AND i.debit != 0
  864. OR i.credit IS NOT NULL AND i.credit != 0
  865. OR i.balance IS NOT NULL AND i.balance != 0
  866. OR f.debit IS NOT NULL AND f.debit != 0
  867. OR f.credit IS NOT NULL AND f.credit != 0
  868. OR f.balance IS NOT NULL AND f.balance != 0
  869. )
  870. """
  871. if self.hide_account_at_0:
  872. query_inject_partner += """
  873. AND
  874. f.balance IS NOT NULL AND f.balance != 0
  875. """
  876. query_inject_partner_params = ()
  877. if self.filter_cost_center_ids:
  878. query_inject_partner_params += (
  879. tuple(self.filter_cost_center_ids.ids),
  880. )
  881. if self.filter_analytic_tag_ids:
  882. query_inject_partner_params += (
  883. tuple(self.filter_analytic_tag_ids.ids),
  884. )
  885. query_inject_partner_params += (
  886. self.id,
  887. )
  888. if self.filter_partner_ids:
  889. query_inject_partner_params += (
  890. tuple(self.filter_partner_ids.ids),
  891. )
  892. if self.filter_analytic_tag_ids:
  893. query_inject_partner_params += (
  894. tuple(self.filter_analytic_tag_ids.ids),
  895. )
  896. query_inject_partner_params += (
  897. self.date_from,
  898. self.fy_start_date,
  899. )
  900. if self.filter_cost_center_ids:
  901. query_inject_partner_params += (
  902. tuple(self.filter_cost_center_ids.ids),
  903. )
  904. query_inject_partner_params += (
  905. self.date_from,
  906. )
  907. if self.filter_cost_center_ids:
  908. query_inject_partner_params += (
  909. tuple(self.filter_cost_center_ids.ids),
  910. )
  911. query_inject_partner_params += (
  912. self.date_to,
  913. self.fy_start_date,
  914. )
  915. if self.filter_cost_center_ids:
  916. query_inject_partner_params += (
  917. tuple(self.filter_cost_center_ids.ids),
  918. )
  919. query_inject_partner_params += (
  920. self.date_to,
  921. )
  922. if self.filter_cost_center_ids:
  923. query_inject_partner_params += (
  924. tuple(self.filter_cost_center_ids.ids),
  925. )
  926. query_inject_partner_params += (
  927. self.env.uid,
  928. )
  929. self.env.cr.execute(query_inject_partner, query_inject_partner_params)
  930. def _inject_line_not_centralized_values(
  931. self,
  932. is_account_line=True,
  933. is_partner_line=False,
  934. only_empty_partner_line=False,
  935. only_unaffected_earnings_account=False):
  936. """ Inject report values for report_general_ledger_qweb_move_line.
  937. If centralized option have been chosen,
  938. only non centralized accounts are computed.
  939. In function of `is_account_line` and `is_partner_line` values,
  940. the move_line link is made either with account or either with partner.
  941. The "only_empty_partner_line" value is used
  942. to compute data without partner.
  943. """
  944. query_inject_move_line = ""
  945. if self.filter_analytic_tag_ids:
  946. query_inject_move_line += """
  947. WITH
  948. move_lines_on_tags AS
  949. (
  950. SELECT
  951. DISTINCT ml.id AS ml_id
  952. FROM
  953. """
  954. if is_account_line:
  955. query_inject_move_line += """
  956. report_general_ledger_qweb_account ra
  957. """
  958. elif is_partner_line:
  959. query_inject_move_line += """
  960. report_general_ledger_qweb_partner rp
  961. INNER JOIN
  962. report_general_ledger_qweb_account ra
  963. ON rp.report_account_id = ra.id
  964. """
  965. query_inject_move_line += """
  966. INNER JOIN
  967. account_move_line ml
  968. ON ra.account_id = ml.account_id
  969. INNER JOIN
  970. account_analytic_tag_account_move_line_rel atml
  971. ON atml.account_move_line_id = ml.id
  972. INNER JOIN
  973. account_analytic_tag aat
  974. ON
  975. atml.account_analytic_tag_id = aat.id
  976. WHERE
  977. ra.report_id = %s
  978. AND
  979. aat.id IN %s
  980. )
  981. """
  982. query_inject_move_line += """
  983. INSERT INTO
  984. report_general_ledger_qweb_move_line
  985. (
  986. """
  987. if is_account_line:
  988. query_inject_move_line += """
  989. report_account_id,
  990. """
  991. elif is_partner_line:
  992. query_inject_move_line += """
  993. report_partner_id,
  994. """
  995. query_inject_move_line += """
  996. create_uid,
  997. create_date,
  998. move_line_id,
  999. matched_ml_id,
  1000. date,
  1001. entry,
  1002. journal,
  1003. account,
  1004. taxes_description,
  1005. partner,
  1006. label,
  1007. cost_center,
  1008. debit,
  1009. credit,
  1010. cumul_balance,
  1011. currency_id,
  1012. amount_currency
  1013. )
  1014. SELECT
  1015. """
  1016. if is_account_line:
  1017. query_inject_move_line += """
  1018. ra.id AS report_account_id,
  1019. """
  1020. elif is_partner_line:
  1021. query_inject_move_line += """
  1022. rp.id AS report_partner_id,
  1023. """
  1024. query_inject_move_line += """
  1025. %s AS create_uid,
  1026. NOW() AS create_date,
  1027. ml.id AS move_line_id,
  1028. fr.id AS matched_ml_id,
  1029. ml.date,
  1030. m.name AS entry,
  1031. j.code AS journal,
  1032. a.code AS account,
  1033. CASE
  1034. WHEN
  1035. ml.tax_line_id is not null
  1036. THEN
  1037. COALESCE(at.description, at.name)
  1038. WHEN
  1039. ml.tax_line_id is null
  1040. THEN
  1041. (SELECT
  1042. array_to_string(
  1043. array_agg(COALESCE(at.description, at.name)
  1044. ), ', ')
  1045. FROM
  1046. account_move_line_account_tax_rel aml_at_rel
  1047. LEFT JOIN
  1048. account_tax at on (at.id = aml_at_rel.account_tax_id)
  1049. WHERE
  1050. aml_at_rel.account_move_line_id = ml.id)
  1051. ELSE
  1052. ''
  1053. END as taxes_description,
  1054. """
  1055. if not only_empty_partner_line:
  1056. query_inject_move_line += """
  1057. CASE
  1058. WHEN
  1059. NULLIF(p.name, '') IS NOT NULL
  1060. AND NULLIF(p.ref, '') IS NOT NULL
  1061. THEN p.name || ' (' || p.ref || ')'
  1062. ELSE p.name
  1063. END AS partner,
  1064. """
  1065. elif only_empty_partner_line:
  1066. query_inject_move_line += """
  1067. '""" + _('No partner allocated') + """' AS partner,
  1068. """
  1069. query_inject_move_line += """
  1070. CONCAT_WS(' - ', NULLIF(ml.ref, ''), NULLIF(ml.name, '')) AS label,
  1071. aa.name AS cost_center,
  1072. ml.debit,
  1073. ml.credit,
  1074. """
  1075. if is_account_line:
  1076. query_inject_move_line += """
  1077. ra.initial_balance + (
  1078. SUM(ml.balance)
  1079. OVER (PARTITION BY a.code
  1080. ORDER BY a.code, ml.date, ml.id)
  1081. ) AS cumul_balance,
  1082. """
  1083. elif is_partner_line and not only_empty_partner_line:
  1084. query_inject_move_line += """
  1085. rp.initial_balance + (
  1086. SUM(ml.balance)
  1087. OVER (PARTITION BY a.code, p.name
  1088. ORDER BY a.code, p.name, ml.date, ml.id)
  1089. ) AS cumul_balance,
  1090. """
  1091. elif is_partner_line and only_empty_partner_line:
  1092. query_inject_move_line += """
  1093. rp.initial_balance + (
  1094. SUM(ml.balance)
  1095. OVER (PARTITION BY a.code
  1096. ORDER BY a.code, ml.date, ml.id)
  1097. ) AS cumul_balance,
  1098. """
  1099. query_inject_move_line += """
  1100. c.id AS currency_id,
  1101. ml.amount_currency
  1102. FROM
  1103. """
  1104. if is_account_line:
  1105. query_inject_move_line += """
  1106. report_general_ledger_qweb_account ra
  1107. """
  1108. elif is_partner_line:
  1109. query_inject_move_line += """
  1110. report_general_ledger_qweb_partner rp
  1111. INNER JOIN
  1112. report_general_ledger_qweb_account ra ON rp.report_account_id = ra.id
  1113. """
  1114. query_inject_move_line += """
  1115. INNER JOIN
  1116. account_move_line ml ON ra.account_id = ml.account_id
  1117. INNER JOIN
  1118. account_move m ON ml.move_id = m.id
  1119. INNER JOIN
  1120. account_journal j ON ml.journal_id = j.id
  1121. INNER JOIN
  1122. account_account a ON ml.account_id = a.id
  1123. LEFT JOIN
  1124. account_tax at ON ml.tax_line_id = at.id
  1125. """
  1126. if is_account_line:
  1127. query_inject_move_line += """
  1128. LEFT JOIN
  1129. res_partner p ON ml.partner_id = p.id
  1130. """
  1131. elif is_partner_line and not only_empty_partner_line:
  1132. query_inject_move_line += """
  1133. INNER JOIN
  1134. res_partner p
  1135. ON ml.partner_id = p.id AND rp.partner_id = p.id
  1136. """
  1137. query_inject_move_line += """
  1138. LEFT JOIN
  1139. account_full_reconcile fr ON ml.full_reconcile_id = fr.id
  1140. LEFT JOIN
  1141. res_currency c ON ml.currency_id = c.id
  1142. """
  1143. if self.filter_cost_center_ids:
  1144. query_inject_move_line += """
  1145. INNER JOIN
  1146. account_analytic_account aa
  1147. ON
  1148. ml.analytic_account_id = aa.id
  1149. AND aa.id IN %s
  1150. """
  1151. else:
  1152. query_inject_move_line += """
  1153. LEFT JOIN
  1154. account_analytic_account aa ON ml.analytic_account_id = aa.id
  1155. """
  1156. if self.filter_analytic_tag_ids:
  1157. query_inject_move_line += """
  1158. INNER JOIN
  1159. move_lines_on_tags ON ml.id = move_lines_on_tags.ml_id
  1160. """
  1161. query_inject_move_line += """
  1162. WHERE
  1163. ra.report_id = %s
  1164. AND
  1165. """
  1166. if only_unaffected_earnings_account:
  1167. query_inject_move_line += """
  1168. a.id = %s
  1169. AND
  1170. """
  1171. if is_account_line:
  1172. query_inject_move_line += """
  1173. (ra.is_partner_account IS NULL OR ra.is_partner_account != TRUE)
  1174. """
  1175. elif is_partner_line:
  1176. query_inject_move_line += """
  1177. ra.is_partner_account = TRUE
  1178. """
  1179. if self.centralize:
  1180. query_inject_move_line += """
  1181. AND
  1182. (a.centralized IS NULL OR a.centralized != TRUE)
  1183. """
  1184. query_inject_move_line += """
  1185. AND
  1186. ml.date BETWEEN %s AND %s
  1187. """
  1188. if self.only_posted_moves:
  1189. query_inject_move_line += """
  1190. AND
  1191. m.state = 'posted'
  1192. """
  1193. if only_empty_partner_line:
  1194. query_inject_move_line += """
  1195. AND
  1196. ml.partner_id IS NULL
  1197. AND
  1198. rp.partner_id IS NULL
  1199. """
  1200. if self.filter_journal_ids:
  1201. query_inject_move_line += """
  1202. AND
  1203. j.id IN %s
  1204. """
  1205. if is_account_line:
  1206. query_inject_move_line += """
  1207. ORDER BY
  1208. a.code, ml.date, ml.id
  1209. """
  1210. elif is_partner_line and not only_empty_partner_line:
  1211. query_inject_move_line += """
  1212. ORDER BY
  1213. a.code, p.name, ml.date, ml.id
  1214. """
  1215. elif is_partner_line and only_empty_partner_line:
  1216. query_inject_move_line += """
  1217. ORDER BY
  1218. a.code, ml.date, ml.id
  1219. """
  1220. query_inject_move_line_params = ()
  1221. if self.filter_analytic_tag_ids:
  1222. query_inject_move_line_params += (
  1223. self.id,
  1224. tuple(self.filter_analytic_tag_ids.ids),
  1225. )
  1226. query_inject_move_line_params += (
  1227. self.env.uid,
  1228. )
  1229. if self.filter_cost_center_ids:
  1230. query_inject_move_line_params += (
  1231. tuple(self.filter_cost_center_ids.ids),
  1232. )
  1233. query_inject_move_line_params += (
  1234. self.id,
  1235. )
  1236. if only_unaffected_earnings_account:
  1237. query_inject_move_line_params += (
  1238. self.unaffected_earnings_account.id,
  1239. )
  1240. query_inject_move_line_params += (
  1241. self.date_from,
  1242. self.date_to,
  1243. )
  1244. if self.filter_journal_ids:
  1245. query_inject_move_line_params += (tuple(
  1246. self.filter_journal_ids.ids,
  1247. ),)
  1248. self.env.cr.execute(
  1249. query_inject_move_line,
  1250. query_inject_move_line_params
  1251. )
  1252. def _inject_line_centralized_values(self):
  1253. """ Inject report values for report_general_ledger_qweb_move_line.
  1254. Only centralized accounts are computed.
  1255. """
  1256. if self.filter_analytic_tag_ids:
  1257. query_inject_move_line_centralized = """
  1258. WITH
  1259. move_lines_on_tags AS
  1260. (
  1261. SELECT
  1262. DISTINCT ml.id AS ml_id
  1263. FROM
  1264. report_general_ledger_qweb_account ra
  1265. INNER JOIN
  1266. account_move_line ml
  1267. ON ra.account_id = ml.account_id
  1268. INNER JOIN
  1269. account_analytic_tag_account_move_line_rel atml
  1270. ON atml.account_move_line_id = ml.id
  1271. INNER JOIN
  1272. account_analytic_tag aat
  1273. ON
  1274. atml.account_analytic_tag_id = aat.id
  1275. WHERE
  1276. ra.report_id = %s
  1277. AND
  1278. aat.id IN %s
  1279. ),
  1280. """
  1281. else:
  1282. query_inject_move_line_centralized = """
  1283. WITH
  1284. """
  1285. query_inject_move_line_centralized += """
  1286. move_lines AS
  1287. (
  1288. SELECT
  1289. ml.account_id,
  1290. (
  1291. DATE_TRUNC('month', ml.date) + interval '1 month'
  1292. - interval '1 day'
  1293. )::date AS date,
  1294. SUM(ml.debit) AS debit,
  1295. SUM(ml.credit) AS credit,
  1296. SUM(ml.balance) AS balance,
  1297. ml.currency_id AS currency_id,
  1298. ml.journal_id as journal_id
  1299. FROM
  1300. report_general_ledger_qweb_account ra
  1301. INNER JOIN
  1302. account_move_line ml ON ra.account_id = ml.account_id
  1303. INNER JOIN
  1304. account_move m ON ml.move_id = m.id
  1305. INNER JOIN
  1306. account_account a ON ml.account_id = a.id
  1307. """
  1308. if self.filter_cost_center_ids:
  1309. query_inject_move_line_centralized += """
  1310. INNER JOIN
  1311. account_analytic_account aa
  1312. ON
  1313. ml.analytic_account_id = aa.id
  1314. AND aa.id IN %s
  1315. """
  1316. if self.filter_analytic_tag_ids:
  1317. query_inject_move_line_centralized += """
  1318. INNER JOIN
  1319. move_lines_on_tags ON ml.id = move_lines_on_tags.ml_id
  1320. """
  1321. query_inject_move_line_centralized += """
  1322. WHERE
  1323. ra.report_id = %s
  1324. AND
  1325. a.centralized = TRUE
  1326. AND
  1327. ml.date BETWEEN %s AND %s
  1328. """
  1329. if self.only_posted_moves:
  1330. query_inject_move_line_centralized += """
  1331. AND
  1332. m.state = 'posted'
  1333. """
  1334. query_inject_move_line_centralized += """
  1335. GROUP BY
  1336. ra.id, ml.account_id, a.code, 2, ml.currency_id, ml.journal_id
  1337. )
  1338. INSERT INTO
  1339. report_general_ledger_qweb_move_line
  1340. (
  1341. report_account_id,
  1342. create_uid,
  1343. create_date,
  1344. date,
  1345. account,
  1346. journal,
  1347. label,
  1348. debit,
  1349. credit,
  1350. cumul_balance
  1351. )
  1352. SELECT
  1353. ra.id AS report_account_id,
  1354. %s AS create_uid,
  1355. NOW() AS create_date,
  1356. ml.date,
  1357. a.code AS account,
  1358. j.code as journal,
  1359. '""" + _('Centralized Entries') + """' AS label,
  1360. ml.debit AS debit,
  1361. ml.credit AS credit,
  1362. ra.initial_balance + (
  1363. SUM(ml.balance)
  1364. OVER (PARTITION BY a.code ORDER BY ml.date)
  1365. ) AS cumul_balance
  1366. FROM
  1367. report_general_ledger_qweb_account ra
  1368. INNER JOIN
  1369. move_lines ml ON ra.account_id = ml.account_id
  1370. INNER JOIN
  1371. account_account a ON ml.account_id = a.id
  1372. INNER JOIN
  1373. account_journal j ON ml.journal_id = j.id
  1374. LEFT JOIN
  1375. res_currency c ON ml.currency_id = c.id
  1376. WHERE
  1377. ra.report_id = %s
  1378. AND
  1379. (a.centralized IS NOT NULL AND a.centralized = TRUE)
  1380. """
  1381. if self.filter_journal_ids:
  1382. query_inject_move_line_centralized += """
  1383. AND
  1384. j.id in %s
  1385. """
  1386. query_inject_move_line_centralized += """
  1387. ORDER BY
  1388. a.code, ml.date
  1389. """
  1390. query_inject_move_line_centralized_params = ()
  1391. if self.filter_analytic_tag_ids:
  1392. query_inject_move_line_centralized_params += (
  1393. self.id,
  1394. tuple(self.filter_analytic_tag_ids.ids),
  1395. )
  1396. if self.filter_cost_center_ids:
  1397. query_inject_move_line_centralized_params += (
  1398. tuple(self.filter_cost_center_ids.ids),
  1399. )
  1400. query_inject_move_line_centralized_params += (
  1401. self.id,
  1402. self.date_from,
  1403. self.date_to,
  1404. self.env.uid,
  1405. self.id,
  1406. )
  1407. if self.filter_journal_ids:
  1408. query_inject_move_line_centralized_params += (tuple(
  1409. self.filter_journal_ids.ids,
  1410. ),)
  1411. self.env.cr.execute(
  1412. query_inject_move_line_centralized,
  1413. query_inject_move_line_centralized_params
  1414. )
  1415. def _compute_analytic_tags(self):
  1416. """ Compute "tags" column"""
  1417. query_update_analytic_tags = """
  1418. UPDATE
  1419. report_general_ledger_qweb_move_line
  1420. SET
  1421. tags = tags_values.tags
  1422. FROM
  1423. (
  1424. (
  1425. SELECT
  1426. rml.id AS report_id,
  1427. array_to_string(array_agg(t.name ORDER BY t.name), ',') AS tags
  1428. FROM
  1429. account_move_line ml
  1430. INNER JOIN
  1431. report_general_ledger_qweb_move_line rml
  1432. ON ml.id = rml.move_line_id
  1433. INNER JOIN
  1434. report_general_ledger_qweb_account ra
  1435. ON rml.report_account_id = ra.id
  1436. INNER JOIN
  1437. account_analytic_tag_account_move_line_rel tml
  1438. ON ml.id = tml.account_move_line_id
  1439. INNER JOIN
  1440. account_analytic_tag t
  1441. ON tml.account_analytic_tag_id = t.id
  1442. WHERE
  1443. ra.report_id = %(report_id)s
  1444. GROUP BY
  1445. rml.id,
  1446. ml.id
  1447. )
  1448. UNION
  1449. (
  1450. SELECT
  1451. rml.id AS report_id,
  1452. array_to_string(array_agg(t.name ORDER BY t.name), ',') AS tags
  1453. FROM
  1454. account_move_line ml
  1455. INNER JOIN
  1456. report_general_ledger_qweb_move_line rml
  1457. ON ml.id = rml.move_line_id
  1458. INNER JOIN
  1459. report_general_ledger_qweb_partner rp
  1460. ON rml.report_partner_id = rp.id
  1461. INNER JOIN
  1462. report_general_ledger_qweb_account ra
  1463. ON rp.report_account_id = ra.id
  1464. INNER JOIN
  1465. account_analytic_tag_account_move_line_rel tml
  1466. ON ml.id = tml.account_move_line_id
  1467. INNER JOIN
  1468. account_analytic_tag t
  1469. ON tml.account_analytic_tag_id = t.id
  1470. WHERE
  1471. ra.report_id = %(report_id)s
  1472. GROUP BY
  1473. rml.id,
  1474. ml.id
  1475. )
  1476. ) AS tags_values
  1477. WHERE
  1478. report_general_ledger_qweb_move_line.id = tags_values.report_id
  1479. """
  1480. params = {
  1481. 'report_id': self.id,
  1482. }
  1483. self.env.cr.execute(query_update_analytic_tags, params)
  1484. def _inject_unaffected_earnings_account_values(self):
  1485. """Inject the report values of the unaffected earnings account
  1486. for report_general_ledger_qweb_account."""
  1487. # Fetch the profit and loss accounts
  1488. query_unaffected_earnings_account_ids = """
  1489. SELECT a.id
  1490. FROM account_account as a
  1491. INNER JOIN account_account_type as at
  1492. ON at.id = a.user_type_id
  1493. WHERE at.include_initial_balance = FALSE
  1494. """
  1495. self.env.cr.execute(query_unaffected_earnings_account_ids)
  1496. pl_account_ids = [r[0] for r in self.env.cr.fetchall()]
  1497. unaffected_earnings_account_ids = \
  1498. pl_account_ids + [self.unaffected_earnings_account.id]
  1499. # Fetch the current fiscal year start date
  1500. date = fields.Datetime.from_string(self.date_from)
  1501. res = self.company_id.compute_fiscalyear_dates(date)
  1502. fy_start_date = res['date_from']
  1503. query_select_previous_fy_unaffected_earnings_params = {
  1504. 'date_to': fy_start_date,
  1505. 'company_id': self.company_id.id,
  1506. 'account_ids': tuple(unaffected_earnings_account_ids),
  1507. 'analytic_tag_ids': tuple(self.filter_analytic_tag_ids.ids),
  1508. }
  1509. query_select_previous_fy_unaffected_earnings = ''
  1510. q_analytic_tags = ''
  1511. if self.filter_analytic_tag_ids:
  1512. q_analytic_tags = """
  1513. WITH move_lines_on_tags AS
  1514. (
  1515. SELECT
  1516. DISTINCT ml.id AS ml_id
  1517. FROM
  1518. account_account a
  1519. INNER JOIN
  1520. account_move_line ml
  1521. ON a.id = ml.account_id
  1522. INNER JOIN
  1523. account_analytic_tag_account_move_line_rel atml
  1524. ON atml.account_move_line_id = ml.id
  1525. INNER JOIN
  1526. account_analytic_tag aat
  1527. ON
  1528. atml.account_analytic_tag_id = aat.id
  1529. WHERE
  1530. aat.id IN %(analytic_tag_ids)s
  1531. )
  1532. """
  1533. query_select_previous_fy_unaffected_earnings += q_analytic_tags
  1534. query_select_previous_fy_unaffected_earnings += """
  1535. SELECT sum(ml.balance) as balance
  1536. FROM account_move_line as ml
  1537. INNER JOIN account_move as am
  1538. ON am.id = ml.move_id
  1539. INNER JOIN account_journal j
  1540. ON am.journal_id = j.id
  1541. """
  1542. if self.filter_cost_center_ids:
  1543. query_select_previous_fy_unaffected_earnings += """
  1544. INNER JOIN account_analytic_account aa
  1545. ON ml.analytic_account_id = aa.id
  1546. AND aa.id IN %(cost_center_ids)s
  1547. """
  1548. query_select_previous_fy_unaffected_earnings_params[
  1549. 'cost_center_ids'] = tuple(self.filter_cost_center_ids.ids)
  1550. if self.filter_analytic_tag_ids:
  1551. query_select_previous_fy_unaffected_earnings += """
  1552. INNER JOIN move_lines_on_tags ON ml.id =
  1553. move_lines_on_tags.ml_id
  1554. """
  1555. query_select_previous_fy_unaffected_earnings += """
  1556. WHERE ml.date < %(date_to)s
  1557. AND ml.company_id = %(company_id)s
  1558. AND ml.account_id IN %(account_ids)s
  1559. """
  1560. if self.filter_journal_ids:
  1561. query_select_previous_fy_unaffected_earnings += """
  1562. AND j.id IN %(journal_ids)s
  1563. """
  1564. query_select_previous_fy_unaffected_earnings_params[
  1565. 'journal_ids'] = tuple(self.filter_journal_ids.ids)
  1566. if self.only_posted_moves:
  1567. query_select_previous_fy_unaffected_earnings += """
  1568. AND am.state = 'posted'
  1569. """
  1570. self.env.cr.execute(
  1571. query_select_previous_fy_unaffected_earnings,
  1572. query_select_previous_fy_unaffected_earnings_params)
  1573. res = self.env.cr.fetchone()
  1574. unaffected_earnings_initial_balance = res[0] or 0.0
  1575. # Now select the current period unaffected earnings,
  1576. # excluding the current period P&L.
  1577. query_select_period_unaffected_earnings_params = {
  1578. 'date_from': self.date_from,
  1579. 'date_to': self.date_to,
  1580. 'company_id': self.company_id.id,
  1581. 'unaffected_earnings_id': self.unaffected_earnings_account.id,
  1582. 'analytic_tag_ids': tuple(self.filter_analytic_tag_ids.ids),
  1583. }
  1584. query_select_period_unaffected_earnings = ''
  1585. if self.filter_analytic_tag_ids:
  1586. query_select_period_unaffected_earnings += q_analytic_tags
  1587. query_select_period_unaffected_earnings += """
  1588. SELECT
  1589. sum(ml.debit) as sum_debit,
  1590. sum(ml.credit) as sum_credit,
  1591. sum(ml.balance) as balance
  1592. FROM account_move_line as ml
  1593. INNER JOIN account_move as am
  1594. ON am.id = ml.move_id
  1595. INNER JOIN account_journal j
  1596. ON am.journal_id = j.id
  1597. """
  1598. if self.filter_cost_center_ids:
  1599. query_select_period_unaffected_earnings += """
  1600. INNER JOIN account_analytic_account aa
  1601. ON ml.analytic_account_id = aa.id
  1602. AND aa.id IN %(cost_center_ids)s
  1603. """
  1604. query_select_period_unaffected_earnings_params[
  1605. 'cost_center_ids'] = tuple(self.filter_cost_center_ids.ids)
  1606. if self.filter_analytic_tag_ids:
  1607. query_select_period_unaffected_earnings += """
  1608. INNER JOIN move_lines_on_tags
  1609. ON ml.id = move_lines_on_tags.ml_id
  1610. """
  1611. query_select_period_unaffected_earnings += """
  1612. WHERE am.date >= %(date_from)s
  1613. AND ml.date <= %(date_to)s
  1614. AND ml.company_id = %(company_id)s
  1615. AND ml.account_id = %(unaffected_earnings_id)s
  1616. """
  1617. if self.filter_journal_ids:
  1618. query_select_period_unaffected_earnings += """
  1619. AND j.id IN %(journal_ids)s
  1620. """
  1621. query_select_period_unaffected_earnings_params[
  1622. 'journal_ids'] = tuple(self.filter_journal_ids.ids)
  1623. if self.only_posted_moves:
  1624. query_select_period_unaffected_earnings += """
  1625. AND am.state = 'posted'
  1626. """
  1627. self.env.cr.execute(query_select_period_unaffected_earnings,
  1628. query_select_period_unaffected_earnings_params)
  1629. res = self.env.cr.fetchone()
  1630. unaffected_earnings_period_debit = res[0] or 0.0
  1631. unaffected_earnings_period_credit = res[1] or 0.0
  1632. unaffected_earnings_period_balance = res[2] or 0.0
  1633. # pylint: disable=sql-injection
  1634. query_inject_account = """
  1635. INSERT INTO
  1636. report_general_ledger_qweb_account (
  1637. report_id,
  1638. create_uid,
  1639. create_date,
  1640. account_id,
  1641. code,
  1642. name,
  1643. is_partner_account,
  1644. initial_debit,
  1645. initial_credit,
  1646. initial_balance,
  1647. final_debit,
  1648. final_credit,
  1649. final_balance
  1650. )
  1651. VALUES (
  1652. %(report_id)s,
  1653. %(user_id)s,
  1654. NOW(),
  1655. %(account_id)s,
  1656. %(code)s,
  1657. %(name)s,
  1658. False,
  1659. %(initial_debit)s,
  1660. %(initial_credit)s,
  1661. %(initial_balance)s,
  1662. %(final_debit)s,
  1663. %(final_credit)s,
  1664. %(final_balance)s
  1665. )
  1666. """
  1667. initial_debit = unaffected_earnings_initial_balance >= 0 and \
  1668. unaffected_earnings_initial_balance or 0
  1669. initial_credit = unaffected_earnings_initial_balance < 0 and \
  1670. -1 * unaffected_earnings_initial_balance or 0
  1671. final_balance = unaffected_earnings_initial_balance + \
  1672. unaffected_earnings_period_balance
  1673. query_inject_account_params = {
  1674. 'report_id': self.id,
  1675. 'user_id': self.env.uid,
  1676. 'account_id': self.unaffected_earnings_account.id,
  1677. 'code': self.unaffected_earnings_account.code,
  1678. 'name': self.unaffected_earnings_account.name,
  1679. 'initial_debit': initial_debit,
  1680. 'initial_credit': initial_credit,
  1681. 'initial_balance': unaffected_earnings_initial_balance,
  1682. 'final_debit': initial_debit + unaffected_earnings_period_debit,
  1683. 'final_credit': initial_credit + unaffected_earnings_period_credit,
  1684. 'final_balance': final_balance,
  1685. }
  1686. self.env.cr.execute(query_inject_account,
  1687. query_inject_account_params)