Skip to content

Commit

Permalink
Fix
Browse files Browse the repository at this point in the history
  • Loading branch information
istarkov committed Sep 17, 2024
1 parent 478fbc6 commit aa71815
Show file tree
Hide file tree
Showing 4 changed files with 371 additions and 1 deletion.
4 changes: 3 additions & 1 deletion .gitignore
Original file line number Diff line number Diff line change
Expand Up @@ -60,4 +60,6 @@ tsconfig.tsbuildinfo
dist

# should be here otherwise if placed inside prisma-client pnpm deploy doesn't copy it
packages/prisma-client/src/__generated__
packages/prisma-client/src/__generated__

.temp
16 changes: 16 additions & 0 deletions packages/postgrest/README.md
Original file line number Diff line number Diff line change
Expand Up @@ -31,3 +31,19 @@ pnpm tsx --env-file ../../apps/builder/.env ./playground/{file}.ts
Use https://supabase.com/docs/reference/cli/supabase-db-start or directly https://github.com/djrobstep/migra for migrations.

Supabase can be used with `--db-url` flag to not reproduce "local" env

## Sql testing

```sql
CREATE SCHEMA IF NOT EXISTS pgtap;
DROP EXTENSION pgtap;
CREATE EXTENSION IF NOT EXISTS pgtap WITH SCHEMA pgtap;
```

```bash
pnpx supabase test new latest-builds
```

```shell
docker run --rm --network host -v ./supabase/tests:/tests -e PGOPTIONS='--search_path=pgtap,public' supabase/pg_prove:3.36 pg_prove -d "postgresql://postgres:pass@localhost/webstudio" --ext .sql /tests
```
161 changes: 161 additions & 0 deletions packages/postgrest/supabase/SQL-TESTS-AI.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,161 @@
# Sql Testing AI Helpers

Extract schema

```bash
pnpx supabase db dump -s public --db-url postgresql://postgres:pass@localhost/webstudio > schema.sql
```

Promt Examples

---

Below is a partial dump of the SQL schema:

```sql

CREATE TABLE IF NOT EXISTS "public"."User" (
"id" "text" NOT NULL,
"createdAt" timestamp(3) with time zone DEFAULT CURRENT_TIMESTAMP NOT NULL,
"email" "text",
"image" "text",
"provider" "text",
"username" "text",
"teamId" "text"
);


CREATE TABLE IF NOT EXISTS "public"."Domain" (
"id" "text" NOT NULL,
"domain" "text" NOT NULL,
"createdAt" timestamp(3) with time zone DEFAULT CURRENT_TIMESTAMP NOT NULL,
"txtRecord" "text",
"status" "public"."DomainStatus" DEFAULT 'INITIALIZING'::"public"."DomainStatus" NOT NULL,
"error" "text",
"updatedAt" timestamp(3) with time zone DEFAULT CURRENT_TIMESTAMP NOT NULL
);

CREATE TABLE IF NOT EXISTS "public"."Build" (
"id" "text" NOT NULL,
"createdAt" timestamp(3) with time zone DEFAULT CURRENT_TIMESTAMP NOT NULL,
"pages" "text" NOT NULL,
"projectId" "text" NOT NULL,
"styleSources" "text" DEFAULT '[]'::"text" NOT NULL,
"styles" "text" DEFAULT '[]'::"text" NOT NULL,
"breakpoints" "text" DEFAULT '[]'::"text" NOT NULL,
"styleSourceSelections" "text" DEFAULT '[]'::"text" NOT NULL,
"props" "text" DEFAULT '[]'::"text" NOT NULL,
"instances" "text" DEFAULT '[]'::"text" NOT NULL,
"updatedAt" timestamp(3) with time zone DEFAULT CURRENT_TIMESTAMP NOT NULL,
"version" integer DEFAULT 0 NOT NULL,
"deployment" "text",
"publishStatus" "public"."PublishStatus" DEFAULT 'PENDING'::"public"."PublishStatus" NOT NULL,
"dataSources" "text" DEFAULT '[]'::"text" NOT NULL,
"lastTransactionId" "text",
"resources" "text" DEFAULT '[]'::"text" NOT NULL,
"marketplaceProduct" "text" DEFAULT '{}'::"text" NOT NULL
);

CREATE TABLE IF NOT EXISTS "public"."Project" (
"id" "text" NOT NULL,
"title" "text" NOT NULL,
"domain" "text" NOT NULL,
"userId" "text",
"isDeleted" boolean DEFAULT false NOT NULL,
"createdAt" timestamp(3) with time zone DEFAULT CURRENT_TIMESTAMP NOT NULL,
"previewImageAssetId" "text",
"marketplaceApprovalStatus" "public"."MarketplaceApprovalStatus" DEFAULT 'UNLISTED'::"public"."MarketplaceApprovalStatus" NOT NULL
);

CREATE TABLE IF NOT EXISTS "public"."ProjectDomain" (
"projectId" "text" NOT NULL,
"domainId" "text" NOT NULL,
"createdAt" timestamp(3) with time zone DEFAULT CURRENT_TIMESTAMP NOT NULL,
"txtRecord" "text" NOT NULL,
"cname" "text" NOT NULL
);

CREATE OR REPLACE FUNCTION "public"."latestBuildVirtual"("public"."Project") RETURNS SETOF "public"."latestBuildVirtual"
LANGUAGE "sql" STABLE ROWS 1
AS $_$ -- The function is expected to return 1 row


SELECT
b.id AS "buildId",
b."projectId",
-- Use CASE to determine which domain to select based on conditions
CASE
WHEN (b.deployment::jsonb ->> 'projectDomain') = p.domain
OR (b.deployment::jsonb -> 'domains') @> to_jsonb(array[p.domain])
THEN p.domain
ELSE d.domain
END AS "domain",
b."createdAt",
b."publishStatus"
FROM "Build" b
JOIN "Project" p ON b."projectId" = p.id
LEFT JOIN "ProjectDomain" pd ON pd."projectId" = p.id
LEFT JOIN "Domain" d ON d.id = pd."domainId"
WHERE b."projectId" = $1.id
AND b.deployment IS NOT NULL
-- 'destination' IS NULL for backward compatibility; 'destination' = 'saas' for non-static builds
AND ((b.deployment::jsonb ->> 'destination') IS NULL OR (b.deployment::jsonb ->> 'destination') = 'saas')
AND (
-- Check if 'projectDomain' matches p.domain
(b.deployment::jsonb ->> 'projectDomain') = p.domain
-- Check if 'domains' contains p.domain or d.domain
OR (b.deployment::jsonb -> 'domains') @> to_jsonb(array[p.domain])
OR (b.deployment::jsonb -> 'domains') @> to_jsonb(array[d.domain])
)
ORDER BY b."createdAt" DESC
LIMIT 1;

$_$;

```

