Browse Source

new module bi_sql_editor [IMP] function to guess model for many2one field; [ADD] security

pull/162/head
Sylvain LE GAL 8 years ago
committed by Darshan Patel
parent
commit
b2df6dfd17
  1. 184
      bi_sql_editor/README.rst
  2. 3
      bi_sql_editor/__init__.py
  3. 28
      bi_sql_editor/__openerp__.py
  4. 59
      bi_sql_editor/demo/bi_sql_view.xml
  5. 18
      bi_sql_editor/demo/res_groups.xml
  6. 4
      bi_sql_editor/models/__init__.py
  7. 495
      bi_sql_editor/models/bi_sql_view.py
  8. 194
      bi_sql_editor/models/bi_sql_view_field.py
  9. 6
      bi_sql_editor/security/ir.model.access.csv
  10. BIN
      bi_sql_editor/static/description/01_sql_request.png
  11. BIN
      bi_sql_editor/static/description/02_security_access.png
  12. BIN
      bi_sql_editor/static/description/03_field_mapping.png
  13. BIN
      bi_sql_editor/static/description/04_materialized_view_setting.png
  14. BIN
      bi_sql_editor/static/description/05_reporting_pie.png
  15. BIN
      bi_sql_editor/static/description/05_reporting_pivot.png
  16. BIN
      bi_sql_editor/static/description/icon.png
  17. BIN
      bi_sql_editor/static/description/main_screenshot.png
  18. 18
      bi_sql_editor/views/action.xml
  19. 20
      bi_sql_editor/views/menu.xml
  20. 126
      bi_sql_editor/views/view_bi_sql_view.xml

184
bi_sql_editor/README.rst

