Skip to content

Commit

Permalink
Fix scripting of tables with index on non first columns (#2424)
Browse files Browse the repository at this point in the history
When exporting ddl_script for tables with indexes/constraints on columns which are not first in the table definition, wrong table definition in scripted. This is because the scripting tool uses sys.index_columns underneath and we are not returning the correct output currently.
We also need to fix the `index_id` in `sys.indexes` since index_id is unique id for each index per table. index_id in sys.indexes and sys.index_columns should be same.
Also fix sys.generated columns. Currently returns duplicates entries when two tables have same name generated columns.

### Issues Resolved
[BABEL-4817],[BABEL-4853]

Signed-off-by: Tanzeel Khan <[email protected]>
  • Loading branch information
tanscorpio7 authored Apr 9, 2024
1 parent fe50406 commit a5abc18
Show file tree
Hide file tree
Showing 23 changed files with 952 additions and 69 deletions.
2 changes: 1 addition & 1 deletion contrib/babelfishpg_tsql/Version.config
Original file line number Diff line number Diff line change
Expand Up @@ -2,6 +2,6 @@
# places during the build process

PGTSQL_MAJOR_VERSION=2
PGTSQL_MINOR_VERSION=8
PGTSQL_MINOR_VERSION=9
PGTSQL_MICRO_VERSION=0

61 changes: 40 additions & 21 deletions contrib/babelfishpg_tsql/sql/sys_functions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2750,36 +2750,55 @@ END;
$$;
GRANT EXECUTE ON FUNCTION sys.original_login() TO PUBLIC;

CREATE OR REPLACE FUNCTION sys.columnproperty(object_id oid, property name, property_name text)
RETURNS integer
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;
declare return_value integer;
begin
return_value := (
select
case 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)
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)
else
null
end
);

RETURN return_value::integer;
DECLARE
extra_bytes CONSTANT INTEGER := 4;
return_value INTEGER;
BEGIN
return_value:=
CASE 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 () 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)
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;
GRANT EXECUTE ON FUNCTION sys.columnproperty(object_id OID, property NAME, property_name TEXT) TO PUBLIC;

COMMENT ON FUNCTION sys.columnproperty
COMMENT ON FUNCTION sys.columnproperty
IS 'This function returns column or parameter information. Currently only works with "charmaxlen", and "allowsnull" otherwise returns 0.';

-- substring --
Expand Down
78 changes: 55 additions & 23 deletions contrib/babelfishpg_tsql/sql/sys_views.sql
Original file line number Diff line number Diff line change
Expand Up @@ -815,6 +815,15 @@ GRANT SELECT ON sys.identity_columns TO PUBLIC;

create or replace view sys.indexes as
-- Get all indexes from all system and user tables
with index_id_map as MATERIALIZED(
select
indexrelid,
case
when indisclustered then 1
else 1+row_number() over(partition by indrelid order by indexrelid)
end as index_id
from pg_index
)
select
cast(X.indrelid as int) as object_id
, cast(I.relname as sys.sysname) as name
Expand All @@ -834,17 +843,14 @@ select
, cast(0 as sys.bit) as has_filter
, cast(null as sys.nvarchar) as filter_definition
, cast(0 as sys.bit) as auto_created
, index_map.index_id
, cast(imap.index_id as int) as index_id
from pg_index X
inner join index_id_map imap on imap.indexrelid = X.indexrelid
inner join pg_class I on I.oid = X.indexrelid and I.relkind = 'i'
inner join pg_namespace nsp on nsp.oid = I.relnamespace
left join sys.babelfish_namespace_ext ext on (nsp.nspname = ext.nspname and ext.dbid = sys.db_id())
-- check if index is a unique constraint
left join pg_constraint const on const.conindid = I.oid and const.contype = 'u'
-- use rownumber to get index_id scoped on each objects
inner join
(select indexrelid, cast(case when indisclustered then 1 else 1+row_number() over(partition by indrelid) end as int)
as index_id from pg_index) as index_map on index_map.indexrelid = X.indexrelid
where has_schema_privilege(I.relnamespace, 'USAGE')
-- index is active
and X.indislive
Expand Down Expand Up @@ -2081,9 +2087,9 @@ SELECT out_object_id as object_id
, out_graph_type_desc as graph_type_desc
, cast(tsql_get_expr(d.adbin, d.adrelid) AS sys.nvarchar(4000)) AS definition
, 1::sys.bit AS uses_database_collation
, 0::sys.bit AS is_persisted
, 1::sys.bit AS is_persisted
FROM sys.columns_internal() sc
INNER JOIN pg_attribute a ON sc.out_name = a.attname COLLATE sys.database_default AND sc.out_column_id = a.attnum
INNER JOIN pg_attribute a ON sc.out_object_id = a.attrelid AND sc.out_column_id = a.attnum
INNER JOIN pg_attrdef d ON d.adrelid = a.attrelid AND d.adnum = a.attnum
WHERE a.attgenerated = 's' AND sc.out_is_computed::integer = 1;
GRANT SELECT ON sys.computed_columns TO PUBLIC;
Expand All @@ -2102,22 +2108,48 @@ SELECT CAST('TSQL Default TCP' AS sys.sysname) AS name
, CAST(0 AS sys.bit) AS is_admin_endpoint;
GRANT SELECT ON sys.endpoints TO PUBLIC;

