Daniel Sheffield il y a 19 heures
commit
bc21d356d7

+ 3 - 0
.gitmodules

@@ -0,0 +1,3 @@
+[submodule "SQLPage"]
+	path = SQLPage
+	url = https://github.com/sqlpage/SQLPage.git

+ 1 - 0
SQLPage

@@ -0,0 +1 @@
+Subproject commit f92cbf5ba320aa3625cfa18884328c8d47e9b833

+ 6 - 0
build.sh

@@ -0,0 +1,6 @@
+#!/bin/bash
+git submodule update --init --recursive --remote
+{
+    cd SQLPage
+    cargo build --release
+}

+ 78 - 0
config/migrations/001_initial.sql

@@ -0,0 +1,78 @@
+CREATE TABLE public.project (
+    id bigint NOT NULL,
+    project text NOT NULL,
+    ggl_id bigint,
+    description text
+);
+ALTER TABLE public.project OWNER TO postgres;
+ALTER TABLE ONLY public.project
+    ADD CONSTRAINT description_uniq UNIQUE (description);
+ALTER TABLE ONLY public.project
+    ADD CONSTRAINT ggl_id_uniq UNIQUE (ggl_id);
+ALTER TABLE ONLY public.project
+    ADD CONSTRAINT project_pkey PRIMARY KEY (id);
+ALTER TABLE ONLY public.project
+    ADD CONSTRAINT project_uniq UNIQUE (project);
+
+CREATE TABLE public.items (
+    id bigint PRIMARY KEY,
+    project_id bigint NOT NULL,
+    description text,
+    start timestamp(0) without time zone,
+    "end" timestamp(0) without time zone,
+    duration interval,
+    CONSTRAINT start_end_duration_ck CHECK ((((start IS NOT NULL) AND ("end" IS NOT NULL) AND ((duration IS NULL) OR (duration = ("end" - start)))) OR ((duration IS NOT NULL) AND ((start IS NOT NULL) OR ("end" IS NOT NULL)) AND ((start IS NULL) OR ("end" IS NULL)))))
+);
+ALTER TABLE public.items OWNER TO postgres;
+ALTER TABLE ONLY public.items
+    ADD CONSTRAINT project_id_fk FOREIGN KEY (project_id) REFERENCES public.project(id);
+
+CREATE VIEW public.timesheet AS
+ SELECT min(((COALESCE("end", (start + duration)) AT TIME ZONE 'UTC'::text))::date) AS date,
+    project_id,
+    sum(COALESCE(duration, ("end" - start))) AS total,
+    round((EXTRACT(epoch FROM sum(COALESCE(duration, ("end" - start)))) / (3600)::numeric), 2) AS total_hours
+   FROM public.items
+  GROUP BY ROLLUP((((COALESCE("end", (start + duration)) AT TIME ZONE 'UTC'::text))::date), project_id)
+  ORDER BY (min(((COALESCE("end", (start + duration)) AT TIME ZONE 'UTC'::text))::date)) DESC, project_id;
+ALTER VIEW public.timesheet OWNER TO postgres;
+
+CREATE VIEW public.today AS
+ SELECT id,
+    project_id,
+    description,
+    COALESCE(duration, ("end" - start)) AS duration,
+    (COALESCE("end", (start + duration)) AT TIME ZONE 'UTC'::text) AS "end"
+   FROM public.items
+  WHERE (((COALESCE("end", (start + duration)) AT TIME ZONE 'UTC'::text))::date = CURRENT_DATE);
+ALTER VIEW public.today OWNER TO postgres;
+
+CREATE PROCEDURE public.add_item(IN p_project_id numeric, IN p_description text, IN p_start time with time zone, IN p_end time with time zone, IN p_duration interval)
+    LANGUAGE sql
+    AS $$
+INSERT INTO items(id, project_id, description, start, "end", duration)
+VALUES
+(COALESCE((SELECT max(id) FROM items) + 2, 1), p_project_id, p_description, CASE p_start IS NOT NULL
+	WHEN TRUE THEN ((current_date || ' ' || p_start)::timestamp with time zone) AT TIME ZONE 'UTC'
+	ELSE NULL END, CASE p_end IS NOT NULL
+	WHEN TRUE THEN ((current_date || ' ' || p_end)::timestamp with time zone) AT TIME ZONE 'UTC'
+	ELSE ((SELECT COALESCE("end", start + duration) FROM items ORDER BY id DESC LIMIT 1) AT TIME ZONE 'UTC' + p_duration) AT TIME ZONE 'UTC' END, CASE p_duration IS NULL
+	WHEN TRUE AND p_start IS NULL THEN ((current_date || ' ' || p_end)::timestamp with time zone) AT TIME ZONE 'UTC' - (SELECT COALESCE("end", start + duration) FROM items ORDER BY id DESC LIMIT 1)
+	ELSE p_duration END)
+$$;
+ALTER PROCEDURE public.add_item(IN p_project_id numeric, IN p_description text, IN p_start time with time zone, IN p_end time with time zone, IN p_duration interval) OWNER TO postgres;
+
+CREATE FUNCTION public.timesheet_day(p_ago interval DEFAULT '00:00:00'::interval) RETURNS SETOF public.timesheet
+    LANGUAGE sql
+    AS $$
+ SELECT
+    min((COALESCE("end", start + duration) AT TIME ZONE 'UTC'::text)::date) AS date,
+    project_id,
+       sum(COALESCE(duration, "end" - start)) AS total,
+       round(EXTRACT(epoch FROM sum(COALESCE(duration, "end" - start))) / 3600::numeric, 2) AS total_hours
+   FROM items
+  WHERE (COALESCE("end", start + duration) AT TIME ZONE 'UTC'::text)::date = CURRENT_DATE - p_ago
+GROUP BY ROLLUP (project_id)
+ORDER BY project_id
+$$;
+ALTER FUNCTION public.timesheet_day(p_ago interval) OWNER TO postgres;

+ 14 - 0
config/migrations/003_tody_view.sql

@@ -0,0 +1,14 @@
+DROP VIEW public.today;
+CREATE VIEW public.today
+ AS
+ SELECT id,
+    project_id,
+    description,
+    COALESCE(duration, "end" - start) AS duration,
+	(COALESCE(start, "end" - duration) AT TIME ZONE 'UTC'::text) AS "start",
+    (COALESCE("end", start + duration) AT TIME ZONE 'UTC'::text) AS "end"
+   FROM items
+  WHERE (COALESCE("end", start + duration) AT TIME ZONE 'UTC'::text)::date = CURRENT_DATE;
+
+ALTER TABLE public.today
+    OWNER TO postgres;

+ 12 - 0
config/migrations/004_timesheet_view.sql

@@ -0,0 +1,12 @@
+CREATE OR REPLACE VIEW public.timesheet
+ AS
+ SELECT (COALESCE("end", start + duration) AT TIME ZONE 'UTC'::text)::date AS date,
+    project_id,
+    sum(COALESCE(duration, "end" - start)) AS total,
+    round(EXTRACT(epoch FROM sum(COALESCE(duration, "end" - start))) / 3600::numeric, 2) AS total_hours
+   FROM items
+  GROUP BY ROLLUP((COALESCE("end", start + duration) AT TIME ZONE 'UTC'::text)::date, project_id)
+  ORDER BY (COALESCE("end", start + duration) AT TIME ZONE 'UTC'::text)::date DESC NULLS LAST, project_id;
+
+ALTER TABLE public.timesheet
+    OWNER TO postgres;

+ 41 - 0
config/migrations/README.md

