├── examples └── accent.png ├── README.md ├── LICENSE ├── pg_dup_idx ├── pg_missing_idx ├── pg_unused_idx └── pg_graph /examples/accent.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hauleth/pg-utils/HEAD/examples/accent.png -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Collection of PostgreSQL utilities 2 | 3 | Some scripts that I have written during my work with PostgreSQL. 4 | 5 | ## `pg_graph` 6 | 7 | Create [Graphviz's][gv] DOT file describing whole database. Can be seen as poor 8 | man's ERD generator for existing DBs. 9 | 10 | ### Usage 11 | 12 | ``` 13 | $ pg_graph | dot -Tsvg > out.svg 14 | ``` 15 | 16 | Example output (generated for [Accent][accent] translation tool): 17 | 18 | ![Output of pg\_graph command generated as image via dot command](examples/accent.png) 19 | 20 | ## License 21 | 22 | See [`LICENSE`](LICENSE) file. 23 | 24 | [gv]: https://www.graphviz.org 25 | [accent]: https://github.com/mirego/accent 26 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright 2018 Łukasz Niemier 2 | 3 | Permission to use, copy, modify, and/or distribute this software for any purpose 4 | with or without fee is hereby granted, provided that the above copyright notice 5 | and this permission notice appear in all copies. 6 | 7 | THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL WARRANTIES WITH 8 | REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED WARRANTIES OF MERCHANTABILITY AND 9 | FITNESS. IN NO EVENT SHALL THE AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, 10 | INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS 11 | OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, NEGLIGENCE OR OTHER 12 | TORTIOUS ACTION, ARISING OUT OF OR IN CONNECTION WITH THE USE OR PERFORMANCE OF 13 | THIS SOFTWARE. 14 | -------------------------------------------------------------------------------- /pg_dup_idx: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | # Copyright 2018 Łukasz Niemier 3 | 4 | # Permission to use, copy, modify, and/or distribute this software for any purpose 5 | # with or without fee is hereby granted, provided that the above copyright notice 6 | # and this permission notice appear in all copies. 7 | 8 | # THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL WARRANTIES WITH 9 | # REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED WARRANTIES OF MERCHANTABILITY AND 10 | # FITNESS. IN NO EVENT SHALL THE AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, 11 | # INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS 12 | # OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, NEGLIGENCE OR OTHER 13 | # TORTIOUS ACTION, ARISING OUT OF OR IN CONNECTION WITH THE USE OR PERFORMANCE OF 14 | # THIS SOFTWARE. 15 | 16 | exec psql -1qX "$@" < 1 29 | ) q 30 | INNER JOIN pg_class c 31 | ON c.oid = indrelid 32 | INNER JOIN information_schema.columns co 33 | ON co.table_name = relname AND co.ordinal_position = keys; 34 | EOF 35 | -------------------------------------------------------------------------------- /pg_missing_idx: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | # Copyright 2018 Łukasz Niemier 3 | 4 | # Permission to use, copy, modify, and/or distribute this software for any purpose 5 | # with or without fee is hereby granted, provided that the above copyright notice 6 | # and this permission notice appear in all copies. 7 | 8 | # THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL WARRANTIES WITH 9 | # REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED WARRANTIES OF MERCHANTABILITY AND 10 | # FITNESS. IN NO EVENT SHALL THE AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, 11 | # INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS 12 | # OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, NEGLIGENCE OR OTHER 13 | # TORTIOUS ACTION, ARISING OUT OF OR IN CONNECTION WITH THE USE OR PERFORMANCE OF 14 | # THIS SOFTWARE. 15 | 16 | exec psql -1qX "$@" < 0.01 32 | ORDER BY usage_percentage DESC; 33 | EOF 34 | -------------------------------------------------------------------------------- /pg_unused_idx: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | # Copyright 2018 Łukasz Niemier 3 | 4 | # Permission to use, copy, modify, and/or distribute this software for any purpose 5 | # with or without fee is hereby granted, provided that the above copyright notice 6 | # and this permission notice appear in all copies. 7 | 8 | # THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL WARRANTIES WITH 9 | # REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED WARRANTIES OF MERCHANTABILITY AND 10 | # FITNESS. IN NO EVENT SHALL THE AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, 11 | # INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS 12 | # OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, NEGLIGENCE OR OTHER 13 | # TORTIOUS ACTION, ARISING OUT OF OR IN CONNECTION WITH THE USE OR PERFORMANCE OF 14 | # THIS SOFTWARE. 15 | 16 | exec psql -1qX "$@" <' 45 | || c.table_name || '' 46 | || string_agg('' 47 | || c.column_name || ': ' || data_type || '', 48 | '') 49 | || '>]' 50 | FROM 51 | (SELECT * FROM information_schema.columns ORDER BY table_name, ordinal_position) c 52 | LEFT OUTER JOIN LATERAL ( 53 | SELECT key || '_out' AS key 54 | FROM relations r 55 | WHERE (r.table_name = c.table_name AND r.column_name = c.column_name) 56 | LIMIT 1 57 | ) out ON TRUE 58 | LEFT OUTER JOIN LATERAL ( 59 | SELECT key || '_in' AS key 60 | FROM relations r 61 | WHERE (r.foreign_table_name = c.table_name AND r.foreign_column_name = c.column_name) 62 | LIMIT 1 63 | ) "into" ON TRUE 64 | WHERE c.table_schema = 'public' 65 | GROUP BY c.table_name 66 | ), 67 | links AS ( 68 | SELECT 69 | table_name || ':' || key || '_out -> ' || foreign_table_name || ':' || key || '_in [label="' || constraint_name || '"];' 70 | FROM relations 71 | ) 72 | SELECT * FROM columns UNION ALL SELECT * FROM links; 73 | 74 | \echo '}' 75 | EOF 76 | --------------------------------------------------------------------------------