Skip to content

chore(schema_cache): extract queries to files #156

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
112 changes: 3 additions & 109 deletions crates/pg_schema_cache/src/functions.rs
Original file line number Diff line number Diff line change
Expand Up @@ -70,114 +70,8 @@ impl SchemaCacheItem for Function {
type Item = Function;

async fn load(pool: &PgPool) -> Result<Vec<Function>, sqlx::Error> {
sqlx::query_as!(
Function,
r#"
with functions as (
select
*,
-- proargmodes is null when all arg modes are IN
coalesce(
p.proargmodes,
array_fill('i'::text, array[cardinality(coalesce(p.proallargtypes, p.proargtypes))])
) as arg_modes,
-- proargnames is null when all args are unnamed
coalesce(
p.proargnames,
array_fill(''::text, array[cardinality(coalesce(p.proallargtypes, p.proargtypes))])
) as arg_names,
-- proallargtypes is null when all arg modes are IN
coalesce(p.proallargtypes, p.proargtypes) as arg_types,
array_cat(
array_fill(false, array[pronargs - pronargdefaults]),
array_fill(true, array[pronargdefaults])) as arg_has_defaults
from
pg_proc as p
where
p.prokind = 'f'
)
select
f.oid::int8 as id,
n.nspname as schema,
f.proname as name,
l.lanname as language,
case
when l.lanname = 'internal' then ''
else f.prosrc
end as definition,
case
when l.lanname = 'internal' then f.prosrc
else pg_get_functiondef(f.oid)
end as complete_statement,
coalesce(f_args.args, '[]') as args,
pg_get_function_arguments(f.oid) as argument_types,
pg_get_function_identity_arguments(f.oid) as identity_argument_types,
f.prorettype::int8 as return_type_id,
pg_get_function_result(f.oid) as return_type,
nullif(rt.typrelid::int8, 0) as return_type_relation_id,
f.proretset as is_set_returning_function,
case
when f.provolatile = 'i' then 'IMMUTABLE'
when f.provolatile = 's' then 'STABLE'
when f.provolatile = 'v' then 'VOLATILE'
end as behavior,
f.prosecdef as security_definer
from
functions f
left join pg_namespace n on f.pronamespace = n.oid
left join pg_language l on f.prolang = l.oid
left join pg_type rt on rt.oid = f.prorettype
left join (
select
oid,
jsonb_object_agg(param, value) filter (where param is not null) as config_params
from
(
select
oid,
(string_to_array(unnest(proconfig), '='))[1] as param,
(string_to_array(unnest(proconfig), '='))[2] as value
from
functions
) as t
group by
oid
) f_config on f_config.oid = f.oid
left join (
select
oid,
jsonb_agg(jsonb_build_object(
'mode', t2.mode,
'name', name,
'type_id', type_id,
'has_default', has_default
)) as args
from
(
select
oid,
unnest(arg_modes) as mode,
unnest(arg_names) as name,
unnest(arg_types)::int8 as type_id,
unnest(arg_has_defaults) as has_default
from
functions
) as t1,
lateral (
select
case
when t1.mode = 'i' then 'in'
when t1.mode = 'o' then 'out'
when t1.mode = 'b' then 'inout'
when t1.mode = 'v' then 'variadic'
else 'table'
end as mode
) as t2
group by
t1.oid
) f_args on f_args.oid = f.oid"#
)
.fetch_all(pool)
.await
sqlx::query_file_as!(Function, "src/queries/functions.sql")
.fetch_all(pool)
.await
}
}
119 changes: 119 additions & 0 deletions crates/pg_schema_cache/src/queries/functions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,119 @@
with functions as (
select
*,
-- proargmodes is null when all arg modes are IN
coalesce(
p.proargmodes,
array_fill(
'i' :: text,
array [cardinality(coalesce(p.proallargtypes, p.proargtypes))]
)
) as arg_modes,
-- proargnames is null when all args are unnamed
coalesce(
p.proargnames,
array_fill(
'' :: text,
array [cardinality(coalesce(p.proallargtypes, p.proargtypes))]
)
) as arg_names,
-- proallargtypes is null when all arg modes are IN
coalesce(p.proallargtypes, p.proargtypes) as arg_types,
array_cat(
array_fill(false, array [pronargs - pronargdefaults]),
array_fill(true, array [pronargdefaults])
) as arg_has_defaults
from
pg_proc as p
where
p.prokind = 'f'
)
select
f.oid :: int8 as id,
n.nspname as schema,
f.proname as name,
l.lanname as language,
case
when l.lanname = 'internal' then ''
else f.prosrc
end as definition,
case
when l.lanname = 'internal' then f.prosrc
else pg_get_functiondef(f.oid)
end as complete_statement,
coalesce(f_args.args, '[]') as args,
pg_get_function_arguments(f.oid) as argument_types,
pg_get_function_identity_arguments(f.oid) as identity_argument_types,
f.prorettype :: int8 as return_type_id,
pg_get_function_result(f.oid) as return_type,
nullif(rt.typrelid :: int8, 0) as return_type_relation_id,
f.proretset as is_set_returning_function,
case
when f.provolatile = 'i' then 'IMMUTABLE'
when f.provolatile = 's' then 'STABLE'
when f.provolatile = 'v' then 'VOLATILE'
end as behavior,
f.prosecdef as security_definer
from
functions f
left join pg_namespace n on f.pronamespace = n.oid
left join pg_language l on f.prolang = l.oid
left join pg_type rt on rt.oid = f.prorettype
left join (
select
oid,
jsonb_object_agg(param, value) filter (
where
param is not null
) as config_params
from
(
select
oid,
(string_to_array(unnest(proconfig), '=')) [1] as param,
(string_to_array(unnest(proconfig), '=')) [2] as value
from
functions
) as t
group by
oid
) f_config on f_config.oid = f.oid
left join (
select
oid,
jsonb_agg(
jsonb_build_object(
'mode',
t2.mode,
'name',
name,
'type_id',
type_id,
'has_default',
has_default
)
) as args
from
(
select
oid,
unnest(arg_modes) as mode,
unnest(arg_names) as name,
unnest(arg_types) :: int8 as type_id,
unnest(arg_has_defaults) as has_default
from
functions
) as t1,
lateral (
select
case
when t1.mode = 'i' then 'in'
when t1.mode = 'o' then 'out'
when t1.mode = 'b' then 'inout'
when t1.mode = 'v' then 'variadic'
else 'table'
end as mode
) as t2
group by
t1.oid
) f_args on f_args.oid = f.oid;
15 changes: 15 additions & 0 deletions crates/pg_schema_cache/src/queries/schemas.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,15 @@
select
n.oid :: int8 as "id!",
n.nspname as name,
u.rolname as "owner!"
from
pg_namespace n,
pg_roles u
where
n.nspowner = u.oid
and (
pg_has_role(n.nspowner, 'USAGE')
or has_schema_privilege(n.oid, 'CREATE, USAGE')
)
and not pg_catalog.starts_with(n.nspname, 'pg_temp_')
and not pg_catalog.starts_with(n.nspname, 'pg_toast_temp_');
40 changes: 40 additions & 0 deletions crates/pg_schema_cache/src/queries/tables.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,40 @@
select
c.oid :: int8 as "id!",
nc.nspname as schema,
c.relname as name,
c.relrowsecurity as rls_enabled,
c.relforcerowsecurity as rls_forced,
case
when c.relreplident = 'd' then 'DEFAULT'
when c.relreplident = 'i' then 'INDEX'
when c.relreplident = 'f' then 'FULL'
else 'NOTHING'
end as "replica_identity!",
pg_total_relation_size(format('%I.%I', nc.nspname, c.relname)) :: int8 as "bytes!",
pg_size_pretty(
pg_total_relation_size(format('%I.%I', nc.nspname, c.relname))
) as "size!",
pg_stat_get_live_tuples(c.oid) as "live_rows_estimate!",
pg_stat_get_dead_tuples(c.oid) as "dead_rows_estimate!",
obj_description(c.oid) as comment
from
pg_namespace nc
join pg_class c on nc.oid = c.relnamespace
where
c.relkind in ('r', 'p')
and not pg_is_other_temp_schema(nc.oid)
and (
pg_has_role(c.relowner, 'USAGE')
or has_table_privilege(
c.oid,
'SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER'
)
or has_any_column_privilege(c.oid, 'SELECT, INSERT, UPDATE, REFERENCES')
)
group by
c.oid,
c.relname,
c.relrowsecurity,
c.relforcerowsecurity,
c.relreplident,
nc.nspname;
53 changes: 53 additions & 0 deletions crates/pg_schema_cache/src/queries/types.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,53 @@
select
t.oid :: int8 as "id!",
t.typname as name,
n.nspname as "schema!",
format_type (t.oid, null) as "format!",
coalesce(t_enums.enums, '[]') as enums,
coalesce(t_attributes.attributes, '[]') as attributes,
obj_description (t.oid, 'pg_type') as comment
from
pg_type t
left join pg_namespace n on n.oid = t.typnamespace
left join (
select
enumtypid,
jsonb_agg(
enumlabel
order by
enumsortorder
) as enums
from
pg_enum
group by
enumtypid
) as t_enums on t_enums.enumtypid = t.oid
left join (
select
oid,
jsonb_agg(
jsonb_build_object('name', a.attname, 'type_id', a.atttypid :: int8)
order by
a.attnum asc
) as attributes
from
pg_class c
join pg_attribute a on a.attrelid = c.oid
where
c.relkind = 'c'
and not a.attisdropped
group by
c.oid
) as t_attributes on t_attributes.oid = t.typrelid
where
(
t.typrelid = 0
or (
select
c.relkind = 'c'
from
pg_class c
where
c.oid = t.typrelid
)
);
10 changes: 10 additions & 0 deletions crates/pg_schema_cache/src/queries/versions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
select
version(),
current_setting('server_version_num') :: int8 AS version_num,
(
select
count(*) :: int8 AS active_connections
FROM
pg_stat_activity
) AS active_connections,
current_setting('max_connections') :: int8 AS max_connections;
23 changes: 3 additions & 20 deletions crates/pg_schema_cache/src/schemas.rs
Original file line number Diff line number Diff line change
Expand Up @@ -13,25 +13,8 @@ impl SchemaCacheItem for Schema {
type Item = Schema;

async fn load(pool: &PgPool) -> Result<Vec<Schema>, sqlx::Error> {
sqlx::query_as!(
Schema,
r#"select
n.oid::int8 as "id!",
n.nspname as name,
u.rolname as "owner!"
from
pg_namespace n,
pg_roles u
where
n.nspowner = u.oid
and (
pg_has_role(n.nspowner, 'USAGE')
or has_schema_privilege(n.oid, 'CREATE, USAGE')
)
and not pg_catalog.starts_with(n.nspname, 'pg_temp_')
and not pg_catalog.starts_with(n.nspname, 'pg_toast_temp_')"#
)
.fetch_all(pool)
.await
sqlx::query_file_as!(Schema, "src/queries/schemas.sql")
.fetch_all(pool)
.await
}
}
Loading
Loading