Skip to content

Commit

Permalink
Performance improvement for queries having join between TABLE_CONSTRA…
Browse files Browse the repository at this point in the history
…INTS and KEY_COLUMN_USAGE views (babelfish-for-postgresql#3241)

This commit addresses poor performance issues in queries that join the TABLE_CONSTRAINTS and KEY_COLUMN_USAGE views. The problem was caused by inaccurate row estimates resulting from a CASE expression in the TABLE_CONSTRAINTS view, leading to suboptimal query plans.

Signed-off-by: Sumit Jaiswal [email protected]

Issues Resolved
Task: BABEL-5427
  • Loading branch information
sumitj824 authored and timchang514 committed Dec 17, 2024
1 parent b2bbef4 commit d860c3a
Show file tree
Hide file tree
Showing 4 changed files with 144 additions and 27 deletions.
82 changes: 55 additions & 27 deletions contrib/babelfishpg_tsql/sql/information_schema_tsql.sql
Original file line number Diff line number Diff line change
Expand Up @@ -493,16 +493,27 @@ CREATE VIEW information_schema_tsql.tables AS

GRANT SELECT ON information_schema_tsql.tables TO PUBLIC;

/*
* TABLE_CONSTRAINTS view
*/

CREATE VIEW information_schema_tsql.table_constraints AS
SELECT CAST(nc.dbname AS sys.nvarchar(128)) AS "CONSTRAINT_CATALOG",
CAST(extc.orig_name AS sys.nvarchar(128)) AS "CONSTRAINT_SCHEMA",
CREATE OR REPLACE FUNCTION information_schema_tsql.table_constraints_internal()
RETURNS TABLE (
"CONSTRAINT_CATALOG" sys.nvarchar(128),
"CONSTRAINT_SCHEMA" sys.nvarchar(128),
"CONSTRAINT_NAME" sys.sysname,
"TABLE_CATALOG" sys.nvarchar(128),
"TABLE_SCHEMA" sys.nvarchar(128),
"TABLE_NAME" sys.sysname,
"CONSTRAINT_TYPE" sys.varchar(11),
"IS_DEFERRABLE" sys.varchar(2),
"INITIALLY_DEFERRED" sys.varchar(2)
)
AS
$$
BEGIN
RETURN QUERY
SELECT CAST(db_name AS sys.nvarchar(128)) AS "CONSTRAINT_CATALOG",
CAST(ext.orig_name AS sys.nvarchar(128)) AS "CONSTRAINT_SCHEMA",
CAST(c.conname AS sys.sysname) AS "CONSTRAINT_NAME",
CAST(nr.dbname AS sys.nvarchar(128)) AS "TABLE_CATALOG",
CAST(extr.orig_name AS sys.nvarchar(128)) AS "TABLE_SCHEMA",
CAST(db_name AS sys.nvarchar(128)) AS "TABLE_CATALOG",
CAST(ext.orig_name AS sys.nvarchar(128)) AS "TABLE_SCHEMA",
CAST(r.relname AS sys.sysname) AS "TABLE_NAME",
CAST(
CASE c.contype WHEN 'c' THEN 'CHECK'
Expand All @@ -512,22 +523,39 @@ CREATE VIEW information_schema_tsql.table_constraints AS
AS sys.varchar(11)) COLLATE sys.database_default AS "CONSTRAINT_TYPE",
CAST('NO' AS sys.varchar(2)) AS "IS_DEFERRABLE",
CAST('NO' AS sys.varchar(2)) AS "INITIALLY_DEFERRED"

FROM sys.pg_namespace_ext nc LEFT OUTER JOIN sys.babelfish_namespace_ext extc ON nc.nspname = extc.nspname,
sys.pg_namespace_ext nr LEFT OUTER JOIN sys.babelfish_namespace_ext extr ON nr.nspname = extr.nspname,
pg_constraint c,
pg_class r

WHERE nc.oid = c.connamespace AND nr.oid = r.relnamespace
AND c.conrelid = r.oid
AND c.contype NOT IN ('t', 'x')
FROM
pg_constraint c
INNER JOIN pg_class r ON c.conrelid = r.oid
INNER JOIN pg_namespace nsp ON r.relnamespace = nsp.oid
INNER JOIN sys.babelfish_namespace_ext ext ON nsp.nspname = ext.nspname AND ext.dbid = sys.db_id()
, sys.db_name() AS db_name
WHERE
c.contype IN ('c', 'f', 'p', 'u')
AND r.relkind IN ('r', 'p')
AND relispartition = false
AND (NOT pg_is_other_temp_schema(nr.oid))
AND (pg_has_role(r.relowner, 'USAGE')
OR has_table_privilege(r.oid, 'SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER')
OR has_any_column_privilege(r.oid, 'SELECT, INSERT, UPDATE, REFERENCES') )
AND extc.dbid = sys.db_id();
OR has_any_column_privilege(r.oid, 'SELECT, INSERT, UPDATE, REFERENCES') );
END;
$$
LANGUAGE plpgsql STABLE;

