diff --git a/.sqlx/query-b0163e58e9c646e3af524174081b74ab7e7938e9516ea21513265c49d304b6ea.json b/.sqlx/query-1cc58ddce2b52b5d6f6519cde339f258bce50342c2d5cce036dba4f9062cf811.json similarity index 56% rename from .sqlx/query-b0163e58e9c646e3af524174081b74ab7e7938e9516ea21513265c49d304b6ea.json rename to .sqlx/query-1cc58ddce2b52b5d6f6519cde339f258bce50342c2d5cce036dba4f9062cf811.json index eb8d07787..361bbec20 100644 --- a/.sqlx/query-b0163e58e9c646e3af524174081b74ab7e7938e9516ea21513265c49d304b6ea.json +++ b/.sqlx/query-1cc58ddce2b52b5d6f6519cde339f258bce50342c2d5cce036dba4f9062cf811.json @@ -1,6 +1,6 @@ { "db_name": "PostgreSQL", - "query": "with\n available_tables as (\n select\n c.relname as table_name,\n c.oid as table_oid,\n c.relkind as class_kind,\n n.nspname as schema_name\n from\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n on n.oid = c.relnamespace\n where\n -- r: normal tables\n -- v: views\n -- m: materialized views\n -- f: foreign tables\n -- p: partitioned tables\n c.relkind in ('r', 'v', 'm', 'f', 'p')\n ),\n available_indexes as (\n select\n unnest (ix.indkey) as attnum,\n ix.indisprimary as is_primary,\n ix.indisunique as is_unique,\n ix.indrelid as table_oid\n from\n pg_catalog.pg_class c\n join pg_catalog.pg_index ix on c.oid = ix.indexrelid\n where\n c.relkind = 'i'\n )\nselect\n atts.attname as name,\n atts.attnum as number,\n ts.table_name,\n ts.table_oid :: int8 as \"table_oid!\",\n ts.class_kind :: char as \"class_kind!\",\n ts.schema_name,\n atts.atttypid :: int8 as \"type_id!\",\n tps.typname as \"type_name\",\n not atts.attnotnull as \"is_nullable!\",\n nullif(\n information_schema._pg_char_max_length (atts.atttypid, atts.atttypmod),\n -1\n ) as varchar_length,\n pg_get_expr (def.adbin, def.adrelid) as default_expr,\n coalesce(ix.is_primary, false) as \"is_primary_key!\",\n coalesce(ix.is_unique, false) as \"is_unique!\",\n pg_catalog.col_description (ts.table_oid, atts.attnum) as comment\nfrom\n pg_catalog.pg_attribute atts\n join available_tables ts on atts.attrelid = ts.table_oid\n left join available_indexes ix on atts.attrelid = ix.table_oid\n and atts.attnum = ix.attnum\n left join pg_catalog.pg_attrdef def on atts.attrelid = def.adrelid\n and atts.attnum = def.adnum\n left join pg_catalog.pg_type tps on atts.atttypid = tps.oid\nwhere\n -- system columns, such as `cmax` or `tableoid`, have negative `attnum`s\n atts.attnum >= 0 and atts.atttypid is not null and tps.oid is not null\norder by\n schema_name desc,\n table_name,\n atts.attnum;", + "query": "with\n available_tables as (\n select\n c.relname as table_name,\n c.oid as table_oid,\n c.relkind as class_kind,\n n.nspname as schema_name\n from\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n on n.oid = c.relnamespace\n where\n -- r: normal tables\n -- v: views\n -- m: materialized views\n -- f: foreign tables\n -- p: partitioned tables\n c.relkind in ('r', 'v', 'm', 'f', 'p')\n ),\n available_indexes as (\n select\n unnest (ix.indkey) as attnum,\n bool_or(ix.indisprimary) as is_primary,\n bool_or(ix.indisunique) as is_unique,\n ix.indrelid as table_oid\n from\n pg_catalog.pg_class c\n join pg_catalog.pg_index ix on c.oid = ix.indexrelid\n where\n c.relkind = 'i'\n group by table_oid, attnum\n )\nselect\n atts.attname as name,\n atts.attnum as number,\n ts.table_name,\n ts.table_oid :: int8 as \"table_oid!\",\n ts.class_kind :: char as \"class_kind!\",\n ts.schema_name,\n atts.atttypid :: int8 as \"type_id!\",\n tps.typname as \"type_name\",\n not atts.attnotnull as \"is_nullable!\",\n nullif(\n information_schema._pg_char_max_length (atts.atttypid, atts.atttypmod),\n -1\n ) as varchar_length,\n pg_get_expr (def.adbin, def.adrelid) as default_expr,\n coalesce(ix.is_primary, false) as \"is_primary_key!\",\n coalesce(ix.is_unique, false) as \"is_unique!\",\n pg_catalog.col_description (ts.table_oid, atts.attnum) as comment\nfrom\n pg_catalog.pg_attribute atts\n join available_tables ts on atts.attrelid = ts.table_oid\n left join available_indexes ix on atts.attrelid = ix.table_oid\n and atts.attnum = ix.attnum\n left join pg_catalog.pg_attrdef def on atts.attrelid = def.adrelid\n and atts.attnum = def.adnum\n left join pg_catalog.pg_type tps on atts.atttypid = tps.oid\nwhere\n -- system columns, such as `cmax` or `tableoid`, have negative `attnum`s\n atts.attnum >= 0 and atts.atttypid is not null and tps.oid is not null\norder by\n schema_name desc,\n table_name,\n atts.attnum;", "describe": { "columns": [ { @@ -94,5 +94,5 @@ null ] }, - "hash": "b0163e58e9c646e3af524174081b74ab7e7938e9516ea21513265c49d304b6ea" + "hash": "1cc58ddce2b52b5d6f6519cde339f258bce50342c2d5cce036dba4f9062cf811" } diff --git a/crates/pgt_schema_cache/src/queries/columns.sql b/crates/pgt_schema_cache/src/queries/columns.sql index faa15dd29..210c98edf 100644 --- a/crates/pgt_schema_cache/src/queries/columns.sql +++ b/crates/pgt_schema_cache/src/queries/columns.sql @@ -19,14 +19,15 @@ with available_indexes as ( select unnest (ix.indkey) as attnum, - ix.indisprimary as is_primary, - ix.indisunique as is_unique, + bool_or(ix.indisprimary) as is_primary, + bool_or(ix.indisunique) as is_unique, ix.indrelid as table_oid from pg_catalog.pg_class c join pg_catalog.pg_index ix on c.oid = ix.indexrelid where c.relkind = 'i' + group by table_oid, attnum ) select atts.attname as name, diff --git a/crates/pgt_schema_cache/src/schema_cache.rs b/crates/pgt_schema_cache/src/schema_cache.rs index 227b49883..fa87b2af2 100644 --- a/crates/pgt_schema_cache/src/schema_cache.rs +++ b/crates/pgt_schema_cache/src/schema_cache.rs @@ -165,7 +165,9 @@ pub trait SchemaCacheItem { #[cfg(test)] mod tests { - use sqlx::PgPool; + use std::collections::HashSet; + + use sqlx::{Executor, PgPool}; use crate::SchemaCache; @@ -175,4 +177,33 @@ mod tests { .await .expect("Couldnt' load Schema Cache"); } + + #[sqlx::test(migrator = "pgt_test_utils::MIGRATIONS")] + async fn it_does_not_have_duplicate_entries(test_db: PgPool) { + // we had some duplicate columns in the schema_cache because of indices including the same column multiple times. + // the columns were unnested as duplicates in the query + let setup = r#" + CREATE TABLE public.mfa_factors ( + id uuid PRIMARY KEY, + factor_name text NOT NULL + ); + + -- a second index on id! + CREATE INDEX idx_mfa_user_factor ON public.mfa_factors(id, factor_name); + "#; + + test_db.execute(setup).await.unwrap(); + + let cache = SchemaCache::load(&test_db) + .await + .expect("Couldn't load Schema Cache"); + + let set: HashSet = cache + .columns + .iter() + .map(|c| format!("{}.{}.{}", c.schema_name, c.table_name, c.name)) + .collect(); + + assert_eq!(set.len(), cache.columns.len()); + } }