Create a pgTAP test for the function "public"."latestBuildVirtual" that takes "public"."Project" as an argument.

---

## Additional Instructions

These instructions are sometimes necessary, while at other times they may not be required.

All fields, such as `projectId`, already reference their corresponding table columns (e.g., `"Project"."id"`), but foreign key constraints are omitted.

- **Data Integrity:** Do not create new tables for `"public"."Project"` or related entities. These tables already exist in the database. DO NOT TRUNCATE DROP or DELETE Existing tables.

- **Data Accuracy:** When inserting new data, adhere strictly to the NULL constraints. Ensure all fields without default values are filled correctly in every `INSERT` statement.
you may omit fields with default values if they are not directly relevant to the tests, except for `"createdAt"` and `"updatedAt"` fields, which should always be specified with explicit timestamp values.

- **Timestamp Fields:** For fields like `"createdAt"` and `"updatedAt"`, always use specific timestamp values rather than functions like `NOW()`.

- **Naming Conventions:** Since field and function names use camelCase, always wrap them in double quotes (`""`) to ensure proper referencing.

- **Test Coverage:** In addition to standard tests, cover additional cases to validate that the function returns the correct data in different scenarios:

1. When a project has changed its domain.
2. When builds with the new domain do not exist and when they do exist.
3. When the domain is either in `Build.deployment.projectDomain` or included in `Build.deployment.domains`.

- **Function Calls:** Use precise casting for function calls, such as `(p.*)::Project`, to ensure accuracy in test execution.

Ensure the tests comprehensively validate the function’s behavior in all specified cases.

In addition to the specific test cases mentioned, any other test scenarios the model identifies would be highly appreciated.

Examples of calling the function:

```sql

select "public"."latestBuildVirtual"((p.*)::"Project") from "public"."Project" p where p.id = '1';
```

---

## PS

Initially, it may produce non-working examples. However, it seems that a multi-step improvement process can enhance the results. By incorporating the additions mentioned above, you can achieve better final outcomes. While not perfect, it serves as a good starting point.

Seems like the shorter the input the better the results. The models are seems to struggle with longer inputs.
191 changes: 191 additions & 0 deletions packages/postgrest/supabase/tests/latest-builds_test.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,191 @@
BEGIN;

-- SELECT plan(8);
SELECT no_plan();

-- Insert a new user into the User table
INSERT INTO "public"."User" ("id", "createdAt", "email", "username")
VALUES
('user1', '2023-01-01 00:00:00+00', '[email protected]', 'user1');

