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.

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