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.

1416 lines
43 KiB

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