-- Insert projects associated with the user
INSERT INTO "public"."Project" ("id", "title", "domain", "userId", "isDeleted", "createdAt")
VALUES
('project1', 'Project One', 'project1-domain1', 'user1', false, '2023-01-01 00:00:00+00'),
('project2', 'Project Two', 'project2-domain1', 'user1', false, '2023-01-01 00:00:00+00');

-- Insert builds with different deployment formats
INSERT INTO "public"."Build" ("id", "createdAt", "pages", "projectId", "deployment", "updatedAt", "publishStatus")
VALUES
-- Old deployment format: includes projectDomain
('build1', '2023-01-01 00:00:00+00', 'home', 'project1', '{"projectDomain": "project1-domain1", "domains": [""]}'::text, '2023-01-01 00:00:00+00', 'PUBLISHED'),
('build1-old', '2022-01-01 00:00:00+00', 'home', 'project1', '{"projectDomain": "project1-domain1", "domains": [""]}'::text, '2022-01-01 00:00:00+00', 'PUBLISHED'),
('build1-newest-wrong-domain', '2024-01-01 00:00:00+00', 'home', 'project1', '{"projectDomain": "project-wrong", "domains": [""]}'::text, '2024-01-01 00:00:00+00', 'PUBLISHED'),
-- New deployment format: domains array only
('build2', '2023-01-02 00:00:00+00', 'home', 'project2', '{"domains": ["project2-domain1"]}'::text, '2023-01-02 00:00:00+00', 'PENDING'),
('build2-old', '2022-01-02 00:00:00+00', 'home', 'project2', '{"domains": ["project2-domain1"]}'::text, '2022-01-02 00:00:00+00', 'PENDING');

--------------------------------------------------------------------------------
-- Test Case 1: Verify latest build retrieval using old deployment format (projectDomain)
--------------------------------------------------------------------------------
SELECT is (
(SELECT "buildId" FROM "public"."latestBuildVirtual"(
(SELECT (p.*)::"Project" FROM "public"."Project" p WHERE p."id" = 'project1')
)),
'build1',
'Test Case 1: Should return the latest build for project with domain matching projectDomain.'
);

--------------------------------------------------------------------------------
-- Test Case 2: Verify latest build retrieval using new deployment format (domains array)
--------------------------------------------------------------------------------
SELECT is (
(SELECT "buildId" FROM "public"."latestBuildVirtual"(
(SELECT (p.*)::"Project" FROM "public"."Project" p WHERE p."id" = 'project2')
)),
'build2',
'Test Case 2: Should return the latest build for project with domain present in domains array.'
);

--------------------------------------------------------------------------------
-- Test Case 3: Update project domain and verify no build exists for the new domain
--------------------------------------------------------------------------------
UPDATE "public"."Project" SET "domain" = 'project1-domain2' WHERE "id" = 'project1';

SELECT is (
(SELECT COUNT(*)::integer FROM "public"."latestBuildVirtual"(
(SELECT (p.*)::"Project" FROM "public"."Project" p WHERE p."id" = 'project1')
)),
0,
'Test Case 3: Should return 0 as no build exists for the updated domain.'
);

--------------------------------------------------------------------------------
-- Test Case 4: Insert a new build with the updated domain and verify retrieval
--------------------------------------------------------------------------------
INSERT INTO "public"."Build" ("id", "createdAt", "pages", "projectId", "deployment", "updatedAt", "publishStatus")
VALUES
('build1-for-domain2', '2023-01-01 00:00:00+00', 'home', 'project1',
'{"domains": ["some-other-domain.com", "project1-domain2"]}'::text,
'2023-01-01 00:00:00+00', 'PUBLISHED');

SELECT is (
(SELECT "buildId" FROM "public"."latestBuildVirtual"(
(SELECT (p.*)::"Project" FROM "public"."Project" p WHERE p."id" = 'project1')
)),
'build1-for-domain2',
'Test Case 4: Should return the latest build for project with the updated domain in domains array.'
);

--------------------------------------------------------------------------------
-- Test Case 5: Register custom domains and verify the latest build for a custom domain
--------------------------------------------------------------------------------
-- Insert custom domains
INSERT INTO "public"."Domain" ("id", "domain", "createdAt", "status", "updatedAt")
VALUES
('project-1-custom-domain-1', 'project-1-custom-domain-1.com', '2023-01-01 00:00:00+00', 'INITIALIZING', '2023-01-01 00:00:00+00'),
('project-1-custom-domain-2', 'project-1-custom-domain-2.com', '2023-01-01 00:00:00+00', 'INITIALIZING', '2023-01-01 00:00:00+00');

