From b935dba1c7799bc401dcebb72a77295b2ba1610b Mon Sep 17 00:00:00 2001 From: Amitai Burstein Date: Fri, 17 Nov 2023 17:37:15 +0200 Subject: [PATCH 1/6] Docs on how to use ToField to query custom tuples --- Guide/database.markdown | 66 +++++++++++++++++++++++++++++++++++++++++ 1 file changed, 66 insertions(+) diff --git a/Guide/database.markdown b/Guide/database.markdown index ad11bdf02..55f91a94c 100644 --- a/Guide/database.markdown +++ b/Guide/database.markdown @@ -334,6 +334,72 @@ do |> map (\(Only uuid) -> Id uuid :: Id Project) ``` +### `IN` Clause Queries with Multiple Parameters + +At times, you may need to utilize the IN clause in SQL queries with multiple parameters. This approach differs from searching for records that match a single parameter, such as an ID. Instead, you might search for records that meet a combination of two parameters, like project_id and user_id. + +Consider a Project record, which includes a project type enum and the number of participants: + +``` +# Schema.sql +CREATE TYPE project_type AS ENUM ('project_type_ongoing', 'project_type_not_started', 'project_type_finished'); + +CREATE TABLE projects ( + id UUID DEFAULT uuid_generate_v4() PRIMARY KEY NOT NULL, + project_type project_type NOT NULL, + participants TEXT NOT NULL +); +``` + +In our Fixtures.sql, we can insert some sample data: + +```sql +ALTER TABLE public.projects DISABLE TRIGGER ALL; + +INSERT INTO public.projects (id, project_type, participants) VALUES ('e767f087-d1b9-42ea-898e-c2a2bf39999e', 'project_type_ongoing', '2'); +INSERT INTO public.projects (id, project_type, participants) VALUES ('429177d7-f425-4c5e-b379-5e1a0f72bfb5', 'project_type_ongoing', '2'); +INSERT INTO public.projects (id, project_type, participants) VALUES ('84825fa3-2cce-4b4a-872b-81fe554e2076', 'project_type_not_started', '3'); +INSERT INTO public.projects (id, project_type, participants) VALUES ('687e32f5-8e8b-4a6d-b4a7-ead9d8a39f91', 'project_type_finished', '2'); + + +ALTER TABLE public.projects ENABLE TRIGGER ALL; +``` + +Now, let's say we want to retrieve all projects that are of type project_type_ongoing and have 2 participants. The filterWhere function is not suitable here since we need to query by two parameters. + +First, we must implement ToField to allow using a tuple of `(ProjectType, Int)` as a parameter: + +```haskell +-- Web/Types.hs +import Database.PostgreSQL.Simple.ToField +import Data.ByteString.Builder (byteString, char8) + + +instance ToField (ProjectType, Int) where + toField = serializeProjectTypeAndInt + +serializeProjectTypeAndInt :: (ProjectType, Int) -> Action +serializeProjectTypeAndInt (projectType, participants) = Many + [ Plain (byteString "(") + , toField projectType + , Plain (char8 ',') + , toField $ show participants + , Plain (char8 ')') + ] +``` + +Then, in our controller, we can execute the query: + +```haskell +-- Web/Controller/Projects.hs +action ProjectsAction = do + -- let pairs = projects |> fmap (\project -> (project.projectType, project.participants)) + let pairs = [(ProjectTypeOngoing, 1 :: Int), (ProjectTypeFinished, 2)] + projects :: [Project] <- sqlQuery "SELECT * FROM projects WHERE (project_type, participants) IN ?" (Only $ In pairs) + + render IndexView { .. } +``` + ### Scalar Results The [`sqlQuery`](https://ihp.digitallyinduced.com/api-docs/IHP-ModelSupport.html#v:sqlQuery) function always returns a list of rows as the result. When the result of your query is a single value (such as an integer or string) use [`sqlQueryScalar`](https://ihp.digitallyinduced.com/api-docs/IHP-ModelSupport.html#v:sqlQueryScalar): From 68b5575cbd6c6aefc50142f6f6ffaf7c380c7ae8 Mon Sep 17 00:00:00 2001 From: Amitai Burstein Date: Fri, 17 Nov 2023 18:02:03 +0200 Subject: [PATCH 2/6] Improve example --- Guide/database.markdown | 2 +- flake.lock | 12 ++++++------ 2 files changed, 7 insertions(+), 7 deletions(-) diff --git a/Guide/database.markdown b/Guide/database.markdown index 55f91a94c..20404a068 100644 --- a/Guide/database.markdown +++ b/Guide/database.markdown @@ -365,7 +365,7 @@ INSERT INTO public.projects (id, project_type, participants) VALUES ('687e32f5-8 ALTER TABLE public.projects ENABLE TRIGGER ALL; ``` -Now, let's say we want to retrieve all projects that are of type project_type_ongoing and have 2 participants. The filterWhere function is not suitable here since we need to query by two parameters. +Now, let's say we want to retrieve all projects that are of type Ongoing and have 1 participant, and the Finished ones with 2 participants. The filterWhere function is not suitable here since we need to query by two parameters. First, we must implement ToField to allow using a tuple of `(ProjectType, Int)` as a parameter: diff --git a/flake.lock b/flake.lock index 70270fc75..5a1756a44 100644 --- a/flake.lock +++ b/flake.lock @@ -488,17 +488,17 @@ }, "nixpkgs_2": { "locked": { - "lastModified": 1696172942, - "narHash": "sha256-hKlB5InxJjDxLy5NJ4tQKEJ39Om81H87uoo0HHBG2UU=", - "owner": "mpscholten", + "lastModified": 1696291921, + "narHash": "sha256-isKgVAoUxuxYEuO3Q4xhbfKcZrF/+UkJtOTv0eb/W5E=", + "owner": "NixOS", "repo": "nixpkgs", - "rev": "3cdb4f45a50eb2a6a1a65f324e8243cedef4b19c", + "rev": "ea0284a3da391822909be5e98a60c1e62572a7dc", "type": "github" }, "original": { - "owner": "mpscholten", - "ref": "fix-ghc-m1-issue", + "owner": "NixOS", "repo": "nixpkgs", + "rev": "ea0284a3da391822909be5e98a60c1e62572a7dc", "type": "github" } }, From 335c43c5eb578f0d1749366b29d02e97da493a45 Mon Sep 17 00:00:00 2001 From: Amitai Burstein Date: Fri, 17 Nov 2023 18:06:09 +0200 Subject: [PATCH 3/6] Update Guide/database.markdown --- Guide/database.markdown | 1 - 1 file changed, 1 deletion(-) diff --git a/Guide/database.markdown b/Guide/database.markdown index 20404a068..13bc6e16b 100644 --- a/Guide/database.markdown +++ b/Guide/database.markdown @@ -393,7 +393,6 @@ Then, in our controller, we can execute the query: ```haskell -- Web/Controller/Projects.hs action ProjectsAction = do - -- let pairs = projects |> fmap (\project -> (project.projectType, project.participants)) let pairs = [(ProjectTypeOngoing, 1 :: Int), (ProjectTypeFinished, 2)] projects :: [Project] <- sqlQuery "SELECT * FROM projects WHERE (project_type, participants) IN ?" (Only $ In pairs) From 23c2b4084417e475ed91432a852533ad510144cd Mon Sep 17 00:00:00 2001 From: Amitai Burstein Date: Fri, 17 Nov 2023 18:09:24 +0200 Subject: [PATCH 4/6] Fix example --- Guide/database.markdown | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/Guide/database.markdown b/Guide/database.markdown index 13bc6e16b..eeb0ba4b5 100644 --- a/Guide/database.markdown +++ b/Guide/database.markdown @@ -336,7 +336,7 @@ do ### `IN` Clause Queries with Multiple Parameters -At times, you may need to utilize the IN clause in SQL queries with multiple parameters. This approach differs from searching for records that match a single parameter, such as an ID. Instead, you might search for records that meet a combination of two parameters, like project_id and user_id. +At times, you may need to utilize the IN clause in SQL queries with multiple parameters. This approach differs from searching for records that match a single parameter, such as an ID. Instead, you might search for records that meet a combination of two parameters, like `project_id` and `user_id`. Consider a Project record, which includes a project type enum and the number of participants: @@ -380,7 +380,7 @@ instance ToField (ProjectType, Int) where serializeProjectTypeAndInt :: (ProjectType, Int) -> Action serializeProjectTypeAndInt (projectType, participants) = Many - [ Plain (byteString "(") + [ Plain (char8 '(') , toField projectType , Plain (char8 ',') , toField $ show participants From 58207cdc3c2a49ea601d31c7b2c91b07abb051c9 Mon Sep 17 00:00:00 2001 From: Amitai Burstein Date: Fri, 17 Nov 2023 18:09:45 +0200 Subject: [PATCH 5/6] Remove impot --- Guide/database.markdown | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/Guide/database.markdown b/Guide/database.markdown index eeb0ba4b5..c6289037f 100644 --- a/Guide/database.markdown +++ b/Guide/database.markdown @@ -372,7 +372,7 @@ First, we must implement ToField to allow using a tuple of `(ProjectType, Int)` ```haskell -- Web/Types.hs import Database.PostgreSQL.Simple.ToField -import Data.ByteString.Builder (byteString, char8) +import Data.ByteString.Builder (char8) instance ToField (ProjectType, Int) where From f9a9b5ecc8601273f8f9637909635d5f43d26873 Mon Sep 17 00:00:00 2001 From: Amitai Burstein Date: Tue, 28 Nov 2023 11:43:39 +0200 Subject: [PATCH 6/6] Update doc --- Guide/database.markdown | 10 +++++++--- 1 file changed, 7 insertions(+), 3 deletions(-) diff --git a/Guide/database.markdown b/Guide/database.markdown index c6289037f..cb3c439a6 100644 --- a/Guide/database.markdown +++ b/Guide/database.markdown @@ -334,11 +334,15 @@ do |> map (\(Only uuid) -> Id uuid :: Id Project) ``` -### `IN` Clause Queries with Multiple Parameters +### Implementing `ToField` For Custom Types. -At times, you may need to utilize the IN clause in SQL queries with multiple parameters. This approach differs from searching for records that match a single parameter, such as an ID. Instead, you might search for records that meet a combination of two parameters, like `project_id` and `user_id`. +This is a more advanced topic, and before trying to implement it, we encourage you to +try and use the [Query Builder](https://ihp.digitallyinduced.com/Guide/querybuilder.html), as it provides a better type safety. Even the below example can be accomplished with the Query Builder. -Consider a Project record, which includes a project type enum and the number of participants: +When you want to use a custom type as a parameter for a SQL query, you need to implement the `ToField` class. This is needed for example when you want to use a tuple as a parameter for a SQL query. +For example, you may need to utilize the IN clause in SQL queries with multiple parameters. This approach differs from searching for records that match a single parameter, such as an ID. Instead, you might search for records that meet a combination of two parameters, like `project_id` and `user_id`. + +Consider a `Project` record, which includes a project type enum and the number of participants: ``` # Schema.sql