Skip to content

Commit

Permalink
Dashboard: Added chart and KPI components. Created materialized view
Browse files Browse the repository at this point in the history
  • Loading branch information
mkumar-02 committed Nov 13, 2024
1 parent d22c8f1 commit 6a7e246
Show file tree
Hide file tree
Showing 14 changed files with 372 additions and 276 deletions.
234 changes: 141 additions & 93 deletions g2p_social_registry_dashboard/__init__.py
Original file line number Diff line number Diff line change
@@ -1,122 +1,170 @@
# Part of OpenG2P Registry. See LICENSE file for full copyright and licensing details.
# Part of OpenG2P. See LICENSE file for full copyright and licensing details.

from . import models

from odoo import _
from odoo.exceptions import MissingError
import logging

_logger = logging.getLogger(__name__)


def init_materialized_view(env):
"""
Initializes the res_partner_dashboard_data materialized view.
Initializes or refreshes the materialized views for the res_partner_dashboard_data.
"""

cr = env.cr
cr.execute(
"""
SELECT
matviewname
FROM
pg_matviews
WHERE
matviewname = 'res_partner_dashboard_data';
"""
)
check = cr.fetchone()

if check:
return {}

query = """
CREATE MATERIALIZED VIEW res_partner_dashboard_data AS
SELECT
company_id,
jsonb_build_object(
'individual_count', COUNT(id)
FILTER (WHERE is_registrant = True AND is_group = False),
'group_count', COUNT(id)
FILTER (WHERE is_registrant = True AND is_group = True)
) AS total_registrant,
jsonb_build_object(
'male_count', COUNT(id)
FILTER (
WHERE is_registrant = True
AND is_group = False
AND gender = 'Male'
),
'female_count', COUNT(id)
FILTER (
WHERE is_registrant = True
AND is_group = False
AND gender = 'Female'
)
) AS gender_spec,
jsonb_build_object(
'below_18', COUNT(id)
FILTER (
WHERE is_registrant = True
AND is_group = False
AND EXTRACT(YEAR FROM AGE(birthdate)) < 18
),
'18_to_30', COUNT(id)
FILTER (
WHERE is_registrant = True
AND is_group = False
AND EXTRACT(YEAR FROM AGE(birthdate)) BETWEEN 18 AND 30
),
'31_to_40', COUNT(id)
FILTER (
WHERE is_registrant = True
AND is_group = False
AND EXTRACT(YEAR FROM AGE(birthdate)) BETWEEN 31 AND 40
),
'41_to_50', COUNT(id)
FILTER (
WHERE is_registrant = True
AND is_group = False
AND EXTRACT(YEAR FROM AGE(birthdate)) BETWEEN 41 AND 50
),
'above_50', COUNT(id)
FILTER (
WHERE is_registrant = True
AND is_group = False
AND EXTRACT(YEAR FROM AGE(birthdate)) > 50
)
) AS age_distribution
FROM
res_partner
GROUP BY
company_id;
"""

matviews_to_check = [
"g2p_gender_count_view",
"g2p_age_distribution_view",
"g2p_total_registrants_view",
"g2p_sr_dashboard_data",
]

try:
cr.execute(query)
cr.execute(
"""
SELECT matviewname
FROM pg_matviews
WHERE matviewname IN %s;
""",
(tuple(matviews_to_check),),
)

existing_views = set([row[0] for row in cr.fetchall()])

if "g2p_gender_count_view" not in existing_views:
gender_query = """
CREATE MATERIALIZED VIEW g2p_gender_count_view AS
SELECT
rp.company_id,
gt.code AS gender,
COUNT(rp.id) AS gender_count
FROM
res_partner rp
LEFT JOIN
gender_type gt ON rp.gender = gt.value
WHERE
rp.is_registrant = True
AND rp.active = True
AND rp.is_group = False
GROUP BY
rp.company_id, gt.code;
"""
cr.execute(gender_query)
_logger.info("Created materialized view: g2p_gender_count_view")

