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.

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