Add files

This commit is contained in:
barnold 2022-09-04 18:06:49 +01:00
parent a43f8ea8cc
commit bdd38bb3fb
6 changed files with 667 additions and 3 deletions

69
Makefile Normal file
View File

@ -0,0 +1,69 @@
# This Makefile is for (re)doing some database operations.
.PHONY: \
clean \
dangerous \
export-all \
export-data \
load \
rebuild \
redo-func \
restore-all \
restore-data
# Safe targets first.
# Rebuild triggers and functions, restore grants.
redo-func:
psql --dbname="meter_reading" --username="mr_owner" \
--command="\set ON_ERROR_STOP" \
--command="BEGIN TRANSACTION;" \
--file="func.sql" \
--command="COMMIT;"
# Export the entire database.
export-all:
pg_dump --username="mr_owner" meter_reading > export-all.sql
# Export only the data.
export-data:
pg_dump --data-only meter_reading > export-data.sql
################################################################################
#
# Destructive targets follow, with a small precautionary barrier in
# front of them.
#
################################################################################
dangerous:
ifndef MR_DANGEROUS
$(error Refusing to continue without MR_DANGEROUS set.)
endif
# Drop the database.
clean: dangerous
dropdb --if-exists --username="mr_owner" meter_reading
# Drop and recreate *the entire database* with no rows yet.
rebuild: dangerous clean
createdb --username="mr_owner" meter_reading \
"For my domestic utility meter readings."
psql --dbname="meter_reading" --username="mr_owner" \
--command="\set ON_ERROR_STOP" \
--command="BEGIN TRANSACTION;" \
--file="table.sql" --file="func.sql" \
--command="COMMIT;"
# Restore *the entire database* from an export file.
restore-all: dangerous clean
createdb --username="mr_owner" --template="template0" meter_reading
psql --username="mr_owner" meter_reading < export-all.sql
# Replace existing data, if any, with previously exported data.
restore-data: dangerous
psql --dbname="meter_reading" --username="mr_owner" \
--command="\set ON_ERROR_STOP" \
--command="BEGIN TRANSACTION;" \
--command="TRUNCATE TABLE meter_reading;" --file="export-data.sql" \
--command="COMMIT;"

View File

@ -1,3 +0,0 @@
# meter-reading
Record and report on your utility meter readings.

82
README.org Normal file
View File

@ -0,0 +1,82 @@
* About
This is an overengineered utility I wrote for myself to record
utility meter readings. It uses postgres for the database and perl
for the UI. There should be a screen shot accompanying this to show
what it looks like in use.
Most of the following is about setting up postgres. The perl part
is in a script that you run.
Comments and questions welcome at <barnold@tilde.club>.
* One-off steps for the postgres cluster.
** What these steps are for
These are independent of the meter readings database (mrdb) and
precede its creation. They create database roles and authentication,
which exist at the cluster level and don't depend on the mrdb.
Want the mrdb owned by a postgres user other than my personal role.
Want the ability to connect to mrdb in my personal role and use mrdb
to save readings, etc.
Want to avoid routinely connecting to mrdb as its owner. I'm less
likely to inadvertently drop a table if I lack privilege and have to
go out of my way to connect as the owner. The owner should grant me
only the accesses I need for routine use.
The following sets up for that, for a local postgres only, not over
the network.
** Create the postgres user "mr_owner"
Create a db user to own the tables.
# su - postgres
$ createuser --connection-limit=2 --createdb --echo mr_owner
** Give "barnold" connect access as the "mr_owner" user.
To allow myself to connect as mr_owner, change some postgres
config in /etc/postgresql/12/main/.
pg_ident.conf: add two 'barnoldmap' lines (both are required) so that the
end of the file reads as follows.
# MAPNAME SYSTEM-USERNAME PG-USERNAME
barnoldmap barnold barnold
barnoldmap barnold mr_owner
pg_hba.conf: modify the second "local" line, the one following the
"postgres" line, so that it has a map option on the end. After
removing some of the whitespace, it reads:
local all all peer map=barnoldmap
** The mr_user role
Create it with
# su - postgres
postgres@argon:~$ createuser --connection-limit=4 --no-login mr_user
and add myself to it with
postgres@argon:~$ psql
postgres=# grant mr_user to barnold;
GRANT ROLE
* Repeatable steps for the meter reading database
These are done in the Makefile. Can do them as many times as wanted,
they don't perturb the cluster-level things described above.
* Dependencies
make
postgresql-12+
libdbd-pg-perl
libterm-readline-gnu-perl
libterm-extendedcolor-perl
libtry-tiny-perl

274
func.sql Normal file
View File

@ -0,0 +1,274 @@
-- Drop all safely-rebuildable things.
DROP VIEW IF EXISTS mr_consumption;
DROP FUNCTION IF EXISTS give_reading;
DROP FUNCTION IF EXISTS take_reading;
DROP PROCEDURE IF EXISTS ensure_sane;
DROP FUNCTION IF EXISTS sanity_limit;
DROP FUNCTION IF EXISTS consumption_per_day;
DROP FUNCTION IF EXISTS fluid_unit;
DROP PROCEDURE IF EXISTS ensure_monotonic;
DROP TRIGGER IF EXISTS mr_freeze ON meter_reading;
DROP FUNCTION IF EXISTS mr_freeze;
--------------------------------------------------------------------------------
-- Rebuild them.
CREATE OR REPLACE FUNCTION mr_freeze ()
RETURNS TRIGGER
AS $$
BEGIN
IF OLD.when_entered < CURRENT_TIMESTAMP - '3 days'::INTERVAL THEN
RAISE EXCEPTION 'To change old rows, disable trigger mr_freeze.';
END IF;
RETURN NEW;
END;
$$ LANGUAGE 'plpgsql' SECURITY DEFINER;
CREATE TRIGGER mr_freeze
BEFORE UPDATE OR DELETE
ON meter_reading
FOR EACH ROW
EXECUTE PROCEDURE mr_freeze();
--------------------------------------------------------------------------------
CREATE OR REPLACE PROCEDURE ensure_monotonic
( IN i_fluid fluid_t,
IN i_reading reading_d,
IN i_when_taken DATE
)
AS $$
BEGIN
PERFORM 'x' FROM meter_reading
WHERE when_taken < i_when_taken AND fluid = i_fluid AND reading > i_reading
ORDER BY when_taken DESC LIMIT 1
FOR UPDATE OF meter_reading;
IF FOUND THEN
RAISE EXCEPTION 'bad reading: an earlier reading is higher.';
END IF;
PERFORM 'x' FROM meter_reading
WHERE when_taken > i_when_taken AND fluid = i_fluid AND reading < i_reading
ORDER BY when_taken DESC LIMIT 1
FOR UPDATE OF meter_reading;
IF FOUND THEN
RAISE EXCEPTION 'bad reading: a later reading is lower.';
END IF;
RETURN;
END;
$$
LANGUAGE plpgsql
SECURITY DEFINER
;
--------------------------------------------------------------------------------
CREATE OR REPLACE FUNCTION fluid_unit
( IN i_fluid fluid_t
)
RETURNS unit_t
AS $$
SELECT
CASE i_fluid
WHEN 'E' THEN 'KWh'
WHEN 'G' THEN ''
WHEN 'W' THEN ''
ELSE NULL
END::unit_t
$$
LANGUAGE SQL
IMMUTABLE
CALLED ON NULL INPUT
SECURITY DEFINER
;
--------------------------------------------------------------------------------
CREATE OR REPLACE FUNCTION consumption_per_day
( IN i_fluid fluid_t,
IN i_reading reading_d,
IN i_when_taken DATE
)
RETURNS quantity_d
AS $$
SELECT
( i_fluid,
(i_reading - mr.reading) / (i_when_taken - mr.when_taken),
fluid_unit(i_fluid)
)::quantity_d
FROM meter_reading AS mr
WHERE mr.when_taken < i_when_taken AND mr.fluid = i_fluid
ORDER BY mr.when_taken DESC LIMIT 1
$$
LANGUAGE SQL
STABLE
CALLED ON NULL INPUT
SECURITY DEFINER
;
--------------------------------------------------------------------------------
CREATE OR REPLACE FUNCTION sanity_limit (IN i_fluid fluid_t)
RETURNS reading_d
AS $$
SELECT CASE i_fluid
WHEN 'E' THEN 6.0
WHEN 'G' THEN 6.0
ELSE 0.2 -- 'W'
END::reading_d;
$$
LANGUAGE SQL
IMMUTABLE
CALLED ON NULL INPUT
SECURITY DEFINER
;
--------------------------------------------------------------------------------
CREATE OR REPLACE PROCEDURE ensure_sane
( IN i_fluid fluid_t,
IN i_reading reading_d,
IN i_when_taken DATE
)
AS $$
DECLARE
v_qpd quantity_d := consumption_per_day(i_fluid, i_reading, i_when_taken);
BEGIN
IF i_when_taken > CURRENT_DATE THEN
RAISE EXCEPTION 'date % is in the future', i_when_taken;
ELSIF i_when_taken < CURRENT_DATE - (5 * 356) THEN
RAISE EXCEPTION 'date % is very old', i_when_taken;
ELSIF v_qpd.size > sanity_limit(i_fluid) THEN
RAISE EXCEPTION 'whoa, too high: implies % % per day.',
v_qpd.size, v_qpd.unit;
END IF;
PERFORM 'x' FROM meter_reading
WHERE when_taken = i_when_taken
AND fluid = i_fluid AND when_given IS NOT NULL
FOR UPDATE OF meter_reading;
IF FOUND THEN
RAISE EXCEPTION
'refusing to change a reading you''ve given to the supplier.';
END IF;
RETURN;
END;
$$
LANGUAGE plpgsql
SECURITY DEFINER
;
--------------------------------------------------------------------------------
CREATE OR REPLACE FUNCTION take_reading
( IN i_fluid fluid_t,
IN i_reading reading_d,
IN i_when_taken DATE DEFAULT CURRENT_DATE
)
RETURNS meter_reading.id%TYPE
AS $$
DECLARE
v_id meter_reading.id%TYPE;
BEGIN
IF i_fluid IS NULL OR i_reading IS NULL THEN
RAISE EXCEPTION 'bad arguments, fluid or reading missing.';
END IF;
CALL ensure_monotonic(i_fluid, i_reading, i_when_taken);
CALL ensure_sane(i_fluid, i_reading, i_when_taken);
INSERT INTO meter_reading AS mr (when_taken, fluid, reading)
VALUES (i_when_taken, i_fluid, i_reading)
ON CONFLICT (when_taken, fluid) DO UPDATE
SET reading = i_reading, when_entered = CLOCK_TIMESTAMP()
WHERE mr.when_taken = i_when_taken AND mr.fluid = i_fluid
RETURNING mr.id INTO STRICT v_id;
RETURN v_id;
END;
$$
LANGUAGE plpgsql
VOLATILE
CALLED ON NULL INPUT
SECURITY DEFINER
;
--------------------------------------------------------------------------------
CREATE OR REPLACE FUNCTION give_reading
( IN i_fluid fluid_t,
IN i_when_taken DATE,
IN i_when_given DATE DEFAULT CURRENT_DATE
)
RETURNS meter_reading.id%TYPE
AS $$
DECLARE
v_id meter_reading.id%TYPE;
v_rowcount SMALLINT;
BEGIN
IF i_fluid IS NULL OR i_when_taken IS NULL THEN
RAISE EXCEPTION 'bad arguments, fluid or when_taken missing.';
ELSIF i_when_given > CURRENT_DATE THEN
RAISE EXCEPTION 'given date % is in the future', i_when_given;
ELSIF i_when_given < i_when_taken THEN
RAISE EXCEPTION 'given date % precedes taken date %',
i_when_given, i_when_taken;
END IF;
UPDATE meter_reading
SET when_given = i_when_given
WHERE when_taken = i_when_taken AND fluid = i_fluid
RETURNING id INTO v_id;
GET DIAGNOSTICS v_rowcount := ROW_COUNT;
IF v_rowcount != 1 THEN
RAISE EXCEPTION '% rows updated for % %',
v_rowcount, i_fluid, i_when_taken;
END IF;
RETURN v_id;
END;
$$
LANGUAGE plpgsql
VOLATILE
CALLED ON NULL INPUT
SECURITY DEFINER
;
--------------------------------------------------------------------------------
CREATE OR REPLACE VIEW mr_consumption AS
WITH r0 AS (
SELECT
id,
fluid,
when_taken,
reading,
( fluid,
(reading - FIRST_VALUE(reading) OVER pred)
/
(when_taken - FIRST_VALUE(when_taken) OVER pred),
fluid_unit(fluid)
)::quantity_d
AS
daily_consumption,
when_given,
when_entered
FROM
meter_reading
WINDOW
-- Look for the reading's predecessor (if any) so as to compute
-- consumption.
pred AS (
PARTITION BY fluid
ORDER BY when_taken
ROWS BETWEEN 1 PRECEDING AND CURRENT ROW EXCLUDE CURRENT ROW
)
)
SELECT
r0.id, r0.fluid, r0.when_taken, r0.reading,
(r0.daily_consumption).size AS dc_size,
(r0.daily_consumption).unit AS dc_unit,
r0.when_given, r0.when_entered
FROM
r0;
--------------------------------------------------------------------------------
GRANT EXECUTE ON ROUTINE
consumption_per_day, sanity_limit,
take_reading, give_reading
TO mr_user;
GRANT SELECT ON mr_consumption TO mr_user;
--------------------------------------------------------------------------------