@ -0,0 +1,184 @@
.. image:: https://img.shields.io/badge/licence-AGPL--3-blue.svg
:target: http://www.gnu.org/licenses/agpl-3.0-standalone.html
:alt: License: AGPL-3
===========================================================
BI Views builder, based on Materialized or Normal SQL Views
===========================================================
This module extends the functionality of reporting, to support creation
of extra custom reports.
It allows user to write a custom SQL request. (Generally, admin users)
Once written, a new model is generated, and user can map the selected field
with odoo fields.
Then user ends the process, creating new menu, action and graph view.
Technically, the module create SQL View (or materialized view, if option is
checked). Materialized view duplicates datas, but request are fastest. If
materialized view is enabled, this module will create a cron task to refresh
the data).
By default, users member of 'SQL Request / User' can see all the views.
You can specify extra groups that have the right to access to a specific view.
Warning
-------
This module is intended for technician people in a company and for Odoo integrators.
It requires the user to know SQL syntax and Odoo models.
If you don't have such skills, do not try to use this module specially on a production
environment.
Use Cases
---------
this module is interesting for the following use cases
* You want to realize technical SQL requests, that Odoo framework doesn't allow
(For exemple, UNION with many SELECT) A typical use case is if you want to have
Sale Orders and PoS Orders datas in a same table
* You want to customize an Odoo report, removing some useless fields and adding
some custom ones. In that case, you can simply select the fields of the original
report (sale.report model for exemple), and add your custom fields
* You have a lot of data, and classical SQL Views have very bad performance.
In that case, MATERIALIZED VIEW will be a good solution to reduce display duration
Configuration
=============
To configure this module, you need to:
* Go to Settings / Technical / Database Structure / SQL Views
* tip your SQL request
.. figure:: /bi_sql_editor/static/description/01_sql_request.png
:width: 800 px
* Select the group(s) that could have access to the view
.. figure:: /bi_sql_editor/static/description/02_security_access.png
:width: 800 px
* Click on the button 'Clean and Check Request'
* Once the sql request checked, the module analyses the column of the view,
and propose field mapping. For each field, you can decide to create an index
and set if it will be displayed on the pivot graph as a column, a row or a
measure.
.. figure:: /bi_sql_editor/static/description/03_field_mapping.png
:width: 800 px
* Click on the button 'Create SQL View, Indexes and Models'. (this step could
take a while, if view is materialized)
* If it's a MATERIALIZED view:
* a cron task is created to refresh
the view. You can so define the frequency of the refresh.
* the size of view (and the indexes is displayed)
.. figure:: /bi_sql_editor/static/description/04_materialized_view_setting.png
:width: 800 px
* Finally, click on 'Create UI', to create new menu, action, graph view and
search view.
Usage
=====
To use this module, you need to:
* Go to 'Reporting' / 'Custom Reports'
* select the desired report
.. figure:: /bi_sql_editor/static/description/05_reporting_pivot.png
:width: 800 px
* You can switch to 'Pie' chart or 'Line Chart' as any report,
.. figure:: /bi_sql_editor/static/description/05_reporting_pie.png
:width: 800 px
.. image:: https://odoo-community.org/website/image/ir.attachment/5784_f2813bd/datas
:alt: Try me on Runbot
:target: https://runbot.odoo-community.org/runbot/143/8.0
Known issues / Roadmap
======================
* Add 'interval', after type (row/col/measure) field for date(time) fields.
* Dinamically change displayed action name to mention the last refresh of the
materialized view.
* Create ir.rule to limit access. (for company_id for exemple)
Note
====
The syntax of the sql request has the following constrains:
* the name of the selectable columns should be prefixed by `x_`
Sample:
.. code-block:: sql
SELECT name as x_name
FROM res_partner
Bug Tracker
===========
Bugs are tracked on `GitHub Issues
<https://github.com/OCA/reporting-engine/issues>`_. In case of trouble, please
check there if your issue has already been reported. If you spotted it first,
help us smash it by providing detailed and welcomed feedback.
Credits
=======
Contributors
------------
* Sylvain LE GAL (https://twitter.com/legalsylvain)
* This module is highly inspired by the work of
* Onestein: (http://www.onestein.nl/)
Module: OCA/server-tools/bi_view_editor.
Link: https://github.com/OCA/reporting-engine/tree/8.0/bi_view_editor
* Anybox: (https://anybox.fr/)
Module : OCA/server-tools/materialized_sql_view
link: https://github.com/OCA/server-tools/pull/110
* GRAP, Groupement Régional Alimentaire de Proximité: (http://www.grap.coop/)
Module: grap/odoo-addons-misc/pos_sale_reporting
link: https://github.com/grap/odoo-addons-misc/tree/7.0/pos_sale_reporting
Funders
-------
The development of this module has been financially supported by:
* GRAP, Groupement Régional Alimentaire de Proximité (http://www.grap.coop)
Maintainer
----------
.. image:: https://odoo-community.org/logo.png
:alt: Odoo Community Association
:target: https://odoo-community.org
This module is maintained by the OCA.
OCA, or the Odoo Community Association, is a nonprofit organization whose
mission is to support the collaborative development of Odoo features and
promote its widespread use.
To contribute to this module, please visit https://odoo-community.org.

3
bi_sql_editor/__init__.py

@ -0,0 +1,3 @@
# -*- coding: utf-8 -*-
from . import models

28
bi_sql_editor/__openerp__.py

@ -0,0 +1,28 @@
# -*- coding: utf-8 -*-
# Copyright (C) 2017 - Today: GRAP (http://www.grap.coop)
# @author: Sylvain LE GAL (https://twitter.com/legalsylvain)
# License AGPL-3.0 or later (http://www.gnu.org/licenses/agpl.html).
{
'name': 'BI SQL Editor',
'summary': "BI Views builder, based on Materialized or Normal SQL Views",
'version': '8.0.1.0.0',
'license': 'AGPL-3',
'category': 'Reporting',
'author': 'GRAP,Odoo Community Association (OCA)',
'website': 'https://www.odoo-community.org',
'depends': [
'sql_request_abstract',
],
'data': [
'security/ir.model.access.csv',
'views/view_bi_sql_view.xml',
'views/action.xml',
'views/menu.xml',
],
'demo': [
'demo/res_groups.xml',
'demo/bi_sql_view.xml',
],
'installable': True,
}

59
bi_sql_editor/demo/bi_sql_view.xml

@ -0,0 +1,59 @@
<?xml version="1.0" encoding="UTF-8"?>
<!--
Copyright (C) 2014 - Today GRAP (http://www.grap.coop)
@author Sylvain LE GAL (https://twitter.com/legalsylvain)
License AGPL-3.0 or later (http://www.gnu.org/licenses/agpl).
-->
<openerp><data>
<record id="incorrect_sql_view" model="bi.sql.view">
<field name="name">Draft Incorrect SQL View</field>
<field name="technical_name">incorrect_view</field>
<field name="query"><![CDATA[
SELECT *
FROM unexisting_table
ORDER BY unexisting_field
]]>
</field>
</record>
<record id="partner_sql_view" model="bi.sql.view">
<field name="name">Partners View</field>
<field name="technical_name">partners_view</field>
<field name="query"><![CDATA[
SELECT
name as x_name,
street as x_street,
company_id as x_company_id
FROM res_partner
ORDER BY name
]]>
</field>
</record>
<function model="bi.sql.view" name="button_validate_sql_expression" eval="([ref('partner_sql_view')])"/>
<record id="module_sql_view" model="bi.sql.view">
<field name="name">Modules by Authors</field>
<field name="technical_name">modules_view</field>
<field name="is_materialized" eval="0" />
<field name="query"><![CDATA[
SELECT
name as x_name,
case
when author ilike '%OpenERP SA%' THEN 'Odoo SA'
when author ilike '%Odoo Community Association (OCA)%' THEN 'OCA'
else 'Undefined Author' END as x_author_type
FROM ir_module_module
]]>
</field>
</record>
<function model="bi.sql.view" name="button_validate_sql_expression" eval="([ref('module_sql_view')])"/>
<function model="bi.sql.view" name="button_create_sql_view_and_model" eval="([ref('module_sql_view')])"/>
<function model="bi.sql.view" name="button_create_ui" eval="([ref('module_sql_view')])"/>
</data></openerp>

18
bi_sql_editor/demo/res_groups.xml

@ -0,0 +1,18 @@
<?xml version="1.0" encoding="UTF-8"?>
<!--
Copyright (C) 2014 - Today GRAP (http://www.grap.coop)
@author Sylvain LE GAL (https://twitter.com/legalsylvain)
License AGPL-3.0 or later (http://www.gnu.org/licenses/agpl).
-->
<openerp><data>
<record id="base.group_no_one" model="res.groups">
<field name="users" eval="[(4, ref('base.user_root'))]" />
</record>
<record id="sql_request_abstract.group_sql_request_user" model="res.groups">
<field name="users" eval="[(4, ref('base.user_demo'))]" />
</record>
</data></openerp>

4
bi_sql_editor/models/__init__.py

@ -0,0 +1,4 @@
# -*- coding: utf-8 -*-
from . import bi_sql_view
from . import bi_sql_view_field

495
bi_sql_editor/models/bi_sql_view.py

@ -0,0 +1,495 @@
# -*- coding: utf-8 -*-
# Copyright (C) 2017 - Today: GRAP (http://www.grap.coop)
# @author: Sylvain LE GAL (https://twitter.com/legalsylvain)
# License AGPL-3.0 or later (http://www.gnu.org/licenses/agpl.html).
import logging
from psycopg2 import ProgrammingError
from openerp import _, api, fields, models, SUPERUSER_ID
from openerp.exceptions import Warning as UserError
_logger = logging.getLogger(__name__)
class BiSQLView(models.Model):
_name = 'bi.sql.view'
_inherit = ['sql.request.mixin']
_sql_prefix = 'x_bi_sql_view_'
_model_prefix = 'x_bi_sql_view.'
_sql_request_groups_relation = 'bi_sql_view_groups_rel'
_sql_request_users_relation = 'bi_sql_view_users_rel'
_STATE_SQL_EDITOR = [
('model_valid', 'SQL View and Model Created'),
('ui_valid', 'Graph, action and Menu Created'),
]
technical_name = fields.Char(
string='Technical Name', required=True,
help="Suffix of the SQL view. (SQL full name will be computed and"
" prefixed by 'x_bi_sql_view_'. Should have correct"
"syntax. For more information, see https://www.postgresql.org/"
"docs/current/static/sql-syntax-lexical.html#SQL-SYNTAX-IDENTIFIERS")
view_name = fields.Char(
string='View Name', compute='_compute_view_name', readonly=True,
store=True, help="Full name of the SQL view")
model_name = fields.Char(
string='Model Name', compute='_compute_model_name', readonly=True,
store=True, help="Full Qualified Name of the transient model that will"
" be created.")
is_materialized = fields.Boolean(
string='Is Materialized View', default=True, readonly=True,
states={'draft': [('readonly', False)]})
materialized_text = fields.Char(
compute='_compute_materialized_text', store=True)
size = fields.Char(
string='Database Size', readonly=True,
help="Size of the materialized view and its indexes")
state = fields.Selection(selection_add=_STATE_SQL_EDITOR)
query = fields.Text(
help="SQL Request that will be inserted as the view. Take care to :\n"
" * set a name for all your selected fields, specially if you use"
" SQL function (like EXTRACT, ...);\n"
" * Do not use 'SELECT *' or 'SELECT table.*';\n"
" * prefix the name of the selectable columns by 'x_';",
default="SELECT\n"
" my_field as x_my_field\n"
"FROM my_table")
domain_force = fields.Text(
string='Extra Rule Definition', default="[]", help="Define here"
" access restriction to data.\n"
" Take care to use field name prefixed by 'x_'."
" A global 'ir.rule' will be created."
" A typical Multi Company rule is for exemple \n"
" ['|', ('x_company_id','child_of', [user.company_id.id]),"
"('x_company_id','=',False)].")
has_group_changed = fields.Boolean(copy=False)
bi_sql_view_field_ids = fields.One2many(
string='SQL Fields', comodel_name='bi.sql.view.field',
inverse_name='bi_sql_view_id')
model_id = fields.Many2one(
string='Odoo Model', comodel_name='ir.model', readonly=True)
graph_view_id = fields.Many2one(
string='Odoo Graph View', comodel_name='ir.ui.view', readonly=True)
search_view_id = fields.Many2one(
string='Odoo Search View', comodel_name='ir.ui.view', readonly=True)
action_id = fields.Many2one(
string='Odoo Action', comodel_name='ir.actions.act_window',
readonly=True)
menu_id = fields.Many2one(
string='Odoo Menu', comodel_name='ir.ui.menu', readonly=True)
cron_id = fields.Many2one(
string='Odoo Cron', comodel_name='ir.cron', readonly=True,
help="Cron Task that will refresh the materialized view")
rule_id = fields.Many2one(
string='Odoo Rule', comodel_name='ir.rule', readonly=True)
# Compute Section
@api.depends('is_materialized')
@api.multi
def _compute_materialized_text(self):
for sql_view in self:
sql_view.materialized_text =\
sql_view.is_materialized and 'MATERIALIZED' or ''
@api.depends('technical_name')
@api.multi
def _compute_view_name(self):
for sql_view in self:
sql_view.view_name = '%s%s' % (
sql_view._sql_prefix, sql_view.technical_name)
@api.depends('technical_name')
@api.multi
def _compute_model_name(self):
for sql_view in self:
sql_view.model_name = '%s%s' % (
sql_view._model_prefix, sql_view.technical_name)
@api.onchange('group_ids')
def onchange_group_ids(self):
if self.state not in ('draft', 'sql_valid'):
self.has_group_changed = True
# Overload Section
@api.multi
def unlink(self):
non_draft_views = self.search([
('id', 'in', self.ids),
('state', 'not in', ('draft', 'sql_valid'))])
if non_draft_views:
raise UserError(_("You can only unlink draft views"))
return self.unlink()
@api.multi
def copy(self, default=None):
self.ensure_one()
default = dict(default or {})
default.update({
'name': _('%s (Copy)') % (self.name),
'technical_name': '%s_copy' % (self.technical_name),
})
return super(BiSQLView, self).copy(default=default)
# Action Section
@api.multi
def button_create_sql_view_and_model(self):
for sql_view in self:
if sql_view.state != 'sql_valid':
raise UserError(_(
"You can only process this action on SQL Valid items"))
# Create ORM and acess
sql_view._create_model_and_fields()
sql_view._create_model_access()
# Create SQL View and indexes
sql_view._create_view()
sql_view._create_index()
if sql_view.is_materialized:
sql_view.cron_id = self.env['ir.cron'].create(
sql_view._prepare_cron()).id
sql_view.state = 'model_valid'
@api.multi
def button_set_draft(self):
for sql_view in self:
if sql_view.state in ('model_valid', 'ui_valid'):
# Drop SQL View (and indexes by cascade)
sql_view._drop_view()
# Drop ORM
sql_view._drop_model_and_fields()
sql_view.graph_view_id.unlink()
sql_view.action_id.unlink()
sql_view.menu_id.unlink()
sql_view.rule_id.unlink()
if sql_view.cron_id:
sql_view.cron_id.unlink()
sql_view.write({'state': 'draft', 'has_group_changed': False})
@api.multi
def button_create_ui(self):
self.graph_view_id = self.env['ir.ui.view'].create(
self._prepare_graph_view()).id
self.search_view_id = self.env['ir.ui.view'].create(
self._prepare_search_view()).id
self.action_id = self.env['ir.actions.act_window'].create(
self._prepare_action()).id
self.menu_id = self.env['ir.ui.menu'].create(
self._prepare_menu()).id
self.write({'state': 'ui_valid'})
@api.multi
def button_update_model_access(self):
self._drop_model_access()
self._create_model_access()
self.write({'has_group_changed': False})
@api.multi
def button_refresh_materialized_view(self):
self._refresh_materialized_view()
@api.multi
def button_open_view(self):
return {
'type': 'ir.actions.act_window',
'res_model': self.model_id.model,
'view_id': self.graph_view_id.id,
'search_view_id': self.search_view_id.id,
'view_type': 'graph',
'view_mode': 'graph',
}
# Prepare Function
@api.multi
def _prepare_model(self):
self.ensure_one()
field_id = []
for field in self.bi_sql_view_field_ids.filtered(
lambda x: x.field_description is not False):
field_id.append([0, False, field._prepare_model_field()])
return {
'name': self.name,
'model': self.model_name,
'access_ids': [],
'field_id': field_id,
}
@api.multi
def _prepare_model_access(self):
self.ensure_one()
res = []
for group in self.group_ids:
res.append({
'name': _('%s Access %s') % (
self.model_name, group.full_name),
'model_id': self.model_id.id,
'group_id': group.id,
'perm_read': True,
'perm_create': False,
'perm_write': False,
'perm_unlink': False,
})
return res
@api.multi
def _prepare_cron(self):
self.ensure_one()
return {
'name': _('Refresh Materialized View %s') % (self.view_name),
'user_id': SUPERUSER_ID,
'model': 'bi.sql.view',
'function': 'button_refresh_materialized_view',
'args': repr(([self.id],))
}
@api.multi
def _prepare_rule(self):
self.ensure_one()
return {
'name': _('Access %s') % (self.name),
'model_id': self.model_id.id,
'domain_force': self.domain_force,
'global': True,
}
@api.multi
def _prepare_graph_view(self):
self.ensure_one()
return {
'name': self.name,
'type': 'graph',
'model': self.model_id.model,
'arch':
"""<?xml version="1.0"?>"""
"""<graph string="Analysis" type="pivot" stacked="True">{}"""
"""</graph>""".format("".join(
[x._prepare_graph_field()
for x in self.bi_sql_view_field_ids]))
}
@api.multi
def _prepare_search_view(self):
self.ensure_one()
return {
'name': self.name,
'type': 'search',
'model': self.model_id.model,
'arch':
"""<?xml version="1.0"?>"""
"""<search string="Analysis">{}"""
"""<group expand="1" string="Group By">{}</group>"""
"""</search>""".format(
"".join(
[x._prepare_search_field()
for x in self.bi_sql_view_field_ids]),
"".join(
[x._prepare_search_filter_field()
for x in self.bi_sql_view_field_ids]))
}
@api.multi
def _prepare_action(self):
self.ensure_one()
return {
'name': self.name,
'res_model': self.model_id.model,
'type': 'ir.actions.act_window',
'view_type': 'form',
'view_mode': 'graph',
'view_id': self.graph_view_id.id,
'search_view_id': self.search_view_id.id,
}
@api.multi
def _prepare_menu(self):
self.ensure_one()
return {
'name': self.name,
'parent_id': self.env.ref('bi_sql_editor.menu_bi_sql_editor').id,
'action': 'ir.actions.act_window,%s' % (self.action_id.id),
}
# Custom Section
def _log_execute(self, req):
_logger.info("Executing SQL Request %s ..." % (req))
self.env.cr.execute(req)
@api.multi
def _drop_view(self):
for sql_view in self:
self._log_execute(
"DROP %s VIEW IF EXISTS %s" % (
sql_view.materialized_text, sql_view.view_name))
sql_view.size = False
@api.multi
def _create_view(self):
for sql_view in self:
sql_view._drop_view()
try:
self._log_execute(sql_view._prepare_request_for_execution())
sql_view._refresh_size()
except ProgrammingError as e:
raise UserError(_(
"SQL Error while creating %s VIEW %s :\n %s") % (
sql_view.materialized_text, sql_view.view_name,
e.message))
@api.multi
def _create_index(self):
for sql_view in self:
for sql_field in sql_view.bi_sql_view_field_ids.filtered(
lambda x: x.is_index is True):
self._log_execute(
"CREATE INDEX %s ON %s (%s);" % (
sql_field.index_name, sql_view.view_name,
sql_field.name))
@api.multi
def _create_model_and_fields(self):
for sql_view in self:
# Create model
sql_view.model_id = self.env['ir.model'].create(
self._prepare_model()).id
sql_view.rule_id = self.env['ir.rule'].create(
self._prepare_rule()).id
# Drop table, created by the ORM
req = "DROP TABLE %s" % (sql_view.view_name)
self.env.cr.execute(req)
@api.multi
def _create_model_access(self):
for sql_view in self:
for item in sql_view._prepare_model_access():
self.env['ir.model.access'].create(item)
@api.multi
def _drop_model_access(self):
for sql_view in self:
self.env['ir.model.access'].search(
[('model_id', '=', sql_view.model_name)]).unlink()
@api.multi
def _drop_model_and_fields(self):
for sql_view in self:
sql_view.model_id.unlink()
@api.multi
def _hook_executed_request(self):
self.ensure_one()
req = """
SELECT attnum,
attname AS column,
format_type(atttypid, atttypmod) AS type
FROM pg_attribute
WHERE attrelid = '%s'::regclass
AND NOT attisdropped
AND attnum > 0
ORDER BY attnum;""" % (self.view_name)
self.env.cr.execute(req)
return self.env.cr.fetchall()
@api.multi
def _prepare_request_check_execution(self):
self.ensure_one()
return "CREATE VIEW %s AS (%s);" % (self.view_name, self.query)
@api.multi
def _prepare_request_for_execution(self):
self.ensure_one()
query = """
SELECT
CAST(row_number() OVER () as integer) AS id,
CAST(Null as timestamp without time zone) as create_date,
CAST(Null as integer) as create_uid,
CAST(Null as timestamp without time zone) as write_date,
CAST(Null as integer) as write_uid,
my_query.*
FROM
(%s) as my_query
""" % (self.query)
return "CREATE %s VIEW %s AS (%s);" % (
self.materialized_text, self.view_name, query)
@api.multi
def _check_execution(self):
"""Ensure that the query is valid, trying to execute it.
a non materialized view is created for this check.
A rollback is done at the end.
After the execution, and before the rollback, an analysis of
the database structure is done, to know fields type."""
self.ensure_one()
sql_view_field_obj = self.env['bi.sql.view.field']
columns = super(BiSQLView, self)._check_execution()
field_ids = []
for column in columns:
existing_field = self.bi_sql_view_field_ids.filtered(
lambda x: x.name == column[1])
if existing_field:
# Update existing field
field_ids.append(existing_field.id)
existing_field.write({
'sequence': column[0],
'sql_type': column[2],
})
else:
# Create a new one if name is prefixed by x_
if column[1][:2] == 'x_':
field_ids.append(sql_view_field_obj.create({
'sequence': column[0],
'name': column[1],
'sql_type': column[2],
'bi_sql_view_id': self.id,
}).id)
# Drop obsolete view field
self.bi_sql_view_field_ids.filtered(
lambda x: x.id not in field_ids).unlink()
if not self.bi_sql_view_field_ids:
raise UserError(_(
"No Column was found.\n"
"Columns name should be prefixed by 'x_'."))
return columns
@api.multi
def _refresh_materialized_view(self):
for sql_view in self:
req = "REFRESH %s VIEW %s" % (
sql_view.materialized_text, sql_view.view_name)
self._log_execute(req)
sql_view._refresh_size()
@api.multi
def _refresh_size(self):
for sql_view in self:
req = "SELECT pg_size_pretty(pg_total_relation_size('%s'));" % (
sql_view.view_name)
self.env.cr.execute(req)
sql_view.size = self.env.cr.fetchone()[0]

194
bi_sql_editor/models/bi_sql_view_field.py

@ -0,0 +1,194 @@
# -*- coding: utf-8 -*-
# Copyright (C) 2017 - Today: GRAP (http://www.grap.coop)
# @author: Sylvain LE GAL (https://twitter.com/legalsylvain)
# License AGPL-3.0 or later (http://www.gnu.org/licenses/agpl.html).
import re
from openerp import api, fields, models
class BiSQLViewField(models.Model):
_name = 'bi.sql.view.field'
_order = 'sequence'
_TTYPE_SELECTION = [
('boolean', 'boolean'),
('char', 'char'),
('date', 'date'),
('datetime', 'datetime'),
('float', 'float'),
('integer', 'integer'),
('many2one', 'many2one'),
('selection', 'selection'),
]
_GRAPH_TYPE_SELECTION = [
('col', 'Column'),
('row', 'Row'),
('measure', 'Measure'),
]
# Mapping to guess Odoo field type, from SQL column type
_SQL_MAPPING = {
'boolean': 'boolean',
'bigint': 'integer',
'integer': 'integer',
'double precision': 'float',
'numeric': 'float',
'text': 'char',
'character varying': 'char',
'date': 'datetime',
'timestamp without time zone': 'datetime',
}
name = fields.Char(string='Name', required=True, readonly=True)
sql_type = fields.Char(
string='SQL Type', required=True, readonly=True,
help="SQL Type in the database")
sequence = fields.Integer(string='sequence', required=True, readonly=True)
bi_sql_view_id = fields.Many2one(
string='SQL View', comodel_name='bi.sql.view', ondelete='cascade')
is_index = fields.Boolean(
string='Is Index', help="Check this box if you want to create"
" an index on that field. This is recommended for searchable and"
" groupable fields, to reduce duration")
is_group_by = fields.Boolean(
string='Is Group by', help="Check this box if you want to create"
" a 'group by' option in the search view")
index_name = fields.Char(
string='Index Name', compute='_compute_index_name')
graph_type = fields.Selection(
string='Graph Type', selection=_GRAPH_TYPE_SELECTION)
field_description = fields.Char(
string='Field Description', help="This will be used as the name"
" of the Odoo field, displayed for users")
ttype = fields.Selection(
string='Field Type', selection=_TTYPE_SELECTION, help="Type of the"
" Odoo field that will be created. Let empty if you don't want to"
" create a new field. If empty, this field will not be displayed"
" neither available for search or group by function")
selection = fields.Text(
string='Selection Options', default='[]',
help="For 'Selection' Odoo field.\n"
" List of options, specified as a Python expression defining a list of"
" (key, label) pairs. For example:"
" [('blue','Blue'), ('yellow','Yellow')]")
many2one_model_id = fields.Many2one(
comodel_name='ir.model', string='Model',
help="For 'Many2one' Odoo field.\n"
" Co Model of the field.")
# Compute Section
@api.multi
def _compute_index_name(self):
for sql_field in self:
sql_field.index_name = '%s_%s' % (
sql_field.bi_sql_view_id.view_name, sql_field.name)
# Overload Section
@api.multi
def create(self, vals):
field_without_prefix = vals['name'][2:]
# guess field description
field_description = re.sub(
r'\w+', lambda m: m.group(0).capitalize(),
field_without_prefix.replace('_id', '').replace('_', ' '))
# Guess ttype
# Don't execute as simple .get() in the dict to manage
# correctly the type 'character varying(x)'
ttype = False
for k, v in self._SQL_MAPPING.iteritems():
if k in vals['sql_type']:
ttype = v
# Guess many2one_model_id
many2one_model_id = False
if vals['sql_type'] == 'integer' and(
vals['name'][-3:] == '_id'):
ttype = 'many2one'
model_name = self._model_mapping().get(field_without_prefix, '')
many2one_model_id = self.env['ir.model'].search(
[('model', '=', model_name)]).id
vals.update({
'ttype': ttype,
'field_description': field_description,
'many2one_model_id': many2one_model_id,
})
return super(BiSQLViewField, self).create(vals)
# Custom Section
@api.model
def _model_mapping(self):
"""Return dict of key value, to try to guess the model based on a
field name. Sample :
{'account_id': 'account.account'; 'product_id': 'product.product'}
"""
relation_fields = self.env['ir.model.fields'].search([
('ttype', '=', 'many2one')])
res = {}
keys_to_pop = []
for field in relation_fields:
if field.name in res and res.get(field.name) != field.relation:
# The field name is not predictive
keys_to_pop.append(field.name)
else:
res.update({field.name: field.relation})
for key in list(set(keys_to_pop)):
res.pop(key)
return res
@api.multi
def _prepare_model_field(self):
self.ensure_one()
return {
'name': self.name,
'field_description': self.field_description,
'model_id': self.bi_sql_view_id.model_id.id,
'ttype': self.ttype,
'selection': self.ttype == 'selection' and self.selection or False,
'relation': self.ttype == 'many2one' and
self.many2one_model_id.model or False,
}
@api.multi
def _prepare_graph_field(self):
self.ensure_one()
res = ''
if self.graph_type and self.field_description:
res = """<field name="{}" type="{}" />""".format(
self.name, self.graph_type)
return res
@api.multi
def _prepare_search_field(self):
self.ensure_one()
res = ''
if self.field_description:
res = """<field name="{}"/>""".format(self.name)
return res
@api.multi
def _prepare_search_filter_field(self):
self.ensure_one()
res = ''
if self.field_description and self.is_group_by:
res =\
"""<filter string="%s" context="{'group_by':'%s'}"/>""" % (
self.field_description, self.name)
return res

6
bi_sql_editor/security/ir.model.access.csv

@ -0,0 +1,6 @@
id,name,model_id:id,group_id:id,perm_read,perm_write,perm_create,perm_unlink
access_bi_sql_view_all,access_bi_sql_view_all,model_bi_sql_view,,0,0,0,0
access_bi_sql_view_manager,access_bi_sql_view_manager,model_bi_sql_view,sql_request_abstract.group_sql_request_manager,1,1,1,1
,,,,,,,
access_bi_sql_view_field_all,access_bi_sql_view_field_all,model_bi_sql_view_field,,0,0,0,0
access_bi_sql_view_field_manager,access_bi_sql_view_field_manager,model_bi_sql_view_field,sql_request_abstract.group_sql_request_manager,1,1,1,1

BIN
bi_sql_editor/static/description/01_sql_request.png

After

Width: 760  |  Height: 469  |  Size: 47 KiB

BIN
bi_sql_editor/static/description/02_security_access.png

After

Width: 763  |  Height: 523  |  Size: 43 KiB

BIN
bi_sql_editor/static/description/03_field_mapping.png

After

Width: 1088  |  Height: 493  |  Size: 60 KiB

BIN
bi_sql_editor/static/description/04_materialized_view_setting.png

After

Width: 949  |  Height: 266  |  Size: 40 KiB

BIN
bi_sql_editor/static/description/05_reporting_pie.png

After

Width: 594  |  Height: 398  |  Size: 24 KiB

BIN
bi_sql_editor/static/description/05_reporting_pivot.png

After

Width: 1000  |  Height: 401  |  Size: 47 KiB

BIN
bi_sql_editor/static/description/icon.png

After

Width: 512  |  Height: 512  |  Size: 11 KiB

BIN
bi_sql_editor/static/description/main_screenshot.png

After

Width: 828  |  Height: 417  |  Size: 45 KiB

18
bi_sql_editor/views/action.xml

@ -0,0 +1,18 @@
<?xml version="1.0" encoding="UTF-8"?>
<!--
Copyright (C) 2017 - Today: GRAP (http://www.grap.coop)
@author Sylvain LE GAL (https://twitter.com/legalsylvain)
License AGPL-3.0 or later (http://www.gnu.org/licenses/agpl.html).
-->
<openerp><data>
<record id="action_bi_sql_view" model="ir.actions.act_window">
<field name="name">SQL Views</field>
<field name="type">ir.actions.act_window</field>
<field name="res_model">bi.sql.view</field>
<field name="view_type">form</field>
<field name="view_mode">tree,form</field>
</record>
</data></openerp>

20
bi_sql_editor/views/menu.xml

@ -0,0 +1,20 @@
<?xml version="1.0" encoding="UTF-8"?>
<!--
Copyright (C) 2017 - Today: GRAP (http://www.grap.coop)
@author Sylvain LE GAL (https://twitter.com/legalsylvain)
License AGPL-3.0 or later (http://www.gnu.org/licenses/agpl.html).
-->
<openerp><data>
<!-- Menu that will contain all the SQL report generated by this module -->
<menuitem id="menu_bi_sql_editor"
name="SQL Reports"
parent="base.menu_reporting"
sequence="0"/>
<menuitem id="menu_bi_sql_view"
parent="base.next_id_9"
action="action_bi_sql_view"/>
</data></openerp>

126
bi_sql_editor/views/view_bi_sql_view.xml

@ -0,0 +1,126 @@
<?xml version="1.0" encoding="UTF-8"?>
<!--
Copyright (C) 2017 - Today: GRAP (http://www.grap.coop)
@author Sylvain LE GAL (https://twitter.com/legalsylvain)
License AGPL-3.0 or later (http://www.gnu.org/licenses/agpl.html).
-->
<openerp><data>
<record id="view_bi_sql_view_tree" model="ir.ui.view">
<field name="model">bi.sql.view</field>
<field name="arch" type="xml">
<tree>
<field name="name"/>
<field name="technical_name"/>
<field name="size"/>
<field name="state"/>
</tree>
</field>
</record>
<record id="view_bi_sql_view_form" model="ir.ui.view">
<field name="model">bi.sql.view</field>
<field name="arch" type="xml">
<form>
<header>
<button name="button_validate_sql_expression" type="object" states="draft"
string="Validate SQL Expression" class="oe_highlight"/>
<button name="button_set_draft" type="object" states="sql_valid,model_valid,ui_valid"
string="Set to Draft" groups="sql_request_abstract.group_sql_request_manager"
confirm="Are you sure you want to set to draft this SQL View. It will delete
the materialized view, and all the previous mapping realized with the columns"/>
<button name="button_create_sql_view_and_model" type="object" states="sql_valid"
string="Create SQL View, Indexes and Models" class="oe_highlight"
help="This will try to create an SQL View, based on the SQL request and the according Transient Model and fields, based on settings"/>
<button name="button_update_model_access" type="object"
attrs="{'invisible': ['|', ('state', 'in', ('draft', 'sql_valid')), ('has_group_changed', '=', False)]}"
string="Update Model Acess" class="oe_highlight"
help="Update Model Access. Required if you changed groups list after having created the model"/>
<button name="button_create_ui" type="object" states="model_valid" string="Create UI"
class="oe_highlight" help="This will create Odoo View, Action and Menu"/>
<button name="button_refresh_materialized_view" type="object" string="Refresh Materialized View"
attrs="{'invisible': ['|', ('state', 'in', ('draft', 'sql_valid')), ('is_materialized', '=', False)]}"
help="this will refresh the materialized view"/>
<button name="button_open_view" type="object" string="Open View" states="ui_valid" class="oe_highlight" />
<field name="state" widget="statusbar" />
</header>
<sheet>
<h1>
<field name="name" attrs="{'readonly': [('state','!=','draft')]}" colspan="4"/>
</h1>
<group>
<group>
<group>
<field name="technical_name"/>
<field name="view_name" />
<field name="is_materialized"/>
<field name="size"
attrs="{'invisible': ['|', ('state', '=', 'draft'), ('is_materialized', '=', False)]}"/>
<field name="cron_id"
attrs="{'invisible': ['|', ('state', 'in', ('draft', 'sql_valid')), ('is_materialized', '=', False)]}"/>
</group>
</group>
</group>
<notebook>
<page string="SQL Query">
<field name="query" nolabel="1" colspan="4"/>
</page>
<page string="SQL Fields" attrs="{'invisible': [('state', '=', 'draft')]}">
<field name="bi_sql_view_field_ids" nolabel="1" colspan="4" attrs="{'readonly': [('state', '!=', 'sql_valid')]}">
<tree editable="bottom" colors="blue:field_description==False">
<field name="sequence"/>
<field name="name"/>
<field name="sql_type"/>
<field name="field_description"/>
<field name="ttype" attrs="{
'required': [('field_description', '!=', False)]}"/>
<field name="many2one_model_id" attrs="{
'invisible': [('ttype', '!=', 'many2one')],
'required': [
('field_description', '!=', False),
('ttype', '=', 'many2one')]}"/>
<field name="selection" attrs="{
'invisible': [('ttype', '!=', 'selection')],
'required': [
('field_description', '!=', False),
('ttype', '=', 'selection')]}"/>
<field name="is_index" attrs="{'invisible': [('field_description', '=', False)]}"/>
<field name="is_group_by" attrs="{'invisible': [('field_description', '=', False)]}"/>
<field name="graph_type" attrs="{'invisible': [('field_description', '=', False)]}"/>
</tree>
</field>
</page>
<page string="Security">
<group string="Rule Definition">
<field name="domain_force" nolabel="1" colspan="4"/>
</group>
<group>
<group string="Allowed Groups">
<field name="group_ids" nolabel="1"/>
<field name="has_group_changed" invisible="1"/>
</group>
</group>
</page>
<page string="Extras Information">
<group>
<group string="Model">
<field name="model_name" />
<field name="model_id" attrs="{'invisible': [('state', '=', 'draft')]}"/>
</group>
<group string="User Interface">
<field name="graph_view_id"/>
<field name="search_view_id"/>
<field name="action_id"/>
<field name="menu_id"/>
</group>
</group>
</page>
</notebook>
</sheet>
</form>
</field>
</record>
</data></openerp>
Loading…
Cancel
Save