-- Establish relationships between project and custom domains
INSERT INTO "public"."ProjectDomain" ("projectId", "domainId", "createdAt", "txtRecord", "cname")
VALUES
('project1', 'project-1-custom-domain-1', '2023-01-01 00:00:00+00', 'txtRecord1', 'cname1'),
('project1', 'project-1-custom-domain-2', '2023-01-01 00:00:00+00', 'txtRecord2', 'cname2');

-- Insert a build associated with a custom domain
INSERT INTO "public"."Build" ("id", "createdAt", "pages", "projectId", "deployment", "updatedAt", "publishStatus")
VALUES
('build1-for-custom-domain-1', '2023-01-02 00:00:00+00', 'home', 'project1',
'{"domains": ["some-other-domain.com", "project-1-custom-domain-1.com"]}'::text,
'2023-01-02 00:00:00+00', 'PUBLISHED');

SELECT is (
(SELECT "buildId" FROM "public"."latestBuildVirtual"(
(SELECT (p.*)::"Project" FROM "public"."Project" p WHERE p."id" = 'project1')
)),
'build1-for-custom-domain-1',
'Test Case 5: Should return the latest build for project with a registered custom domain in domains array.'
);

--------------------------------------------------------------------------------
-- Test Case 6: Publish a preview domain and verify the latest build retrieval
--------------------------------------------------------------------------------
-- Insert a build for the preview domain using the new deployment format
INSERT INTO "public"."Build" ("id", "createdAt", "pages", "projectId", "deployment", "updatedAt", "publishStatus")
VALUES
('build1-for-domain2-new', '2023-01-03 00:00:00+00', 'home', 'project1',
'{"domains": ["project1-domain2"]}'::text,
'2023-01-03 00:00:00+00', 'PUBLISHED');

SELECT is (
(SELECT "buildId" FROM "public"."latestBuildVirtual"(
(SELECT (p.*)::"Project" FROM "public"."Project" p WHERE p."id" = 'project1')
)),
'build1-for-domain2-new',
'Test Case 6: Should return the latest build for project with preview domain in domains array.'
);

--------------------------------------------------------------------------------
-- Test Case 7: Publish a new build for a custom domain, delete the custom domain, and verify latest build update
--------------------------------------------------------------------------------
-- Insert a new build for the custom domain
INSERT INTO "public"."Build" ("id", "createdAt", "pages", "projectId", "deployment", "updatedAt", "publishStatus")
VALUES
('build1-for-custom-domain-1-new', '2023-01-04 00:00:00+00', 'home', 'project1',
'{"domains": ["some-other-domain.com", "project-1-custom-domain-1.com"]}'::text,
'2023-01-04 00:00:00+00', 'PUBLISHED');

SELECT is (
(SELECT "buildId" FROM "public"."latestBuildVirtual"(
(SELECT (p.*)::"Project" FROM "public"."Project" p WHERE p."id" = 'project1')
)),
'build1-for-custom-domain-1-new',
'Test Case 7a: Should return the latest build after publishing a new build for a custom domain.'
);

-- Delete the custom domain association
DELETE FROM "public"."ProjectDomain" WHERE "projectId" = 'project1' AND "domainId" = 'project-1-custom-domain-1';

SELECT is (
(SELECT "buildId" FROM "public"."latestBuildVirtual"(
(SELECT (p.*)::"Project" FROM "public"."Project" p WHERE p."id" = 'project1')
)),
'build1-for-domain2-new',
'Test Case 7b: Should return the latest build after deleting the custom domain, reverting to the previous latest build.'
);

--------------------------------------------------------------------------------
-- Test Case 8: Publish a new build for a custom domain, move the custom domain, and verify latest build update
--------------------------------------------------------------------------------
-- Revert 7
INSERT INTO "public"."ProjectDomain" ("projectId", "domainId", "createdAt", "txtRecord", "cname")
VALUES
('project1', 'project-1-custom-domain-1', '2023-01-01 00:00:00+00', 'txtRecord1', 'cname1');


SELECT is (
(SELECT "buildId" FROM "public"."latestBuildVirtual"(
(SELECT (p.*)::"Project" FROM "public"."Project" p WHERE p."id" = 'project1')
)),
'build1-for-custom-domain-1-new',
'Test Case 8a: Should return the latest build after publishing a new build for a custom domain.'
);


UPDATE "public"."ProjectDomain" SET "projectId" = 'project2' WHERE "projectId" = 'project1' AND "domainId" = 'project-1-custom-domain-1';


SELECT is (
(SELECT "buildId" FROM "public"."latestBuildVirtual"(
(SELECT (p.*)::"Project" FROM "public"."Project" p WHERE p."id" = 'project1')
)),
'build1-for-domain2-new',
'Test Case 8b: Should return the latest build after moving the custom domain, reverting to the previous latest build.'
);




SELECT finish();

ROLLBACK;

0 comments on commit aa71815

Please sign in to comment.