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.

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