From be4d74797092eb87a1209a3f643ed88e9643480b Mon Sep 17 00:00:00 2001 From: Tanzeel Khan <140405735+tanscorpio7@users.noreply.github.com> Date: Thu, 26 Dec 2024 14:53:18 +0530 Subject: [PATCH] Fix sys.columnproperty ordinal (#3314) In sys.columnproperty, the query for ordinal was incorrect. We put the order by clause outside `row_number() OVER()` clause which means the row_number() was called before ordering the result leading to random output. As a fix move ORDER BY clause to inside OVER() Additional an example to show that `row_number() OVER()` clause is executed before outside `ORDER BY`. ``` babelfish_db=# select a, row_number() over() from (select unnest(ARRAY[99, 1]) as a) order by a; a | row_number ----+------------ 1 | 2 99 | 1 (2 rows) babelfish_db=# select a, row_number() over(order by a) from (select unnest(ARRAY[99, 1]) as a); a | row_number ----+------------ 1 | 1 99 | 2 (2 rows) ``` Task: BABEL-5495 Signed-off-by: Tanzeel Khan --- .../babelfishpg_tsql/sql/sys_functions.sql | 4 +- .../babelfishpg_tsql--4.4.0--5.0.0.sql | 48 +++++++++++++++++++ 2 files changed, 50 insertions(+), 2 deletions(-) diff --git a/contrib/babelfishpg_tsql/sql/sys_functions.sql b/contrib/babelfishpg_tsql/sql/sys_functions.sql index b6af1f87ad..d9892b90f4 100644 --- a/contrib/babelfishpg_tsql/sql/sys_functions.sql +++ b/contrib/babelfishpg_tsql/sql/sys_functions.sql @@ -3172,8 +3172,8 @@ BEGIN (SELECT a.attnum FROM pg_catalog.pg_attribute a WHERE a.attrelid = object_id AND (a.attname = property COLLATE sys.database_default)) WHEN 'ordinal' COLLATE sys.database_default THEN - (SELECT b.count FROM (SELECT attname, row_number() OVER () AS count FROM pg_catalog.pg_attribute a - WHERE a.attrelid = object_id AND attisdropped = false AND attnum > 0 ORDER BY a.attnum) AS b WHERE b.attname = property COLLATE sys.database_default) + (SELECT b.count FROM (SELECT attname, row_number() OVER (ORDER BY a.attnum) AS count FROM pg_catalog.pg_attribute a + WHERE a.attrelid = object_id AND attisdropped = false AND attnum > 0) AS b WHERE b.attname = property COLLATE sys.database_default) WHEN 'isidentity' COLLATE sys.database_default THEN (SELECT CASE WHEN char_length(a.attidentity) > 0 THEN 1 diff --git a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.4.0--5.0.0.sql b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.4.0--5.0.0.sql index 141fbf0a43..c456ef3c58 100644 --- a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.4.0--5.0.0.sql +++ b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.4.0--5.0.0.sql @@ -11431,6 +11431,54 @@ CREATE OR REPLACE AGGREGATE sys.string_agg(TEXT, TEXT) ( PARALLEL = SAFE ); +CREATE OR REPLACE FUNCTION sys.columnproperty(object_id OID, property NAME, property_name TEXT) +RETURNS INTEGER +LANGUAGE plpgsql +STABLE STRICT +AS $$ +DECLARE + extra_bytes CONSTANT INTEGER := 4; + return_value INTEGER; +BEGIN + return_value:= + CASE pg_catalog.LOWER(property_name) + WHEN 'charmaxlen' COLLATE sys.database_default THEN (SELECT + CASE + WHEN a.atttypmod > 0 THEN a.atttypmod - extra_bytes + ELSE NULL + END FROM pg_catalog.pg_attribute a WHERE a.attrelid = object_id AND (a.attname = property COLLATE sys.database_default)) + WHEN 'allowsnull' COLLATE sys.database_default THEN (SELECT + CASE + WHEN a.attnotnull THEN 0 + ELSE 1 + END FROM pg_catalog.pg_attribute a WHERE a.attrelid = object_id AND (a.attname = property COLLATE sys.database_default)) + WHEN 'iscomputed' COLLATE sys.database_default THEN (SELECT + CASE + WHEN a.attgenerated != '' THEN 1 + ELSE 0 + END FROM pg_catalog.pg_attribute a WHERE a.attrelid = object_id and (a.attname = property COLLATE sys.database_default)) + WHEN 'columnid' COLLATE sys.database_default THEN + (SELECT a.attnum FROM pg_catalog.pg_attribute a + WHERE a.attrelid = object_id AND (a.attname = property COLLATE sys.database_default)) + WHEN 'ordinal' COLLATE sys.database_default THEN + (SELECT b.count FROM (SELECT attname, row_number() OVER (ORDER BY a.attnum) AS count FROM pg_catalog.pg_attribute a + WHERE a.attrelid = object_id AND attisdropped = false AND attnum > 0) AS b WHERE b.attname = property COLLATE sys.database_default) + WHEN 'isidentity' COLLATE sys.database_default THEN (SELECT + CASE + WHEN char_length(a.attidentity) > 0 THEN 1 + ELSE 0 + END FROM pg_catalog.pg_attribute a WHERE a.attrelid = object_id and (a.attname = property COLLATE sys.database_default)) + ELSE + NULL + END; + RETURN return_value::INTEGER; +EXCEPTION + WHEN others THEN + RETURN NULL; +END; +$$; +GRANT EXECUTE ON FUNCTION sys.columnproperty(object_id OID, property NAME, property_name TEXT) TO PUBLIC; + -- Drops the temporary procedure used by the upgrade script. -- Please have this be one of the last statements executed in this upgrade script. DROP PROCEDURE sys.babelfish_drop_deprecated_object(varchar, varchar, varchar);