mirror of
https://github.com/SamyRai/turash.git
synced 2025-12-26 23:01:33 +00:00
Repository Structure:
- Move files from cluttered root directory into organized structure
- Create archive/ for archived data and scraper results
- Create bugulma/ for the complete application (frontend + backend)
- Create data/ for sample datasets and reference materials
- Create docs/ for comprehensive documentation structure
- Create scripts/ for utility scripts and API tools
Backend Implementation:
- Implement 3 missing backend endpoints identified in gap analysis:
* GET /api/v1/organizations/{id}/matching/direct - Direct symbiosis matches
* GET /api/v1/users/me/organizations - User organizations
* POST /api/v1/proposals/{id}/status - Update proposal status
- Add complete proposal domain model, repository, and service layers
- Create database migration for proposals table
- Fix CLI server command registration issue
API Documentation:
- Add comprehensive proposals.md API documentation
- Update README.md with Users and Proposals API sections
- Document all request/response formats, error codes, and business rules
Code Quality:
- Follow existing Go backend architecture patterns
- Add proper error handling and validation
- Match frontend expected response schemas
- Maintain clean separation of concerns (handler -> service -> repository)
417 lines
9.9 KiB
Markdown
417 lines
9.9 KiB
Markdown
# pgx PostgreSQL Driver Development Guide
|
|
|
|
**Library**: `github.com/jackc/pgx/v5`
|
|
**Used In**: MVP - PostgreSQL + PostGIS for geospatial queries
|
|
**Purpose**: High-performance PostgreSQL driver with native PostGIS support
|
|
|
|
---
|
|
|
|
## Where It's Used
|
|
|
|
- **PostGIS spatial queries** (distance calculations, radius searches)
|
|
- **Site location data** (synced from Neo4j)
|
|
- **Raw SQL queries** when needed
|
|
- **Connection pooling** for database operations
|
|
|
|
---
|
|
|
|
## Official Documentation
|
|
|
|
- **GitHub**: https://github.com/jackc/pgx
|
|
- **GoDoc**: https://pkg.go.dev/github.com/jackc/pgx/v5
|
|
- **PostgreSQL Docs**: https://www.postgresql.org/docs/
|
|
- **PostGIS Docs**: https://postgis.net/documentation/
|
|
|
|
---
|
|
|
|
## Installation
|
|
|
|
```bash
|
|
go get github.com/jackc/pgx/v5
|
|
go get github.com/jackc/pgx/v5/pgxpool
|
|
```
|
|
|
|
---
|
|
|
|
## Key Concepts
|
|
|
|
### 1. Connection Pool Setup
|
|
|
|
```go
|
|
import (
|
|
"context"
|
|
"github.com/jackc/pgx/v5/pgxpool"
|
|
)
|
|
|
|
func NewPostgresPool(ctx context.Context, connString string) (*pgxpool.Pool, error) {
|
|
config, err := pgxpool.ParseConfig(connString)
|
|
if err != nil {
|
|
return nil, err
|
|
}
|
|
|
|
// Configure connection pool
|
|
config.MaxConns = 25
|
|
config.MinConns = 5
|
|
config.MaxConnLifetime = time.Hour
|
|
config.MaxConnIdleTime = 30 * time.Minute
|
|
|
|
pool, err := pgxpool.NewWithConfig(ctx, config)
|
|
if err != nil {
|
|
return nil, err
|
|
}
|
|
|
|
// Verify connection
|
|
if err := pool.Ping(ctx); err != nil {
|
|
return nil, err
|
|
}
|
|
|
|
return pool, nil
|
|
}
|
|
|
|
// Connection string format
|
|
// postgres://user:password@localhost:5432/dbname?sslmode=disable
|
|
```
|
|
|
|
### 2. Basic Queries
|
|
|
|
```go
|
|
// Single row query
|
|
func GetSite(ctx context.Context, pool *pgxpool.Pool, id string) (*Site, error) {
|
|
var site Site
|
|
err := pool.QueryRow(ctx,
|
|
"SELECT id, business_id, latitude, longitude, address FROM sites WHERE id = $1",
|
|
id,
|
|
).Scan(&site.ID, &site.BusinessID, &site.Latitude, &site.Longitude, &site.Address)
|
|
|
|
if err == pgx.ErrNoRows {
|
|
return nil, ErrNotFound
|
|
}
|
|
if err != nil {
|
|
return nil, err
|
|
}
|
|
|
|
return &site, nil
|
|
}
|
|
|
|
// Multiple rows query
|
|
func ListSites(ctx context.Context, pool *pgxpool.Pool, limit, offset int) ([]Site, error) {
|
|
rows, err := pool.Query(ctx,
|
|
"SELECT id, business_id, latitude, longitude, address FROM sites ORDER BY created_at DESC LIMIT $1 OFFSET $2",
|
|
limit, offset,
|
|
)
|
|
if err != nil {
|
|
return nil, err
|
|
}
|
|
defer rows.Close()
|
|
|
|
var sites []Site
|
|
for rows.Next() {
|
|
var site Site
|
|
if err := rows.Scan(&site.ID, &site.BusinessID, &site.Latitude, &site.Longitude, &site.Address); err != nil {
|
|
return nil, err
|
|
}
|
|
sites = append(sites, site)
|
|
}
|
|
|
|
return sites, rows.Err()
|
|
}
|
|
```
|
|
|
|
### 3. Transactions
|
|
|
|
```go
|
|
// Transaction
|
|
func CreateSiteWithBusiness(ctx context.Context, pool *pgxpool.Pool, site Site) error {
|
|
tx, err := pool.Begin(ctx)
|
|
if err != nil {
|
|
return err
|
|
}
|
|
defer tx.Rollback(ctx)
|
|
|
|
// Insert business
|
|
_, err = tx.Exec(ctx,
|
|
"INSERT INTO businesses (id, name, email) VALUES ($1, $2, $3)",
|
|
site.BusinessID, "Business Name", "email@example.com",
|
|
)
|
|
if err != nil {
|
|
return err
|
|
}
|
|
|
|
// Insert site
|
|
_, err = tx.Exec(ctx,
|
|
"INSERT INTO sites (id, business_id, latitude, longitude, location) VALUES ($1, $2, $3, $4, ST_MakePoint($4, $3))",
|
|
site.ID, site.BusinessID, site.Latitude, site.Longitude,
|
|
)
|
|
if err != nil {
|
|
return err
|
|
}
|
|
|
|
return tx.Commit(ctx)
|
|
}
|
|
```
|
|
|
|
### 4. PostGIS Spatial Queries
|
|
|
|
```go
|
|
import "github.com/twpayne/go-geom"
|
|
|
|
// Find sites within radius (PostGIS)
|
|
func FindSitesWithinRadius(ctx context.Context, pool *pgxpool.Pool, lat, lon float64, radiusMeters float64) ([]Site, error) {
|
|
query := `
|
|
SELECT
|
|
site_id,
|
|
business_id,
|
|
latitude,
|
|
longitude,
|
|
ST_Distance(
|
|
location,
|
|
ST_MakePoint($1, $2)::geography
|
|
) AS distance_meters
|
|
FROM sites_geo
|
|
WHERE ST_DWithin(
|
|
location::geography,
|
|
ST_MakePoint($1, $2)::geography,
|
|
$3
|
|
)
|
|
ORDER BY distance_meters ASC
|
|
LIMIT 50
|
|
`
|
|
|
|
rows, err := pool.Query(ctx, query, lon, lat, radiusMeters)
|
|
if err != nil {
|
|
return nil, err
|
|
}
|
|
defer rows.Close()
|
|
|
|
var sites []SiteGeo
|
|
for rows.Next() {
|
|
var site SiteGeo
|
|
var distanceMeters float64
|
|
err := rows.Scan(
|
|
&site.SiteID,
|
|
&site.BusinessID,
|
|
&site.Latitude,
|
|
&site.Longitude,
|
|
&distanceMeters,
|
|
)
|
|
if err != nil {
|
|
return nil, err
|
|
}
|
|
site.DistanceKm = distanceMeters / 1000
|
|
sites = append(sites, site)
|
|
}
|
|
|
|
return sites, rows.Err()
|
|
}
|
|
|
|
// Spatial index is critical for performance
|
|
// CREATE INDEX idx_sites_location ON sites_geo USING GIST(location);
|
|
```
|
|
|
|
### 5. Batch Operations
|
|
|
|
```go
|
|
// Batch insert (faster for multiple rows)
|
|
func BatchInsertSites(ctx context.Context, pool *pgxpool.Pool, sites []Site) error {
|
|
batch := &pgx.Batch{}
|
|
|
|
for _, site := range sites {
|
|
batch.Queue(
|
|
"INSERT INTO sites_geo (site_id, business_id, latitude, longitude, location) VALUES ($1, $2, $3, $4, ST_MakePoint($4, $3))",
|
|
site.ID, site.BusinessID, site.Latitude, site.Longitude,
|
|
)
|
|
}
|
|
|
|
results := pool.SendBatch(ctx, batch)
|
|
defer results.Close()
|
|
|
|
for i := 0; i < len(sites); i++ {
|
|
_, err := results.Exec()
|
|
if err != nil {
|
|
return err
|
|
}
|
|
}
|
|
|
|
return nil
|
|
}
|
|
```
|
|
|
|
### 6. Prepared Statements
|
|
|
|
```go
|
|
// Prepare statement for reuse (performance)
|
|
func (s *SiteService) prepareStatements(ctx context.Context) error {
|
|
var err error
|
|
|
|
s.findSiteStmt, err = s.pool.Prepare(ctx, "find_site",
|
|
"SELECT id, business_id, latitude, longitude FROM sites WHERE id = $1",
|
|
)
|
|
if err != nil {
|
|
return err
|
|
}
|
|
|
|
s.insertSiteStmt, err = s.pool.Prepare(ctx, "insert_site",
|
|
"INSERT INTO sites (id, business_id, latitude, longitude, location) VALUES ($1, $2, $3, $4, ST_MakePoint($4, $3))",
|
|
)
|
|
if err != nil {
|
|
return err
|
|
}
|
|
|
|
return nil
|
|
}
|
|
|
|
// Use prepared statement
|
|
func (s *SiteService) FindSite(ctx context.Context, id string) (*Site, error) {
|
|
var site Site
|
|
err := s.pool.QueryRow(ctx, "find_site", id).Scan(
|
|
&site.ID, &site.BusinessID, &site.Latitude, &site.Longitude,
|
|
)
|
|
// ...
|
|
}
|
|
```
|
|
|
|
---
|
|
|
|
## MVP-Specific Patterns
|
|
|
|
### Site Geo Service
|
|
|
|
```go
|
|
type SiteGeoService struct {
|
|
pool *pgxpool.Pool
|
|
}
|
|
|
|
type SiteGeo struct {
|
|
SiteID uuid.UUID
|
|
BusinessID uuid.UUID
|
|
Latitude float64
|
|
Longitude float64
|
|
DistanceKm float64 // For query results
|
|
}
|
|
|
|
// Sync from Neo4j (event-driven)
|
|
func (s *SiteGeoService) SyncFromNeo4j(ctx context.Context, site SiteGeo) error {
|
|
query := `
|
|
INSERT INTO sites_geo (site_id, business_id, latitude, longitude, location)
|
|
VALUES ($1, $2, $3, $4, ST_MakePoint($4, $3))
|
|
ON CONFLICT (site_id)
|
|
DO UPDATE SET
|
|
latitude = EXCLUDED.latitude,
|
|
longitude = EXCLUDED.longitude,
|
|
location = ST_MakePoint(EXCLUDED.longitude, EXCLUDED.latitude),
|
|
updated_at = NOW()
|
|
`
|
|
|
|
_, err := s.pool.Exec(ctx, query,
|
|
site.SiteID, site.BusinessID, site.Latitude, site.Longitude,
|
|
)
|
|
return err
|
|
}
|
|
|
|
// Spatial pre-filter for matching algorithm
|
|
func (s *SiteGeoService) FindWithinRadius(ctx context.Context, lat, lon, radiusKm float64) ([]uuid.UUID, error) {
|
|
radiusMeters := radiusKm * 1000
|
|
query := `
|
|
SELECT site_id
|
|
FROM sites_geo
|
|
WHERE ST_DWithin(
|
|
location::geography,
|
|
ST_MakePoint($1, $2)::geography,
|
|
$3
|
|
)
|
|
`
|
|
|
|
rows, err := s.pool.Query(ctx, query, lon, lat, radiusMeters)
|
|
if err != nil {
|
|
return nil, err
|
|
}
|
|
defer rows.Close()
|
|
|
|
var siteIDs []uuid.UUID
|
|
for rows.Next() {
|
|
var siteID uuid.UUID
|
|
if err := rows.Scan(&siteID); err != nil {
|
|
return nil, err
|
|
}
|
|
siteIDs = append(siteIDs, siteID)
|
|
}
|
|
|
|
return siteIDs, rows.Err()
|
|
}
|
|
```
|
|
|
|
---
|
|
|
|
## PostGIS Schema
|
|
|
|
```sql
|
|
-- Create table with PostGIS geometry
|
|
CREATE EXTENSION IF NOT EXISTS postgis;
|
|
|
|
CREATE TABLE sites_geo (
|
|
site_id UUID PRIMARY KEY,
|
|
business_id UUID NOT NULL,
|
|
latitude FLOAT NOT NULL,
|
|
longitude FLOAT NOT NULL,
|
|
location GEOMETRY(POINT, 4326) NOT NULL,
|
|
created_at TIMESTAMP DEFAULT NOW(),
|
|
updated_at TIMESTAMP DEFAULT NOW()
|
|
);
|
|
|
|
-- Spatial index (critical for performance)
|
|
CREATE INDEX idx_sites_location ON sites_geo USING GIST(location);
|
|
|
|
-- Business ID index (for joins)
|
|
CREATE INDEX idx_sites_business_id ON sites_geo(business_id);
|
|
|
|
-- Update location from lat/lon trigger (optional)
|
|
CREATE OR REPLACE FUNCTION update_location()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.location = ST_MakePoint(NEW.longitude, NEW.latitude);
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER trigger_update_location
|
|
BEFORE INSERT OR UPDATE ON sites_geo
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_location();
|
|
```
|
|
|
|
---
|
|
|
|
## Performance Tips
|
|
|
|
1. **Use GIST index** for spatial queries (PostGIS)
|
|
2. **Use prepared statements** for repeated queries
|
|
3. **Batch operations** for bulk inserts
|
|
4. **Connection pooling** - configure appropriately
|
|
5. **Geography vs Geometry** - use geography for distance calculations on Earth
|
|
6. **Use LIMIT** - always limit query results
|
|
|
|
---
|
|
|
|
## Error Handling
|
|
|
|
```go
|
|
err := pool.QueryRow(ctx, query, args...).Scan(...)
|
|
if err == pgx.ErrNoRows {
|
|
// Not found
|
|
return nil, ErrNotFound
|
|
}
|
|
if err != nil {
|
|
// Other error
|
|
return nil, err
|
|
}
|
|
```
|
|
|
|
---
|
|
|
|
## Tutorials & Resources
|
|
|
|
- **pgx Examples**: https://github.com/jackc/pgx/tree/master/examples
|
|
- **PostGIS Documentation**: https://postgis.net/documentation/
|
|
- **PostgreSQL Spatial**: https://www.postgresql.org/docs/current/postgis.html
|
|
|