/*
* TABLE_CONSTRAINTS view
*/

CREATE OR REPLACE VIEW information_schema_tsql.table_constraints AS
SELECT
CAST("CONSTRAINT_CATALOG" AS sys.nvarchar(128)),
CAST("CONSTRAINT_SCHEMA" AS sys.nvarchar(128)),
CAST("CONSTRAINT_NAME" AS sys.sysname),
CAST("TABLE_CATALOG" AS sys.nvarchar(128)),
CAST("TABLE_SCHEMA" AS sys.nvarchar(128)),
CAST("TABLE_NAME" AS sys.sysname),
CAST("CONSTRAINT_TYPE" AS sys.varchar(11)),
CAST("IS_DEFERRABLE" AS sys.varchar(2)),
CAST("INITIALLY_DEFERRED" AS sys.varchar(2))
FROM information_schema_tsql.table_constraints_internal();

GRANT SELECT ON information_schema_tsql.table_constraints TO PUBLIC;

Expand Down Expand Up @@ -823,25 +851,25 @@ GRANT SELECT ON information_schema_tsql.sequences TO PUBLIC;

CREATE OR REPLACE VIEW information_schema_tsql.key_column_usage AS
SELECT
CAST(nc.dbname AS sys.nvarchar(128)) AS "CONSTRAINT_CATALOG",
CAST(db_name AS sys.nvarchar(128)) AS "CONSTRAINT_CATALOG",
CAST(ext.orig_name AS sys.nvarchar(128)) AS "CONSTRAINT_SCHEMA",
CAST(c.conname AS sys.nvarchar(128)) AS "CONSTRAINT_NAME",
CAST(nc.dbname AS sys.nvarchar(128)) AS "TABLE_CATALOG",
CAST(db_name AS sys.nvarchar(128)) AS "TABLE_CATALOG",
CAST(ext.orig_name AS sys.nvarchar(128)) AS "TABLE_SCHEMA",
CAST(r.relname AS sys.nvarchar(128)) AS "TABLE_NAME",
CAST(a.attname AS sys.nvarchar(128)) AS "COLUMN_NAME",
CAST(ord AS int) AS "ORDINAL_POSITION"
FROM
pg_constraint c
JOIN pg_class r ON r.oid = c.conrelid AND c.contype in ('p','u','f') AND r.relkind in ('r','p') AND r.relispartition = false
JOIN sys.pg_namespace_ext nc ON nc.oid = c.connamespace AND r.relnamespace = nc.oid
JOIN sys.babelfish_namespace_ext ext ON ext.nspname = nc.nspname AND ext.dbid = sys.db_id()
JOIN pg_namespace nsp ON r.relnamespace = nsp.oid
JOIN sys.babelfish_namespace_ext ext ON ext.nspname = nsp.nspname AND ext.dbid = sys.db_id()
CROSS JOIN unnest(c.conkey) WITH ORDINALITY AS ak(j,ord)
LEFT JOIN pg_attribute a ON a.attrelid = r.oid AND a.attnum = ak.j
LEFT JOIN pg_attribute a ON a.attrelid = r.oid AND a.attnum = ak.j
, sys.db_name() AS db_name
WHERE
pg_has_role(r.relowner, 'USAGE'::text)
OR has_column_privilege(r.oid, a.attnum, 'SELECT, INSERT, UPDATE, REFERENCES'::text)
AND NOT pg_is_other_temp_schema(nc.oid)
;
GRANT SELECT ON information_schema_tsql.key_column_usage TO PUBLIC;

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -10690,6 +10690,92 @@ $body$
LANGUAGE 'plpgsql'
STABLE;

