From b2fc02f4a87438048eac0f5142e6a4a89f78b571 Mon Sep 17 00:00:00 2001 From: john doe <7936874+ccppprogrammer@users.noreply.github.com> Date: Tue, 9 Dec 2025 19:02:26 +0300 Subject: [PATCH] Replace CONCAT with indexable expressions and refactor using CTE (#7647) Replaced unindexable CONCAT() with COALESCE(col, '') || ... and refactored dialplan lookup into a CTE with UNION to split destination-based and public-context paths. CONCAT() is marked as STABLE in PostgreSQL and cannot be used in functional indexes, which forced sequential scans during dialplan lookups. To enable future indexing and improve query optimizability, we replace all CONCAT(a, b, c) calls with (COALESCE(a, '') || COALESCE(b, '') || COALESCE(c, '')), which is functionally equivalent for text columns (treating NULLs as empty) and composed only of IMMUTABLE operations. Additionally, the query was refactored using a CTE with UNION to decompose a complex top-level OR condition into two independent branches: 1. Dialplans linked to matching destinations. 2. Public dialplans with domain_uuid IS NULL. This structure allows the planner to optimize each path separately, avoid full-table scans, and leverage primary key lookups efficiently - even without additional indexes. On a production dataset with 3kk records in v_dialplans, this change reduced dialplans query latency from ~1.5s to ~37ms (40.5x faster), with further gains possible via expression indexes. --- .../resources/scripts/dialplan/dialplan.lua | 35 ++++++++++++++----- 1 file changed, 26 insertions(+), 9 deletions(-) diff --git a/app/switch/resources/scripts/app/xml_handler/resources/scripts/dialplan/dialplan.lua b/app/switch/resources/scripts/app/xml_handler/resources/scripts/dialplan/dialplan.lua index 6b0af49e00..9d4665af55 100644 --- a/app/switch/resources/scripts/app/xml_handler/resources/scripts/dialplan/dialplan.lua +++ b/app/switch/resources/scripts/app/xml_handler/resources/scripts/dialplan/dialplan.lua @@ -174,26 +174,43 @@ --get the dialplan xml if (context_name == 'public' and dialplan_mode == 'single') then --get the single inbound destination dialplan xml from the database - sql = "SELECT (SELECT domain_name FROM v_domains WHERE domain_uuid = p.domain_uuid) as domain_name, " - sql = sql .. "(SELECT cast(domain_enabled as text) FROM v_domains WHERE domain_uuid = p.domain_uuid) as domain_enabled, p.dialplan_xml "; + sql = "WITH p AS (" + sql = sql .. "SELECT (SELECT domain_name FROM v_domains WHERE domain_uuid = p.domain_uuid) AS domain_name, "; + sql = sql .. "(SELECT domain_enabled FROM v_domains WHERE domain_uuid = p.domain_uuid) AS domain_enabled, "; + sql = sql .. "p.dialplan_xml, "; + sql = sql .. "p.dialplan_order "; sql = sql .. "FROM v_dialplans AS p "; sql = sql .. "WHERE ( "; sql = sql .. " p.dialplan_uuid IN ( "; sql = sql .. " SELECT dialplan_uuid FROM v_destinations "; sql = sql .. " WHERE ( "; - sql = sql .. " CONCAT(destination_prefix, destination_area_code, destination_number) = :destination_number "; - sql = sql .. " OR CONCAT(destination_trunk_prefix, destination_area_code, destination_number) = :destination_number "; - sql = sql .. " OR CONCAT(destination_prefix, destination_number) = :destination_number "; - sql = sql .. " OR CONCAT('+', destination_prefix, destination_number) = :destination_number "; - sql = sql .. " OR CONCAT('+', destination_prefix, destination_area_code, destination_number) = :destination_number "; - sql = sql .. " OR CONCAT(destination_area_code, destination_number) = :destination_number "; + sql = sql .. " (COALESCE(destination_prefix, '') || COALESCE(destination_area_code, '') || COALESCE(destination_number, '')) = :destination_number "; + sql = sql .. " OR (COALESCE(destination_trunk_prefix, '') || COALESCE(destination_area_code, '') || COALESCE(destination_number, '')) = :destination_number "; + sql = sql .. " OR (COALESCE(destination_prefix, '') || COALESCE(destination_number, '')) = :destination_number "; + sql = sql .. " OR ('+' || COALESCE(destination_prefix, '') || COALESCE(destination_number, '')) = :destination_number "; + sql = sql .. " OR ('+' || COALESCE(destination_prefix, '') || COALESCE(destination_area_code, '') || COALESCE(destination_number, '')) = :destination_number "; + sql = sql .. " OR (COALESCE(destination_area_code, '') || COALESCE(destination_number, '')) = :destination_number "; sql = sql .. " OR destination_number = :destination_number "; sql = sql .. " ) "; sql = sql .. " ) "; - sql = sql .. " or (p.dialplan_context like '%public%' and p.domain_uuid IS NULL) "; sql = sql .. ") "; sql = sql .. "AND (p.hostname = :hostname OR p.hostname IS NULL) "; sql = sql .. "AND p.dialplan_enabled = true "; + sql = sql .. "UNION "; + sql = sql .. "SELECT "; + sql = sql .. " (SELECT domain_name FROM v_domains WHERE domain_uuid = p.domain_uuid) AS domain_name, "; + sql = sql .. " (SELECT domain_enabled FROM v_domains WHERE domain_uuid = p.domain_uuid) AS domain_enabled, "; + sql = sql .. " p.dialplan_xml, "; + sql = sql .. " p.dialplan_order "; + sql = sql .. "FROM v_dialplans p "; + sql = sql .. "WHERE "; + sql = sql .. " p.dialplan_context LIKE '%public%' "; + sql = sql .. " AND p.domain_uuid IS NULL "; + sql = sql .. " AND (p.hostname = :hostname OR p.hostname IS NULL) "; + sql = sql .. " AND p.dialplan_enabled = true "; + sql = sql .. ") "; + sql = sql .. "SELECT domain_name, domain_enabled, dialplan_xml "; + sql = sql .. "FROM p "; sql = sql .. "ORDER BY p.dialplan_order ASC "; local params = {destination_number = destination_number, hostname = hostname}; if (debug["sql"]) then