Skip to content

Instantly share code, notes, and snippets.

@adunstan
adunstan / gist:803432
Created January 30, 2011 23:47
query_to_json.sql
create or replace function xml2json (xml) returns text
language plperlu as
$func$
use XML::XML2JSON;
use strict;
my $xml = shift;
my $XML2JSON = XML::XML2JSON->new(pretty => 0); # 1 for readable json
@adunstan
adunstan / skeleton_query.sql
Last active January 23, 2019 20:50
generate a select query for a given table, with optional alias and compaction
create or replace function make_select_query (tablename text, tablealias text default null, compact boolean default false)
returns text
language plpgsql as
$$
declare
rec record;
crec record;
firstrow boolean := true;
result text := '';
@adunstan
adunstan / make_type_list.sql
Created February 9, 2011 13:47
make a type list for a given type for use in with things like set returning functions, with optional alias name
create or replace function make_type_list(tablename text, typealias text default null) returns text
language plpgsql as
$$
declare
rec record;
crec record;
firstrow boolean := true;
talias text := '';
@adunstan
adunstan / setcluster.sql
Created August 7, 2011 17:14
set all tables clustered by PK if there is one and no clustering index is set
do $$
declare
rec record;
cmd text;
begin
for rec in
select n.nspname, rc.relname as tbl, ic.relname as idx
from pg_index i
join pg_class ic
@adunstan
adunstan / viewtables.sql
Created September 1, 2011 19:11
See which tables are called in a view
CREATE OR REPLACE FUNCTION public.viewtables(viewname text)
RETURNS SETOF text
LANGUAGE plperl
AS $function$
my $viewname = shift;
my $rv = spi_exec_query("explain (format yaml, verbose) SELECT * FROM $viewname");
my $resp = $rv->{rows}[0]->{'QUERY PLAN'};
my %tbls;
while ($resp =~ /Relation Name: (".*")\n\s+Schema: (".*")\n/g)
{
@adunstan
adunstan / dumpToc.pl
Created October 3, 2011 01:18
Dump header and full TOC from a custom PostgreSQL dump file
#!/usr/bin/perl
use strict;
use YAML;
my @formats = qw(Unknown Custom Files Tar Null Directory);
my @sections = qw(None PreData Data PostData);
my $result = [];
my $toc = [];
my %globs;
@adunstan
adunstan / Dist.pm
Created November 22, 2011 13:43
example Buildfarm module to run "make dist" and collect the results
package PGBuild::Modules::Dist;
use PGBuild::Options;
use PGBuild::SCM;
use strict;
use vars qw($VERSION); $VERSION = 'REL_4.6';
my $hooks = {
@adunstan
adunstan / explain_url.sql
Last active December 16, 2015 11:49
exlain_url sql function
CREATE OR REPLACE FUNCTION public.explain_url(query text)
RETURNS text
LANGUAGE plperlu
AS $function$
my $query = shift;
elog(ERROR,"not an explain query") unless $query =~ /^\s*explain\s/i;
my $rv = spi_exec_query($query);
my $nrows = $rv->{processed};
my $text = $query . "\n QUERY PLAN\n-------------------\n";
@adunstan
adunstan / vacuum_schema.sql
Last active August 29, 2015 13:57
Vacuum a PostgreSQL schema's tables via dblink
-- requires dblink extension the be installed
-- vacuum a schema via dblink
create or replace function vacuum_schema(schemaname text)
returns void
language plpgsql
as
$func$
declare
@adunstan
adunstan / sql_json_comparison_ops.sql
Last active April 18, 2023 10:26
JSON comparison operations in SQL for PostgreSQL
CREATE OR REPLACE FUNCTION json_cmp(left json, right json)
RETURNS integer AS $$
select bttextcmp($1::text, $2::text)
$$ LANGUAGE sql IMMUTABLE STRICT;
CREATE OR REPLACE FUNCTION json_eq(json, json)
RETURNS BOOLEAN LANGUAGE SQL STRICT IMMUTABLE AS $$
SELECT json_cmp($1, $2) = 0;
$$;