CREATE OR REPLACE FUNCTION information_schema_tsql.table_constraints_internal()
RETURNS TABLE (
"CONSTRAINT_CATALOG" sys.nvarchar(128),
"CONSTRAINT_SCHEMA" sys.nvarchar(128),
"CONSTRAINT_NAME" sys.sysname,
"TABLE_CATALOG" sys.nvarchar(128),
"TABLE_SCHEMA" sys.nvarchar(128),
"TABLE_NAME" sys.sysname,
"CONSTRAINT_TYPE" sys.varchar(11),
"IS_DEFERRABLE" sys.varchar(2),
"INITIALLY_DEFERRED" sys.varchar(2)
)
AS
$$
BEGIN
RETURN QUERY
SELECT CAST(db_name AS sys.nvarchar(128)) AS "CONSTRAINT_CATALOG",
CAST(ext.orig_name AS sys.nvarchar(128)) AS "CONSTRAINT_SCHEMA",
CAST(c.conname AS sys.sysname) AS "CONSTRAINT_NAME",
CAST(db_name AS sys.nvarchar(128)) AS "TABLE_CATALOG",
CAST(ext.orig_name AS sys.nvarchar(128)) AS "TABLE_SCHEMA",
CAST(r.relname AS sys.sysname) AS "TABLE_NAME",
CAST(
CASE c.contype WHEN 'c' THEN 'CHECK'
WHEN 'f' THEN 'FOREIGN KEY'
WHEN 'p' THEN 'PRIMARY KEY'
WHEN 'u' THEN 'UNIQUE' END
AS sys.varchar(11)) COLLATE sys.database_default AS "CONSTRAINT_TYPE",
CAST('NO' AS sys.varchar(2)) AS "IS_DEFERRABLE",
CAST('NO' AS sys.varchar(2)) AS "INITIALLY_DEFERRED"
FROM
pg_constraint c
INNER JOIN pg_class r ON c.conrelid = r.oid
INNER JOIN pg_namespace nsp ON r.relnamespace = nsp.oid
INNER JOIN sys.babelfish_namespace_ext ext ON nsp.nspname = ext.nspname AND ext.dbid = sys.db_id()
, sys.db_name() AS db_name
WHERE
c.contype IN ('c', 'f', 'p', 'u')
AND r.relkind IN ('r', 'p')
AND relispartition = false
AND (pg_has_role(r.relowner, 'USAGE')
OR has_table_privilege(r.oid, 'SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER')
OR has_any_column_privilege(r.oid, 'SELECT, INSERT, UPDATE, REFERENCES') );
END;
$$
LANGUAGE plpgsql STABLE;