if "g2p_age_distribution_view" not in existing_views:
age_distribution_query = """
CREATE MATERIALIZED VIEW g2p_age_distribution_view AS
SELECT
rp.company_id,
jsonb_build_object(
'below_18', COUNT(rp.id) FILTER (
WHERE EXTRACT(YEAR FROM AGE(rp.birthdate)) < 18
),
'18_to_30', COUNT(rp.id) FILTER (
WHERE EXTRACT(YEAR FROM AGE(rp.birthdate)) BETWEEN 18 AND 30
),
'31_to_40', COUNT(rp.id) FILTER (
WHERE EXTRACT(YEAR FROM AGE(rp.birthdate)) BETWEEN 31 AND 40
),
'41_to_50', COUNT(rp.id) FILTER (
WHERE EXTRACT(YEAR FROM AGE(rp.birthdate)) BETWEEN 41 AND 50
),
'above_50', COUNT(rp.id) FILTER (
WHERE EXTRACT(YEAR FROM AGE(rp.birthdate)) > 50
)
) AS age_distribution
FROM
res_partner rp
WHERE
rp.is_registrant = True
AND rp.active = True
AND rp.is_group = False
GROUP BY
rp.company_id;
"""
cr.execute(age_distribution_query)
_logger.info("Created materialized view: g2p_age_distribution_view")

if "g2p_total_registrants_view" not in existing_views:
total_registrants_query = """
CREATE MATERIALIZED VIEW g2p_total_registrants_view AS
SELECT
rp.company_id,
jsonb_build_object(
'total_individuals', COUNT(rp.id) FILTER (WHERE rp.is_group = False),
'total_groups', COUNT(rp.id) FILTER (WHERE rp.is_group = True)
) AS total_registrants
FROM
res_partner rp
WHERE
rp.is_registrant = True
AND rp.active = True
GROUP BY
rp.company_id;
"""
cr.execute(total_registrants_query)
_logger.info("Created materialized view: g2p_total_registrants_view")

if "g2p_sr_dashboard_data" not in existing_views:
dashboard_query = """
CREATE MATERIALIZED VIEW g2p_sr_dashboard_data AS
SELECT
trv.company_id,
trv.total_registrants,
COALESCE(
jsonb_object_agg(gc.gender, gc.gender_count) FILTER (WHERE gc.gender IS NOT NULL),
'{}'
) AS gender_spec,
adv.age_distribution
FROM
g2p_total_registrants_view trv
LEFT JOIN
g2p_gender_count_view gc ON trv.company_id = gc.company_id
LEFT JOIN
g2p_age_distribution_view adv ON trv.company_id = adv.company_id
GROUP BY
trv.company_id, trv.total_registrants, adv.age_distribution;
"""
cr.execute(dashboard_query)
_logger.info("Created materialized view: g2p_sr_dashboard_data")

except Exception as exc:
_logger.error("Error while creating materialized views: %s", str(exc))
raise MissingError(
_(
"Failed to create the materialized view 'res_partner_dashboard_data'.\n"
"Please create it manually by running the required SQL query with proper permissions."
"Failed to create the materialized views."
"Please check the logs for details or Manually create it."
)
) from exc


def drop_materialized_view(env):
"""
Drop the res_partner_dashboard_data materialized view.
Drop all the materialized views related to the dashboard.
"""

cr = env.cr

matviews_to_drop = [
"g2p_gender_count_view",
"g2p_age_distribution_view",
"g2p_total_registrants_view",
"g2p_sr_dashboard_data",
]

try:
cr.execute(
"""
DROP MATERIALIZED VIEW IF EXISTS
res_partner_dashboard_data;
"""
)
for matview in matviews_to_drop:
cr.execute(f"DROP MATERIALIZED VIEW IF EXISTS {matview};") # pylint: disable=sql-injection
_logger.info("Dropped materialized view: %s", matview)

