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.

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