CREATE OR REPLACE VIEW information_schema_tsql.table_constraints AS
SELECT
CAST("CONSTRAINT_CATALOG" AS sys.nvarchar(128)),
CAST("CONSTRAINT_SCHEMA" AS sys.nvarchar(128)),
CAST("CONSTRAINT_NAME" AS sys.sysname),
CAST("TABLE_CATALOG" AS sys.nvarchar(128)),
CAST("TABLE_SCHEMA" AS sys.nvarchar(128)),
CAST("TABLE_NAME" AS sys.sysname),
CAST("CONSTRAINT_TYPE" AS sys.varchar(11)),
CAST("IS_DEFERRABLE" AS sys.varchar(2)),
CAST("INITIALLY_DEFERRED" AS sys.varchar(2))
FROM information_schema_tsql.table_constraints_internal();

GRANT SELECT ON information_schema_tsql.table_constraints TO PUBLIC;

CREATE OR REPLACE VIEW information_schema_tsql.key_column_usage AS
SELECT
CAST(db_name AS sys.nvarchar(128)) AS "CONSTRAINT_CATALOG",
CAST(ext.orig_name AS sys.nvarchar(128)) AS "CONSTRAINT_SCHEMA",
CAST(c.conname AS sys.nvarchar(128)) AS "CONSTRAINT_NAME",
CAST(db_name AS sys.nvarchar(128)) AS "TABLE_CATALOG",
CAST(ext.orig_name AS sys.nvarchar(128)) AS "TABLE_SCHEMA",
CAST(r.relname AS sys.nvarchar(128)) AS "TABLE_NAME",
CAST(a.attname AS sys.nvarchar(128)) AS "COLUMN_NAME",
CAST(ord AS int) AS "ORDINAL_POSITION"
FROM
pg_constraint c
JOIN pg_class r ON r.oid = c.conrelid AND c.contype in ('p','u','f') AND r.relkind in ('r','p') AND r.relispartition = false
JOIN pg_namespace nsp ON r.relnamespace = nsp.oid
JOIN sys.babelfish_namespace_ext ext ON ext.nspname = nsp.nspname AND ext.dbid = sys.db_id()
CROSS JOIN unnest(c.conkey) WITH ORDINALITY AS ak(j,ord)
LEFT JOIN pg_attribute a ON a.attrelid = r.oid AND a.attnum = ak.j
, sys.db_name() AS db_name
WHERE
pg_has_role(r.relowner, 'USAGE'::text)
OR has_column_privilege(r.oid, a.attnum, 'SELECT, INSERT, UPDATE, REFERENCES'::text)
;
GRANT SELECT ON information_schema_tsql.key_column_usage TO PUBLIC;

-- After upgrade, always run analyze for all babelfish catalogs.
CALL sys.analyze_babelfish_catalogs();

Expand Down
Original file line number Diff line number Diff line change
@@ -1,6 +1,7 @@
Could not find tests for function assemblyproperty
Could not find tests for function bbf_string_agg_finalfn_nvarchar
Could not find tests for function bbf_string_agg_finalfn_varchar
Could not find tests for function information_schema_tsql.table_constraints_internal
Could not find tests for function pltsql_call_handler
Could not find tests for function pltsql_inline_handler
Could not find tests for function pltsql_validator
Expand Down Expand Up @@ -97,6 +98,7 @@ Could not find upgrade tests for function assemblyproperty
Could not find upgrade tests for function bbf_string_agg_finalfn_nvarchar
Could not find upgrade tests for function bbf_string_agg_finalfn_varchar
Could not find upgrade tests for function connectionproperty
Could not find upgrade tests for function information_schema_tsql.table_constraints_internal
Could not find upgrade tests for function pltsql_call_handler
Could not find upgrade tests for function pltsql_inline_handler
Could not find upgrade tests for function pltsql_validator
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -61,6 +61,7 @@ Collation sys.ukrainian_ci_as
Collation sys.ukrainian_cs_as
Collation sys.vietnamese_ci_ai
Collation sys.vietnamese_ci_as
Function information_schema_tsql.table_constraints_internal()
Function sys."char"(integer)
Function sys."decimal"(sys."nchar",integer,boolean)
Function sys."isnull"(bigint,bigint)
Expand Down

0 comments on commit d860c3a

Please sign in to comment.