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.

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