Skip to content

Commit 2838b65

Browse files
handwritten column incoming
1 parent 8336135 commit 2838b65

File tree

2 files changed

+37
-10
lines changed

2 files changed

+37
-10
lines changed

crates/pg_schema_cache/src/columns.rs

Lines changed: 9 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -42,17 +42,20 @@ pub struct Column {
4242

4343
pub schema_name: String,
4444
pub type_id: i64,
45-
// pub is_nullable: bool,
46-
// pub is_primary_key: bool,
4745

48-
// pub default_value: Option<String>,
46+
pub is_nullable: bool,
4947

50-
// pub varchar_length: Option<i32>,
48+
pub is_primary_key: bool,
49+
pub is_unique: bool,
5150

51+
/// The Default "value" of the column. Might be a function call, hence "_expr".
52+
pub default_expr: Option<String>,
53+
54+
pub varchar_length: Option<i32>,
5255
// /// None if the column is not a foreign key.
5356
// pub foreign_key: Option<ForeignKeyReference>,
54-
55-
// pub comment: Option<String>,
57+
/// Comment inserted via `COMMENT ON COLUMN my_table.my_comment '...'`, if present.
58+
pub comment: Option<String>,
5659
}
5760

5861
#[derive(Debug, Clone, PartialEq, Eq)]

crates/pg_schema_cache/src/queries/columns.sql

Lines changed: 28 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -7,14 +7,26 @@ with
77
n.nspname as schema_name
88
from
99
pg_catalog.pg_class c
10-
left join pg_catalog.pg_namespace n on n.oid = c.relnamespace
10+
join pg_catalog.pg_namespace n on n.oid = c.relnamespace
1111
where
1212
-- r: normal tables
1313
-- v: views
1414
-- m: materialized views
1515
-- f: foreign tables
1616
-- p: partitioned tables
1717
c.relkind in ('r', 'v', 'm', 'f', 'p')
18+
),
19+
available_indexes as (
20+
select
21+
unnest (ix.indkey) as attnum,
22+
ix.indisprimary as is_primary,
23+
ix.indisunique as is_unique,
24+
ix.indrelid as table_oid
25+
from
26+
pg_catalog.pg_class c
27+
join pg_catalog.pg_index ix on c.oid = ix.indexrelid
28+
where
29+
c.relkind = 'i'
1830
)
1931
select
2032
atts.attname as name,
@@ -28,10 +40,22 @@ select
2840
nullif(
2941
information_schema._pg_char_max_length (atts.atttypid, atts.atttypmod),
3042
-1
31-
) as varchar_length
43+
) as varchar_length,
44+
pg_get_expr (def.adbin, def.adrelid) as default_expr,
45+
coalesce(ix.is_primary, false) as is_primary_key,
46+
coalesce(ix.is_unique, false) as is_unique,
47+
pg_catalog.col_description (ts.table_oid, atts.attnum) as comment
3248
from
3349
pg_catalog.pg_attribute atts
34-
left join available_tables ts on atts.attrelid = ts.table_oid
50+
join available_tables ts on atts.attrelid = ts.table_oid
51+
left join available_indexes ix on atts.attrelid = ix.table_oid
52+
and atts.attnum = ix.attnum
53+
left join pg_catalog.pg_attrdef def on atts.attrelid = def.adrelid
54+
and atts.attnum = def.adnum
3555
where
3656
-- system columns, such as `cmax` or `tableoid`, have negative `attnum`s
37-
atts.attnum >= 0;
57+
atts.attnum >= 0
58+
order by
59+
schema_name desc,
60+
table_name,
61+
attnum;

0 commit comments

Comments
 (0)