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.

1770 lines
58 KiB

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