@@ -0,0 +1,41 @@
+# SQLPage migrations
+
+SQLPage migrations are SQL scripts that you can use to create or update the database schema.
+They are entirely optional: you can use SQLPage without them, and manage the database schema yourself with other tools.
+
+If you are new to SQL migrations, please read our [**introduction to database migrations**](https://sql-page.com/your-first-sql-website/migrations.sql).
+
+## Creating a migration
+
+To create a migration, create a file in the `sqlpage/migrations` directory with the following name:
+
+```
+<version>_<name>.sql
+```
+
+Where `<version>` is a number that represents the version of the migration, and `<name>` is a name for the migration.
+For example, `001_initial.sql` or `002_add_users.sql`.
+
+When you need to update the database schema, always create a **new** migration file with a new version number
+that is greater than the previous one.
+Use commands like `ALTER TABLE` to update the schema declaratively instead of modifying the existing `CREATE TABLE`
+statements.
+
+If you try to edit an existing migration, SQLPage will not run it again, will detect
+
+## Running migrations
+
+Migrations that need to be applied are run automatically when SQLPage starts.
+You need to restart SQLPage each time you create a new migration.
+
+## How does it work?
+
+SQLPage keeps track of the migrations that have been applied in a table called `_sqlx_migrations`.
+This table is created automatically when SQLPage starts for the first time, if you create migration files.
+If you don't create any migration files, SQLPage will never touch the database schema on its own.
+
+When SQLPage starts, it checks the `_sqlx_migrations` table to see which migrations have been applied.
+It checks the `sqlpage/migrations` directory to see which migrations are available.
+If the checksum of a migration file is different from the checksum of the migration that has been applied,
+SQLPage will return an error and refuse to start.
+If you end up in this situation, you can remove the `_sqlx_migrations` table: all your old migrations will be reapplied, and SQLPage will start again.

+ 2 - 0
config/sqlpage.yml

@@ -0,0 +1,2 @@
+database_url: "sqlite://./timesheet.db" #"postgres://postgres:postgres@localhost:5432/timesheet"
+port: 6974 

+ 20 - 0
config/templates/README.md

@@ -0,0 +1,20 @@
+# SQLPage component templates
+
+SQLPage templates are handlebars[^1] files that are used to render the results of SQL queries.
+
+[^1]: https://handlebarsjs.com/
+
+## Default components
+
+SQLPage comes with a set of default[^2] components that you can use without having to write any code.
+These are documented on https://sql-page.com/components.sql
+
+## Custom components
+
+You can [write your own component templates](https://sql-page.com/custom_components.sql)
+and place them in the `sqlpage/templates` directory.
+To override a default component, create a file with the same name as the default component.
+If you want to start from an existing component, you can copy it from the `sqlpage/templates` directory
+in the SQLPage source code[^2].
+
+[^2]: A simple component to start from: https://github.com/sqlpage/SQLPage/blob/main/sqlpage/templates/code.handlebars

+ 2 - 0
run.sh

@@ -0,0 +1,2 @@
+#!/bin/bash
+SLQPage/target/release/sqlpage

+ 54 - 0
site/add_item.sql

@@ -0,0 +1,54 @@
+SET TIME ZONE 'Pacific/Auckland';
+SET ":title" = 'Timesheet Form';
+SELECT 'shell' AS component
+, 'dark' AS theme
+, '/clock-2.svg' AS favicon
+, 'clock-2' AS icon
+, :title AS title
+;
+SELECT 'title' AS component
+, 'Add Item' AS contents
+;
+SELECT 'form' AS component
+, '/add_item_post.sql' AS action
+, 'post' AS method
+;
+
+SELECT 'Project ID' AS label
+, 'project_id' AS name
+, 'number' AS type
+, 'input-project-id' AS id
+, 1 AS width
+;
+SELECT 'Description' AS label
+, 'description' AS name
+, 'text' AS type
+, 'input-description' AS id
+, 5 AS width
+;
+SELECT 'Start' AS label
+, 'start_time' AS name
+, 'time' AS type
+, 'input-start-time' AS id
+, 2 AS width
+;
+SELECT 'End' AS label
+, 'end_time' AS name
+, 'time' AS type
+, 'input-end-time' AS id
+, 2 AS width
+;
+SELECT 'Duration' AS label
+, 'duration' AS name
+, 'time' AS type
+, 'input-duration' AS id
+, 2 AS width
+;
+
+SELECT 'card' as component
+, '' AS title
+, 1 AS columns
+;
+SELECT '/items_today.sql?level=2&_sqlpage_embed' AS embed;
+SELECT '/timesheet_day.sql?level=2&_sqlpage_embed' AS embed;
+SELECT '/timesheet_history.sql?level=2&_sqlpage_embed' AS embed;

+ 18 - 0
site/add_item_post.sql

@@ -0,0 +1,18 @@
+SET TIME ZONE 'Pacific/Auckland';
+--SET ":project_id" = CAST(COALESCE(:project_id, NULL) AS INT);
+--SET ":start_time" = CAST(COALESCE(:start_time, NULL) AS TIMESTAMP WITHOUT TIME ZONE);
+--SET :end_time = CAST(COALESCE(:end_time, NULL) AS TIMESTAMP WITHOUT TIME ZONE);
+SET ":project_id" = CASE :project_id WHEN '' THEN NULL ELSE :project_id END;
+SET ":description" = CASE :description WHEN '' THEN NULL ELSE :description END;
+SET ":start_time" = CASE :start_time WHEN '' THEN NULL ELSE :start_time END;
+SET ":end_time" = CASE :end_time WHEN '' THEN NULL ELSE :end_time END;
+SET ":duration" = CASE :duration WHEN '' THEN NULL ELSE :duration END;
+
+CALL public.add_item(
+    CAST(:project_id AS NUMERIC),
+    CAST(:description AS TEXT),
+    CAST(:start_time AS TIME WITH TIME ZONE),
+    COALESCE(CAST(:end_time AS TIME WITH TIME ZONE), current_time(0)),
+    CAST(:duration AS INTERVAL)
+);
+SELECT 'redirect' AS component, 'add_item.sql' AS link;

+ 1 - 0
site/clock-2.svg

@@ -0,0 +1 @@
+<svg  xmlns="http://www.w3.org/2000/svg"  width="24"  height="24"  viewBox="0 0 24 24"  fill="none"  stroke="currentColor"  stroke-width="2"  stroke-linecap="round"  stroke-linejoin="round"  class="icon icon-tabler icons-tabler-outline icon-tabler-clock-2"><path stroke="none" d="M0 0h24v24H0z" fill="none"/><path d="M4 4m0 1a1 1 0 0 1 1 -1h14a1 1 0 0 1 1 1v14a1 1 0 0 1 -1 1h-14a1 1 0 0 1 -1 -1z" /><path d="M12 7v5l3 3" /><path d="M4 12h1" /><path d="M19 12h1" /><path d="M12 19v1" /></svg>

+ 27 - 0
site/items_today.sql

@@ -0,0 +1,27 @@
+SET TIME ZONE 'Pacific/Auckland';
+SET ":title" = 'Timesheet Items';
+SELECT 'shell' AS component
+  , 'dark' AS theme
+  , '/clock-2.svg' AS favicon
+  , 'clock-2' AS icon
+  , :title AS title
+;
+
+SET ":level" = CASE $level WHEN '' THEN 1 ELSE CAST($level AS INT) END;
+SELECT 'title' AS component
+  , :title AS contents
+  , COALESCE(CAST(:level AS INT), 1) AS level
+;
+SET ":ago" = CASE $ago WHEN '' THEN NULL ELSE $ago END;
+SELECT 'table' AS component
+  , TRUE AS striped_rows
+;
+SELECT id
+, project_id
+, description
+, duration
+, CAST(start AS TIME)
+, CAST("end" AS TIME)
+FROM today
+ORDER BY id DESC
+;

+ 36 - 0
site/timesheet_day.sql

@@ -0,0 +1,36 @@
+SET TIME ZONE 'Pacific/Auckland';
+SET ":ago_msg" = CASE COALESCE($ago, '') WHEN '' THEN '' ELSE ' (' || $ago || ' ago)' END;
+SET ":ago" = CASE $ago WHEN '' THEN NULL ELSE $ago END;
+SET ":title" = 'Timesheet' || :ago_msg;
+SELECT 'shell' AS component
+  , 'dark' AS theme
+  , '/clock-2.svg' AS favicon
+  , 'clock-2' AS icon
+  , :title AS title
+;
+
+SET ":level" = CASE $level WHEN '' THEN 1 ELSE CAST($level AS INT) END;
+SELECT 'title' AS component
+  , :title AS contents
+  , COALESCE(CAST(:level AS INT), 1) AS level
+;
+SELECT 'table' AS component
+  , TRUE AS striped_rows
+;
+SELECT date
+, project_id
+, CAST(total AS TEXT) AS total
+, total_hours
+FROM timesheet_day(CAST(COALESCE(:ago, '0 days') AS INTERVAL));
+
+SELECT 'table' AS component;
+SELECT id
+,   project_id
+,   description
+,   COALESCE(duration, "end" - start)::text AS duration
+,   (COALESCE(start, "end" - duration) AT TIME ZONE 'UTC'::text) AS start
+,   (COALESCE("end", start + duration) AT TIME ZONE 'UTC'::text) AS "end"
+FROM items
+WHERE (COALESCE("end", start + duration) AT TIME ZONE 'UTC'::text)::date = (CURRENT_DATE - CAST(:ago AS INTERVAL))::date
+ORDER BY id DESC
+;

+ 26 - 0
site/timesheet_history.sql

@@ -0,0 +1,26 @@
+SET TIME ZONE 'Pacific/Auckland';
+SET ":title" = 'Timesheet History';
+SELECT 'shell' AS component
+, 'dark' AS theme
+, '/clock-2.svg' AS favicon
+, 'clock-2' AS icon
+, :title AS title
+;
+
+SET ":level" = CASE $level WHEN '' THEN 1 ELSE CAST($level AS INT) END;
+SELECT 'title' AS component
+, :title AS contents
+, COALESCE(CAST(:level AS INT), 1) AS level
+;
+SELECT 'table' AS component
+, TRUE AS striped_rows
+, 'History' AS title
+;
+SELECT date
+, total
+, total_hours
+FROM timesheet
+WHERE project_id IS NULL
+AND date IS NOT NULL
+ORDER BY date DESC
+;