Skip to content

Instantly share code, notes, and snippets.

@akki
Created July 25, 2016 17:11
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save akki/6a64075ad3c50f3bcb4926dc49a06939 to your computer and use it in GitHub Desktop.
Save akki/6a64075ad3c50f3bcb4926dc49a06939 to your computer and use it in GitHub Desktop.
Desired output:
relname | array | indisunique | indisprimary | order | type (can skip this if it is difficult to get this column)
---------------------------------+-------+-------------+--------------+-------------+-----------------------------------------------------------
ticket26180_indexes_spamin_pkey | {id} | t | t | {ASC} | btree
ticket26180_a_6fe9a5_idx | {a,b} | f | f | {ASC, ASC} | btree
test26180_indexes_spamin_atpata | {a,b} | f | f | {ASC, DESC} | btree
test26180_indexes_spamin_b_hsh | {b} | f | f | | hash
test26180_indexes_spamin_a_hsh | {a} | f | f | | hash
Currently I am getting
relname | array | indisunique | indisprimary
---------------------------------+-------+-------------+--------------
ticket26180_indexes_spamin_pkey | {id} | t | t
ticket26180_a_6fe9a5_idx | {a,b} | f | f
test26180_indexes_spamin_atpata | {a,b} | f | f
test26180_indexes_spamin_b_hsh | {b} | f | f
test26180_indexes_spamin_a_hsh | {a} | f | f
using:
SELECT
c2.relname,
ARRAY(
SELECT (SELECT attname FROM pg_catalog.pg_attribute WHERE attnum = i AND attrelid = c.oid)
FROM unnest(idx.indkey) i
),
idx.indisunique,
idx.indisprimary
FROM pg_catalog.pg_class c, pg_catalog.pg_class c2,
pg_catalog.pg_index idx
WHERE c.oid = idx.indrelid
AND idx.indexrelid = c2.oid
AND c.relname = 'ticket26180_indexes_spamin';
------------------------------------------------------ Some queries which might be helpful -------------------------------------------------------------
Way to find ASC, DESC (after a lot of Googling, pheww):
table_name | indisunique | index_name | ordinal_position | column_name | asc_or_desc | filter_condition
----------------------------+-------------+---------------------------------+------------------+-------------+-------------+------------------
ticket26180_indexes_spamin | t | ticket26180_indexes_spamin_pkey | 1 | id | ASC |
ticket26180_indexes_spamin | f | ticket26180_a_6fe9a5_idx | 1 | a | ASC |
ticket26180_indexes_spamin | f | ticket26180_a_6fe9a5_idx | 2 | b | ASC |
ticket26180_indexes_spamin | f | test26180_indexes_spamin_atpata | 1 | a | DESC |
ticket26180_indexes_spamin | f | test26180_indexes_spamin_atpata | 2 | b | ASC |
ticket26180_indexes_spamin | f | test26180_indexes_spamin_b_hsh | 1 | b | |
ticket26180_indexes_spamin | f | test26180_indexes_spamin_a_hsh | 1 | a | |
using:
SELECT ct.relname AS TABLE_NAME,
i.indisunique,
ci.relname AS INDEX_NAME,
(i.keys).n AS ORDINAL_POSITION,
pg_catalog.pg_get_indexdef(ci.oid, (i.keys).n, false) AS COLUMN_NAME,
CASE am.amcanorder
WHEN true THEN CASE i.indoption[(i.keys).n - 1] & 1
WHEN 1 THEN 'DESC'
ELSE 'ASC'
END
ELSE NULL
END AS ASC_OR_DESC,
pg_catalog.pg_get_expr(i.indpred, i.indrelid) AS FILTER_CONDITION
FROM pg_catalog.pg_class ct
JOIN pg_catalog.pg_namespace n ON (ct.relnamespace = n.oid)
JOIN (SELECT i.indexrelid, i.indrelid, i.indoption,
i.indisunique, i.indisclustered, i.indpred,
i.indexprs,
information_schema._pg_expandarray(i.indkey) AS keys
FROM pg_catalog.pg_index i) i
ON (ct.oid = i.indrelid)
JOIN pg_catalog.pg_class ci ON (ci.oid = i.indexrelid)
JOIN pg_catalog.pg_am am ON (ci.relam = am.oid)
WHERE n.nspname = 'public'
AND ct.relname = 'ticket26180_indexes_spamin';
Way to find type of index
attname | indkey | indisunique | indisprimary | amname
---------+--------+-------------+--------------+--------
id | 1 | t | t | btree
a | 2 3 | f | f | btree
a | 2 3 | f | f | btree
b | 3 | f | f | hash
a | 2 | f | f | hash
using
SELECT attr.attname, idx.indkey, idx.indisunique, idx.indisprimary,
am.amname
FROM pg_catalog.pg_class c, pg_catalog.pg_class c2,
pg_catalog.pg_index idx, pg_catalog.pg_attribute attr, pg_catalog.pg_am am
WHERE c.oid = idx.indrelid
AND idx.indexrelid = c2.oid
AND attr.attrelid = c.oid
AND attr.attnum = idx.indkey[0]
AND c2.relam = am.oid
AND c.relname = 'ticket26180_indexes_spamin';
--------------------------------------------------------------------------------------------------------------------------------------------------
Finally:
Credits - RhodiumToad on IRC. :)
select schemaname, tablename, indexname, amname, indisunique, indisprimary,
array_agg(attname order by ord) as columns,
array_agg(coll order by ord) as collations,
array_agg(opclass order by ord) as opclasses,
array_agg(ordering order by ord) as orderings,
array_agg(expression order by ord) as expressions,
predicate
from (select n.nspname as schemaname,
ct.relname as tablename,
c.relname as indexname,
m.amname,
s.indisunique, s.indisprimary, s.ord,
a.attname,
case when con.nspname is not null
then format('%I.%I',con.nspname,co.collname)
end as coll,
case when oc.opcname is not null
then format('%I.%I',ocn.nspname,oc.opcname)
end as opclass,
case when m.amcanorder
then format('%s NULLS %s',
case (option & 1) when 1 then 'DESC' else 'ASC' end,
case (option & 2) when 2 then 'FIRST' else 'LAST' end)
end as ordering,
pg_get_expr(s.indpred, s.indrelid) as predicate,
pg_get_indexdef(s.indexrelid, ord, false) as expression
from (select *,
generate_series(1,array_length(i.indkey,1)) as ord,
unnest(i.indkey) as key,
unnest(i.indcollation) as coll,
unnest(i.indclass) as class,
unnest(i.indoption) as option
from pg_index i) s
join pg_class c on (c.oid=s.indexrelid)
join pg_class ct on (ct.oid=s.indrelid)
join pg_namespace n on (n.oid=c.relnamespace)
join pg_am m on (m.oid=c.relam)
left join pg_attribute a on (a.attrelid=s.indrelid and a.attnum=s.key)
left join pg_collation co on (co.oid=s.coll)
left join pg_namespace con on (con.oid=co.collnamespace)
left join pg_opclass oc on (oc.oid=s.class)
left join pg_namespace ocn on (ocn.oid=oc.opcnamespace)
) s2
where tablename = 'yourtable'
group by schemaname, tablename, indexname, amname, indisunique, indisprimary, predicate;
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment