Browse Source

Add Haskell/PostgREST Implementation (#6162)

* Add Postgrest Test

* add stuff

* Initial PostgREST Implementation

* Initial PostgREST Implementation

* Add Haskell/postgrest

* Update README.md

* Update README.md

* remove setup files
Fred Leitz 4 years ago
parent
commit
6e0b3bbacf

+ 1 - 0
.travis.yml

@@ -47,6 +47,7 @@ env:
     - "TESTDIR=Haskell/spock"
     - "TESTDIR=Haskell/warp"
     - "TESTDIR=Haskell/wizzardo-inline"
+    - "TESTDIR=Haskell/postgrest"
     - 'TESTDIR="Java/act Java/comsat"'
     - 'TESTDIR="Java/activeweb Java/armeria Java/baratine Java/bayou Java/blade Java/curacao Java/dropwizard Java/firenio Java/servicetalk Java/voovan"'
     - 'TESTDIR="Java/gemini Java/greenlightning Java/grizzly Java/helidon Java/httpserver Java/jetty Java/jlhttp Java/jooby Java/wicket"'

+ 44 - 0
frameworks/Haskell/postgrest/README.md

@@ -0,0 +1,44 @@
+# PostgREST Benchmarking Test
+
+### Test Type Implementation Source Code
+
+* [JSON](src/json.sql)
+* [PLAINTEXT](src/plaintext.sql)
+* [DB](src/db.sql)
+* [QUERY](src/query.sql)
+* [CACHED QUERY] Not Implemented
+* [UPDATE] Not Implemented
+* [FORTUNES](src/fortunes.sql)
+
+## Important Libraries
+The tests were run with:
+* docker-compose down && docker-compose build && docker-compose up
+
+## Test URLs
+### JSON
+
+http://localhost:3000/rpc/json
+
+### PLAINTEXT
+
+http://localhost:3000/rpc/plaintext
+
+### DB
+
+http://localhost:3000/rpc/db
+
+### QUERY
+
+http://localhost:3000/rpc/query?queries=
+
+### CACHED QUERY Not Implemented
+
+http://localhost:8080/cached_query?queries=
+
+### UPDATE Not Implemented
+
+http://localhost:3000/rpc/update?queries=
+
+### FORTUNES
+
+http://localhost:3000/rpc/fortunes.html

+ 29 - 0
frameworks/Haskell/postgrest/benchmark_config.json

@@ -0,0 +1,29 @@
+{
+  "framework": "postgrest",
+  "tests": [
+    {
+      "default": {
+        "json_url": "/rpc/json",
+        "plaintext_url": "/rpc/plaintext",
+        "db_url": "/rpc/db",
+        "query_url": "/rpc/queries?queries=",
+        "fortunes_url": "/rpc/fortunes.html",
+        "port": 3000,
+        "approach": "Realistic",
+        "classification": "Micro",
+        "database": "postgres",
+        "framework": "PostgREST",
+        "language": "Haskell",
+        "flavor": "None",
+        "orm": "Full",
+        "platform": "None",
+        "webserver": "None",
+        "os": "Linux",
+        "database_os": "Linux",
+        "display_name": "PostgREST",
+        "notes": "",
+        "versus": "None"
+      }
+    }
+  ]
+}

+ 16 - 0
frameworks/Haskell/postgrest/docker-compose.yml

@@ -0,0 +1,16 @@
+version: '3'
+services:
+  tfb-database:
+    build: 
+      dockerfile: postgresql.dockerfile
+      context: .
+    environment: 
+      - POSTGRES_PASSWORD=benchmarkdbpass
+      - POSTGRES_USER=benchmarkdbuser
+      - POSTGRES_DB=hello_world
+  web:
+    build: 
+      dockerfile: postgrest.dockerfile
+      context: .
+    ports:
+      - 3030:3000

+ 4 - 0
frameworks/Haskell/postgrest/postgresql.dockerfile

@@ -0,0 +1,4 @@
+FROM postgres:latest
+
+RUN mkdir -p /docker-entrypoint-initdb.d
+COPY src/*.sql /docker-entrypoint-initdb.d/

+ 37 - 0
frameworks/Haskell/postgrest/postgrest.dockerfile

@@ -0,0 +1,37 @@
+FROM postgrest/postgrest:latest
+
+FROM alpine
+RUN apk add postgresql-client bash
+
+COPY --from=0 /usr/local/bin/postgrest /usr/local/bin/postgrest
+COPY --from=0 /etc/postgrest.conf /etc/postgrest.conf
+
+ENV PGRST_DB_SCHEMA=public
+ENV PGRST_DB_ANON_ROLE=
+ENV PGRST_DB_POOL=100
+ENV PGRST_DB_POOL_TIMEOUT=10
+ENV PGRST_DB_EXTRA_SEARCH_PATH=public
+ENV PGRST_DB_CHANNEL=pgrst
+ENV PGRST_DB_CHANNEL_ENABLED=false
+ENV PGRST_SERVER_HOST=*4
+ENV PGRST_SERVER_PORT=3000
+ENV PGRST_OPENAPI_SERVER_PROXY_URI=
+ENV PGRST_JWT_SECRET=
+ENV PGRST_SECRET_IS_BASE64=false
+ENV PGRST_JWT_AUD=
+ENV PGRST_MAX_ROWS=
+ENV PGRST_PRE_REQUEST=
+ENV PGRST_ROLE_CLAIM_KEY=.role
+ENV PGRST_ROOT_SPEC=
+ENV PGRST_RAW_MEDIA_TYPES=
+
+ENV PGRST_DB_URI=postgres://benchmarkdbuser:benchmarkdbpass@tfb-database/hello_world
+ENV PGRST_DB_SCHEMA=public
+ENV PGRST_DB_ANON_ROLE=benchmarkdbuser
+ENV PGRST_RAW_MEDIA_TYPES="text/html, text/plain"
+ENV PGRST_DB_POOL=64
+RUN mkdir /app
+COPY src /app
+RUN chmod +x /app/entrypoint.sh 
+WORKDIR /app
+ENTRYPOINT [ "/app/entrypoint.sh" ]

+ 4 - 0
frameworks/Haskell/postgrest/src/db.sql

@@ -0,0 +1,4 @@
+
+create or replace function db() returns json as $$
+   SELECT json_build_object('id', id, 'randomNumber', randomNumber) from (SELECT ((random()*9999)::int+1) as rnd) g JOIN "World" ON id = rnd; 
+$$ language sql volatile;

+ 6 - 0
frameworks/Haskell/postgrest/src/entrypoint.sh

@@ -0,0 +1,6 @@
+#!/bin/bash
+touch /root/.pgpass
+chmod 600 /root/.pgpass
+echo tfb-database:5432:hello_world:benchmarkdbuser:benchmarkdbpass >> /root/.pgpass 
+cat *.sql | psql -U benchmarkdbuser -h tfb-database -d hello_world
+/usr/local/bin/postgrest /etc/postgrest.conf > /dev/null 2>&1

+ 35 - 0
frameworks/Haskell/postgrest/src/fortunes.sql

@@ -0,0 +1,35 @@
+CREATE TYPE fortune_t AS (id int, message text);
+
+create or replace function fortune_template(f fortune_t) returns text as $$
+   SELECT format('<tr><td>%s</td><td>%s</td></tr>', $1.id, regexp_replace($1.message, '<', '&lt;','g')); 
+$$ language sql volatile;
+
+create or replace function fortunes_template(fortunes fortune_t[]) returns text as $$
+WITH header AS (
+   SELECT 0 as id,'<!DOCTYPE html>
+<html><head><title>Fortunes</title></head><body><table><tr><th>id</th><th>message</th></tr>' as html
+), footer AS (
+   SELECT 2,'</table></body></html>' as html
+), fortunes AS (
+   SELECT unnest as fortune from unnest($1) 
+), additional AS (
+   SELECT (-1, 'Additional fortune added at request time.')::fortune_t as f
+), all_fortunes AS (
+   SELECT * from (SELECT * FROM fortunes UNION ALL SELECT * from additional) p ORDER BY (fortune).message
+), fortunes_html AS (
+   SELECT 1,string_agg(fortune_template(fortune), '') from all_fortunes
+), html AS (
+   SELECT * FROM header UNION SELECT * FROM fortunes_html UNION SELECT * from footer ORDER BY id
+)
+SELECT string_agg(html,'') from html;
+$$ language sql volatile;
+
+create or replace function "fortunes.html"() returns bytea as $$
+DECLARE
+   fortunes fortune_t[];
+BEGIN
+   SET LOCAL "response.headers" = '[{"Content-Type": "text/html"}]';
+   SELECT array_agg(CAST((id,message) AS fortune_t)) FROM "Fortunes" INTO fortunes;
+   RETURN convert_to(fortunes_template(fortunes), 'UTF8');
+END
+$$ language plpgsql volatile;

+ 3 - 0
frameworks/Haskell/postgrest/src/json.sql

@@ -0,0 +1,3 @@
+create function json() returns json as $$
+   SELECT json_build_object('message', 'Hello, World!');
+$$ language sql volatile;

+ 3 - 0
frameworks/Haskell/postgrest/src/plaintext.sql

@@ -0,0 +1,3 @@
+create function plaintext() returns text as $$
+   SELECT 'Hello, World!';
+$$ language sql volatile;

+ 25 - 0
frameworks/Haskell/postgrest/src/query.sql

@@ -0,0 +1,25 @@
+create or replace function queries(queries text default '') returns jsonb as $$
+DECLARE
+   r "World"%ROWTYPE;
+   j jsonb := jsonb_build_array();
+   count int;
+BEGIN
+   IF queries ~ '^[1-9]\d{0,2}$' THEN
+      count := CAST(queries as int);
+   ELSE 
+      count := 1;   
+   END IF;
+   IF count > 500 THEN
+      count := 500;
+   END IF;
+   LOOP
+      IF count <= 0 THEN
+         EXIT;  -- exit loop
+      END IF;
+      SELECT id, randomNumber into r from (SELECT ((random()*9999)::int+1) as rnd) g JOIN "World" ON id = rnd; 
+      j := jsonb_insert(j, '{0}', to_jsonb(r), true);
+      count := count - 1;
+   END LOOP;
+   RETURN j;
+END
+$$ language plpgsql volatile;

+ 31 - 0
frameworks/Haskell/postgrest/src/update.sql

@@ -0,0 +1,31 @@
+create or replace function update(queries text default '') returns jsonb as $$
+DECLARE
+   r "World"%ROWTYPE;
+   j jsonb := jsonb_build_array();
+   new_rnd int;
+   rnd_id int;
+   count int;
+BEGIN
+   SET TRANSACTION READ WRITE;
+   IF queries ~ '^[1-9]\d{0,2}$' THEN
+      count := CAST(queries as int);
+   ELSE 
+      count := 1;   
+   END IF;
+   IF count > 500 THEN
+      count := 500;
+   END IF;
+   LOOP
+      IF count <= 0 THEN
+         EXIT;  -- exit loop
+      END IF;
+      rnd_id := ((random()*9999)::int+1);
+      new_rnd := ((random()*9999)::int+1);
+      UPDATE "World" SET randomNumber = new_rnd WHERE id = rnd_id;
+      SELECT * INTO r FROM "World" where id = rnd_id;
+      j := jsonb_insert(j, '{0}', to_jsonb(r), true);
+      count := count - 1;
+   END LOOP;
+   RETURN j;
+END
+$$ language plpgsql volatile;