26
table.sql Normal file
View File

@ -0,0 +1,26 @@
CREATE TYPE fluid_t AS ENUM ('E', 'G', 'W');
CREATE TYPE unit_t AS ENUM ('', 'KWh');
CREATE DOMAIN reading_d AS DECIMAL(8,3)
CONSTRAINT reading_nonnegative CHECK (VALUE >= 0.0);
CREATE TYPE quantity_t AS (fluid fluid_t, size reading_d, unit unit_t);
CREATE DOMAIN quantity_d AS quantity_t
CONSTRAINT quantity_unit
CHECK (((VALUE).fluid = 'E' AND (VALUE).unit = 'KWh')
OR ((VALUE).fluid != 'E' AND (VALUE).unit = ''));
CREATE TABLE meter_reading
( id INTEGER PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
when_taken DATE NOT NULL DEFAULT CURRENT_DATE,
when_entered TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(),
fluid fluid_t NOT NULL,
reading reading_d NOT NULL,
when_given DATE,
CONSTRAINT mr_uniq UNIQUE (when_taken, fluid),
CONSTRAINT mr_gt_order CHECK (when_given >= when_taken)
);
GRANT SELECT ON meter_reading, meter_reading_id_seq TO mr_user;

216
ui.pl Executable file
View File

@ -0,0 +1,216 @@
#!/usr/bin/perl
# Based on
# /usr/share/doc/libterm-readline-gnu-perl/examples/fileman.gz
use DBI;
use English qw(-no_match_vars);
use List::Util qw( reduce );
use Term::ExtendedColor qw(:all);
use Term::ReadLine;
use Time::Piece;
use Try::Tiny;
use common::sense;
# Seems to be necessary for utf8 to print correctly when running under tmux.
# Thanks to 'fuzzix' on #perl.
#
binmode STDOUT, ':encoding(UTF-8)';
#-------------------------------------------------------------------------------
# Globals.
my $dbh = DBI->connect(
"dbi:Pg:dbname=meter_reading", '', '',
{ AutoCommit => 1, RaiseError => 1, PrintError => 0 },
);
my $command_by_name = {
g => {
func => \&com_give,
doc => "Give: record when you gave a meter reading to the supplier.",
long => <<EOF
Usage: g {E|G|W} TAKEN_DATE [GIVEN_DATE]
You can omit GIVEN_DATE if it's 'today', or use CTRL-t to type today's date.
EOF
},
h => {
func => \&com_help,
doc => "Help. Type 'h x' for help on command x.",
},
q => {
func => \&com_quit,
doc => "Quit.",
},
r => {
func => \&com_report,
doc => "Report recent readings.",
long => <<EOF
Usage: r [E|G|W] [ROWS]
Report ROWS recent readings, for the given fluid or for all.
EOF
},
t => {
func => \&com_take,
doc => "Take: record a reading you took from a meter.",
long => <<EOF
Usage: t {E|G|W} READING [TAKEN_DATE]
You can omit TAKEN_DATE if it's 'today', or use CTRL-t to type today's date.
EOF
},
};
my $term = Term::ReadLine->new('Meter Reading');
# Use this ref as a sentinel value.
my $quit = [];
#-------------------------------------------------------------------------------
# Functions for the line reader.
sub stripwhite {
my $string = shift;
$string =~ s/^\s*//;
$string =~ s/\s*$//;
return $string;
}
sub print_err {
my ($str) = @_;
warn sprintf("%s\n", fg("red3", $str));
return;
}
sub execute_line {
my ($line) = @_;
my ($verb, @nouns) = split(' ', $line);
my $cmd = $command_by_name->{$verb};
if (! defined $cmd) {
print_err("'$verb': no such command.");
return;
} else {
return $cmd->{func}->(@nouns);
}
}
#-------------------------------------------------------------------------------
# Command functions and helpers.
# The $id parameter is for use by com_take() and com_give(). They use
# it to report on the row that's just been taken or given.
sub com_report {
my ($fluid, $rowcount, $id) = @_;
# Normalize to (fluid, rowcount).
if ((defined $rowcount) && $rowcount =~ m/(e|g|w)/i) {
($fluid, $rowcount) = ($rowcount, $fluid);
} elsif ((defined $fluid) && $fluid =~ m/[0-9]/) {
$rowcount = $fluid;
$fluid = undef;
}
$fluid = ($fluid ? (uc $fluid) : undef);
$rowcount = ($rowcount ? $rowcount : 5);
my $sql = <<EOF;
SELECT id, fluid, when_taken, reading, dc_size, dc_unit, when_given
FROM mr_consumption
WHERE id = COALESCE(?, id) AND fluid = COALESCE(?, fluid)
ORDER BY when_taken DESC, when_entered DESC
LIMIT ?
EOF
my $rows = $dbh->selectall_arrayref($sql, {}, $id, $fluid, $rowcount);
printf(
"%5s %s %10s %10s %9s %10s\n",
map { underline(fg('darkred1', bg('grey93', $_))); } (
" Id", "F", "Taken ", " Reading", " Per day", "Given ",
),
);
for (my $i = 0; $i < (scalar @$rows); $i++) {
my ($id, $f, $t, $r, $s, $u, $g) = @{$rows->[$i]};
my $rowstr = sprintf(
"%5d %s %s %10.3f %5.3f %-3s %10s",
$id, $f, $t, $r, $s, $u, $g // "",
);
printf("%s\n", $i % 2 ? $rowstr : bg("mistyrose1", $rowstr));
}
return;
}
sub com_give {
my ($fluid, $when_taken, $when_given) = @_;
$when_given = localtime->ymd if (! $when_given);
my $sql = <<EOF;
SELECT give_reading(i_fluid => ?, i_when_taken => ?, i_when_given => ?)
EOF
my ($id) = $dbh->selectrow_array(
$sql, {}, (uc $fluid), $when_taken, $when_given
);
printf("Reading %d updated as given on %s.\n", $id, $when_given);
com_report($fluid, 1, $id);
return;
}
sub com_take {
my ($fluid, $reading, $when_taken) = @_;
$when_taken = localtime->ymd if (! defined $when_taken);
my $sql = <<EOF;
SELECT take_reading(i_fluid => ?, i_reading => ?, i_when_taken => ?)
EOF
my ($id) = $dbh->selectrow_array($sql, {}, (uc $fluid), $reading, $when_taken);
printf("Reading saved in row %d.\n", $id);
com_report($fluid, 1, $id);
return;
}
sub com_quit {
my $sure = $term->readline(clear() . italic("Confirm quit? [Y/n]") . " ");
if ($sure =~ m/^y?$/i) {
printf("%s\n", italic("Bye."));
return $quit;
}
return;
}
sub com_help {
my ($cmd) = @_;
my $help_text = do {
if (my $cmdref = $command_by_name->{$cmd}) {
"$cmd: $cmdref->{doc}" . "\n" . $cmdref->{long};
} else {
reduce {
$a . "$b: " . $command_by_name->{$b}->{doc} . "\n";
} "", (sort keys %$command_by_name);
}
};
printf("%s", fg('blue15', $help_text));
return;
}
#-------------------------------------------------------------------------------
# Main.
$term->MinLine(0); # disable implict call of add_history()
$term->add_defun(
'foo', # dunno what this name is for.
sub { $term->insert_text(localtime->ymd); },
ord "\ct",
);
printf("%s\n", italic("For help, type 'h' and press return."));
RUNCMD: while (1) {
my $line = $term->readline(
fg('yellow1', bg('green28', "mr>")) . " ",
);
my $s = stripwhite($line);
next RUNCMD if (! length($s));
$term->AddHistory($s) if ($term->can('AddHistory'));
my $result = try {
execute_line($s);
} catch {
# Postgres errors take several lines so print only the first.
my @warning_lines = split(/\n/, $_);
print_err($warning_lines[0]);
};
last RUNCMD if ($quit == $result);
}
exit(0);