create or replace view sys.index_columns
as
select i.indrelid::integer as object_id
, CAST(CASE WHEN i.indisclustered THEN 1 ELSE 1+row_number() OVER(PARTITION BY c.oid) END AS INTEGER) AS index_id
, a.attrelid::integer as index_column_id
, a.attnum::integer as column_id
, a.attnum::sys.tinyint as key_ordinal
, 0::sys.tinyint as partition_ordinal
, 0::sys.bit as is_descending_key
, 1::sys.bit as is_included_column
from pg_index as i
inner join pg_catalog.pg_attribute a on i.indexrelid = a.attrelid
inner join pg_class c on i.indrelid = c.oid
inner join sys.schemas sch on sch.schema_id = c.relnamespace
where has_schema_privilege(sch.schema_id, 'USAGE')
and has_table_privilege(c.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER');
CREATE OR REPLACE VIEW sys.index_columns
AS
WITH index_id_map AS MATERIALIZED (
SELECT
indexrelid,
CASE
WHEN indisclustered THEN 1
ELSE 1+row_number() OVER(PARTITION BY indrelid ORDER BY indexrelid)
END AS index_id
FROM pg_index
)
SELECT
CAST(i.indrelid AS INT) AS object_id,
-- should match index_id of sys.indexes
CAST(imap.index_id AS INT) AS index_id,
CAST(a.index_column_id AS INT) AS index_column_id,
CAST(a.attnum AS INT) AS column_id,
CAST(CASE
WHEN a.index_column_id <= i.indnkeyatts THEN a.index_column_id
ELSE 0
END AS SYS.TINYINT) AS key_ordinal,
CAST(0 AS SYS.TINYINT) AS partition_ordinal,
CAST(CASE
WHEN i.indoption[a.index_column_id-1] & 1 = 1 THEN 1
ELSE 0
END AS SYS.BIT) AS is_descending_key,
CAST(CASE
WHEN a.index_column_id > i.indnkeyatts THEN 1
ELSE 0
END AS SYS.BIT) AS is_included_column
FROM
pg_index i
INNER JOIN index_id_map imap ON imap.indexrelid = i.indexrelid
INNER JOIN pg_class c ON i.indrelid = c.oid
INNER JOIN pg_namespace nsp ON nsp.oid = c.relnamespace
LEFT JOIN sys.babelfish_namespace_ext ext ON (nsp.nspname = ext.nspname AND ext.dbid = sys.db_id())
LEFT JOIN unnest(i.indkey) WITH ORDINALITY AS a(attnum, index_column_id) ON true
WHERE
has_schema_privilege(c.relnamespace, 'USAGE') AND
has_table_privilege(c.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') AND
(nsp.nspname = 'sys' OR ext.nspname is not null) AND
i.indislive;
GRANT SELECT ON sys.index_columns TO PUBLIC;

-- internal function that returns relevant info needed
Expand Down
Original file line number Diff line number Diff line change
@@ -1,5 +1,5 @@
-- complain if script is sourced in psql, rather than via ALTER EXTENSION
\echo Use "ALTER EXTENSION ""babelfishpg_tsql"" UPDATE TO '2.7.0'" to load this file. \quit
\echo Use "ALTER EXTENSION ""babelfishpg_tsql"" UPDATE TO '2.8.0'" to load this file. \quit

-- add 'sys' to search path for the convenience
SELECT set_config('search_path', 'sys, '||current_setting('search_path'), false);
Expand Down
Loading

0 comments on commit a5abc18

Please sign in to comment.