Re: [SQL] md5 checksum of a previous row
От | MS (direkt) |
---|---|
Тема | Re: [SQL] md5 checksum of a previous row |
Дата | |
Msg-id | 95a944da-e4f2-2500-b917-6aa825a28f03@stb-datenservice.de обсуждение исходный текст |
Ответ на | [SQL] md5 checksum of a previous row (Iaam Onkara <iamonkara@gmail.com>) |
Ответы |
Re: [SQL] md5 checksum of a previous row
|
Список | pgsql-sql |
Hi,
you can easily join the preceeding row, e.g.
select sub.id, sub.created_at, preceedingid, m2.* from (
select m.id, m.created_at, lag(m.id) over(order by m.created_at) as preceedingid from test m
order by m.created_at) as sub
left join test m2 on m2.id=sub.preceedingid order by sub.created_at;
Regards, Martin
you can easily join the preceeding row, e.g.
select sub.id, sub.created_at, preceedingid, m2.* from (
select m.id, m.created_at, lag(m.id) over(order by m.created_at) as preceedingid from test m
order by m.created_at) as sub
left join test m2 on m2.id=sub.preceedingid order by sub.created_at;
Regards, Martin
Am 13.11.2017 um 07:15 schrieb Iaam Onkara:
before_insert:Hi,I have a requirement to create an tamper proof chain of records for audit purposes. The pseudo code is as follows1. compute checksum of previous row (or conditionally selected row)2. insert the computed checksum in the current row3. using on-update or on-delete trigger raise error to prevent update/delete of any row.OnkaraHere are the different options that I have tried using lag and md5 functions
http://www.sqlfiddle.com/#!17/69843/2
CREATE TABLE test
("id" uuid DEFAULT uuid_generate_v4() NOT NULL,
"value" decimal(5,2) NOT NULL,
"delta" decimal(5,2),
"created_at" timestamp default current_timestamp,
"words" text,
CONSTRAINT pid PRIMARY KEY (id)
)
;
INSERT INTO test
(value, words)
VALUES
(51.0, 'A'),
(52.0, 'B'),
(54.0, 'C'),
(57.0, 'D')
;
select
created_at, value,
value - lag(value, 1, 0.0) over(order by created_at) as delta,
md5(lag(words,1,words) over(order by created_at)) as the_word,
md5(textin(record_out(test))) as Hash
FROM test
ORDER BY created_at;But how do I use lag function or something like lag to read the previous record as whole.Thanks,PS: This was earlier posted in 'pgsql-in-general' mailing list, but I think this is a more appropriate list, if I am wrong I am sorry
-- Widdersdorfer Str. 415, 50933 Köln; Tel. +49 / 221 / 9544 010 HRB Köln HRB 75439, Geschäftsführer: S. Böhland, S. Rosenbauer
В списке pgsql-sql по дате отправления: