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.

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