except Exception as exc:
raise Exception(
_logger.error("Error while dropping materialized views: %s", str(exc))
raise MissingError(
_(
"Failed to drop the materialized view 'res_partner_dashboard_data'.\n"
"Please manually delete the view."
"Failed to drop the materialized views."
"Please check the logs for details or manually delete the view."
)
) from exc
4 changes: 2 additions & 2 deletions g2p_social_registry_dashboard/__manifest__.py
Original file line number Diff line number Diff line change
Expand Up @@ -12,10 +12,10 @@
"data": ["data/cron_job.xml", "views/menu.xml"],
"assets": {
"web.assets_backend": [
"https://cdn.jsdelivr.net/npm/chart.js",
"g2p_social_registry_dashboard/static/src/components/chart/**/*",
"g2p_social_registry_dashboard/static/src/components/kpi/**/*",
"g2p_social_registry_dashboard/static/src/js/dashboard.js",
"g2p_social_registry_dashboard/static/src/xml/dashboard.xml",
"g2p_social_registry_dashboard/static/src/scss/dashboard.scss",
],
},
"demo": [],
Expand Down
2 changes: 1 addition & 1 deletion g2p_social_registry_dashboard/data/cron_job.xml
Original file line number Diff line number Diff line change
Expand Up @@ -9,7 +9,7 @@ Part of OpenG2P. See LICENSE file for full copyright and licensing details.
<field name="state">code</field>
<field name="code">model._refresh_dashboard_materialized_view()</field>
<field name="interval_number">10</field>
<field name="interval_type">minutes</field>
<field name="interval_type">hours</field>
<field name="numbercall">-1</field>
<field name="doall" eval="False" />
<field name="active" eval="True" />
Expand Down
2 changes: 2 additions & 0 deletions g2p_social_registry_dashboard/models/__init__.py
Original file line number Diff line number Diff line change
@@ -1,2 +1,4 @@
# Part of OpenG2P. See LICENSE file for full copyright and licensing details.

from . import cron
from . import registrant
43 changes: 41 additions & 2 deletions g2p_social_registry_dashboard/models/cron.py
Original file line number Diff line number Diff line change
@@ -1,8 +1,47 @@
from odoo import models
import logging

from odoo import _, models
from odoo.exceptions import MissingError

_logger = logging.getLogger(__name__)


class DashboardCron(models.Model):
_inherit = "ir.cron"

def _refresh_dashboard_materialized_view(self):
self.env.cr.execute("REFRESH MATERIALIZED VIEW res_partner_dashboard_data")
"""
Refreshes all the materialized views related to the Dashboard.
"""
cr = self.env.cr
matviews_to_refresh = [
"g2p_gender_count_view",
"g2p_age_distribution_view",
"g2p_total_registrants_view",
"g2p_sr_dashboard_data",
]

for matview in matviews_to_refresh:
try:
cr.execute(
"""
SELECT matviewname
FROM pg_matviews
WHERE matviewname = %s;
""",
(matview,),
)

if not cr.fetchall():
raise MissingError(
_("Materialized view '%s' does not exist. Please create it first.") % matview
)

cr.execute(f"REFRESH MATERIALIZED VIEW {matview}") # pylint: disable=sql-injection

except Exception as exc:
_logger.error("Error refreshing materialized view '%s': %s", matview, str(exc))
raise MissingError(
_("Failed to refresh materialized view '%s'. Please check the logs for details.")
% matview
) from exc
33 changes: 8 additions & 25 deletions g2p_social_registry_dashboard/models/registrant.py
Original file line number Diff line number Diff line change
@@ -1,3 +1,5 @@
# Part of OpenG2P. See LICENSE file for full copyright and licensing details.

from odoo import api, models


Expand All @@ -9,39 +11,20 @@ def get_dashboard_data(self):
"""Fetch data from materialized view and prepare it for charts."""
company_id = self.env.company.id

# Fetch data from the materialized view
query = """
SELECT total_registrant, gender_spec, age_distribution
FROM res_partner_dashboard_data
SELECT total_registrants, gender_spec, age_distribution
FROM g2p_sr_dashboard_data
WHERE company_id = %s
"""
self.env.cr.execute(query, (company_id,))
result = self.env.cr.fetchone()

if not result:
return {
"total_individuals": 0,
"total_groups": 0,
"gender_distribution": {"male": 0, "female": 0},
"age_distribution": {
"below_18": 0,
"18_to_30": 0,
"31_to_40": 0,
"41_to_50": 0,
"above_50": 0,
},
}

total_registrant, gender_spec, age_distribution = result
total_registrants, gender_spec, age_distribution = result

# Return formatted data
return {
"total_individuals": total_registrant.get("individual_count", 0),
"total_groups": total_registrant.get("group_count", 0),
"gender_distribution": {
"male": gender_spec.get("male_count", 0),
"female": gender_spec.get("female_count", 0),
},
"total_individuals": total_registrants.get("total_individuals", 0),
"total_groups": total_registrants.get("total_groups", 0),
"gender_distribution": gender_spec,
"age_distribution": {
"Below 18": age_distribution.get("below_18", 0),
"18 to 30": age_distribution.get("18_to_30", 0),
Expand Down
Loading

0 comments on commit 6a7e246

Please sign in to comment.