Skip to content

Commit

Permalink
Merge pull request #307 from rizwanahar/master
Browse files Browse the repository at this point in the history
Postgres integration across the code base
  • Loading branch information
llemeurfr authored May 9, 2024
2 parents 6e95190 + 80b5ff0 commit 8d00bbe
Show file tree
Hide file tree
Showing 14 changed files with 265 additions and 76 deletions.
4 changes: 4 additions & 0 deletions config/config.go
Original file line number Diff line number Diff line change
Expand Up @@ -141,6 +141,10 @@ func GetDatabase(uri string) (string, string) {
}

parts := strings.Split(uri, "://")
if parts[0] == "postgres" {
return parts[0], uri
}

return parts[0], parts[1]
}

Expand Down
50 changes: 50 additions & 0 deletions dbmodel/postgres _db_setup_frontend.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,50 @@
CREATE SEQUENCE publication_seq;

CREATE TABLE publication (
id int PRIMARY KEY DEFAULT NEXTVAL ('publication_seq'),
uuid varchar(255) NOT NULL, /* == content id */
title varchar(255) NOT NULL,
status varchar(255) NOT NULL
);

CREATE INDEX uuid_index ON publication (uuid);

CREATE SEQUENCE user_seq;

CREATE TABLE "user" (
id int PRIMARY KEY DEFAULT NEXTVAL ('user_seq'),
uuid varchar(255) NOT NULL,
name varchar(64) NOT NULL,
email varchar(64) NOT NULL,
password varchar(64) NOT NULL,
hint varchar(64) NOT NULL
);

CREATE SEQUENCE purchase_seq;

CREATE TABLE purchase (
id int PRIMARY KEY DEFAULT NEXTVAL ('purchase_seq'),
uuid varchar(255) NOT NULL,
publication_id int NOT NULL,
user_id int NOT NULL,
license_uuid varchar(255) NULL,
type varchar(32) NOT NULL,
transaction_date timestamp(0),
start_date timestamp(0),
end_date timestamp(0),
status varchar(255) NOT NULL,
FOREIGN KEY (publication_id) REFERENCES publication (id),
FOREIGN KEY (user_id) REFERENCES "user" (id)
);

CREATE INDEX idx_purchase ON purchase (license_uuid);

CREATE SEQUENCE license_view_seq;

CREATE TABLE license_view (
id int PRIMARY KEY DEFAULT NEXTVAL ('license_view_seq'),
uuid varchar(255) NOT NULL,
device_count int NOT NULL,
status varchar(255) NOT NULL,
message varchar(255) NOT NULL
);
25 changes: 25 additions & 0 deletions dbmodel/postgres_db_setup_lcpserver.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@

CREATE TABLE content (
id varchar(255) PRIMARY KEY NOT NULL,
encryption_key bytea NOT NULL,
location text NOT NULL,
length bigint,
sha256 varchar(64),
type varchar(255) NOT NULL DEFAULT 'application/epub+zip'
);

-- SQLINES LICENSE FOR EVALUATION USE ONLY
CREATE TABLE license (
id varchar(255) PRIMARY KEY NOT NULL,
user_id varchar(255) NOT NULL,
provider varchar(255) NOT NULL,
issued timestamp(0) NOT NULL,
updated timestamp(0) DEFAULT NULL,
rights_print int DEFAULT NULL,
rights_copy int DEFAULT NULL,
rights_start timestamp(0) DEFAULT NULL,
rights_end timestamp(0) DEFAULT NULL,
content_fk varchar(255) NOT NULL,
lsd_status int default 0,
FOREIGN KEY(content_fk) REFERENCES content(id)
);
26 changes: 26 additions & 0 deletions dbmodel/postgres_db_setup_lsdserver.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,26 @@
CREATE TABLE license_status (
id serial4 NOT NULL,
status smallint NOT NULL,
license_updated timestamp(3) NOT NULL,
status_updated timestamp(3) NOT NULL,
device_count smallint DEFAULT NULL,
potential_rights_end timestamp(3) DEFAULT NULL,
license_ref varchar(255) NOT NULL,
rights_end timestamp(3) DEFAULT NULL,
CONSTRAINT license_status_pkey PRIMARY KEY (id)
);

CREATE INDEX license_ref_index ON license_status (license_ref);

CREATE TABLE event (
id serial4 NOT NULL,
device_name varchar(255) DEFAULT NULL,
timestamp timestamp(3) NOT NULL,
type int NOT NULL,
device_id varchar(255) DEFAULT NULL,
license_status_fk int NOT NULL,
CONSTRAINT event_pkey PRIMARY KEY (id),
FOREIGN KEY(license_status_fk) REFERENCES license_status(id)
);

CREATE INDEX license_status_fk_index on event (license_status_fk);
31 changes: 31 additions & 0 deletions dbutils/dbutils.go
Original file line number Diff line number Diff line change
@@ -0,0 +1,31 @@
package dbutils

import (
"bytes"
"fmt"
"strings"
)

func getPostgresQuery(query string) string {
var buffer bytes.Buffer
idx := 1
for _, char := range query {
if char == '?' {
buffer.WriteString(fmt.Sprintf("$%d", idx))
idx += 1
} else {
buffer.WriteRune(char)
}
}
return buffer.String()
}

// GetParamQuery replaces parameter placeholders '?' in the SQL query to
// placeholders supported by the selected database driver.
func GetParamQuery(database, query string) string {
if strings.HasPrefix(database, "postgres") {
return getPostgresQuery(query)
} else {
return query
}
}
17 changes: 17 additions & 0 deletions dbutils/dbutils_test.go
Original file line number Diff line number Diff line change
@@ -0,0 +1,17 @@
package dbutils

import "testing"

const demo_query = "SELECT * FROM test WHERE id = ? AND test = ? LIMIT 1"

func TestGetParamQuery(t *testing.T) {
q := GetParamQuery("postgres", demo_query)
if q != "SELECT * FROM test WHERE id = $1 AND test = $2 LIMIT 1" {
t.Fatalf("Incorrect postgres query")
}

q = GetParamQuery("sqlite3", demo_query)
if q != "SELECT * FROM test WHERE id = ? AND test = ? LIMIT 1" {
t.Fatalf("Incorrect sqlite3 query")
}
}
19 changes: 11 additions & 8 deletions frontend/weblicense/weblicense.go
Original file line number Diff line number Diff line change
Expand Up @@ -32,6 +32,7 @@ import (
"log"

"github.com/readium/readium-lcp-server/config"
"github.com/readium/readium-lcp-server/dbutils"
)

// License status
Expand Down Expand Up @@ -135,7 +136,7 @@ func (licManager LicenseManager) GetFiltered(deviceLimit string) ([]License, err
// Add adds a new license
func (licManager LicenseManager) Add(licenses License) error {

_, err := licManager.db.Exec("INSERT INTO license_view (uuid, device_count, status, message) VALUES (?, ?, ?, ?)",
_, err := licManager.db.Exec(dbutils.GetParamQuery(config.Config.FrontendServer.Database, "INSERT INTO license_view (uuid, device_count, status, message) VALUES (?, ?, ?, ?)"),
licenses.UUID, licenses.DeviceCount, licenses.Status, licenses.Message)
return err
}
Expand All @@ -148,7 +149,8 @@ func (licManager LicenseManager) AddFromJSON(licensesJSON []byte) error {
return err
}

add, err := licManager.db.Prepare("INSERT INTO license_view (uuid, device_count, status, message) VALUES (?, ?, ?, ?)")
add, err := licManager.db.Prepare(dbutils.GetParamQuery(config.Config.FrontendServer.Database,
"INSERT INTO license_view (uuid, device_count, status, message) VALUES (?, ?, ?, ?)"))
if err != nil {
return err
}
Expand All @@ -173,15 +175,16 @@ func (licManager LicenseManager) PurgeDataBase() error {
// Update updates a license
func (licManager LicenseManager) Update(lic License) error {

_, err := licManager.db.Exec("UPDATE license_view SET device_count=?, uuid=?, status=? , message=? WHERE id = ?",
_, err := licManager.db.Exec(dbutils.GetParamQuery(config.Config.FrontendServer.Database,
"UPDATE license_view SET device_count=?, uuid=?, status=? , message=? WHERE id = ?"),
lic.DeviceCount, lic.Status, lic.UUID, lic.ID, lic.Message)
return err
}

// Delete deletes a license
func (licManager LicenseManager) Delete(id int64) error {

_, err := licManager.db.Exec("DELETE FROM license_view WHERE id = ?", id)
_, err := licManager.db.Exec(dbutils.GetParamQuery(config.Config.FrontendServer.Database, "DELETE FROM license_view WHERE id = ?"), id)
return err
}

Expand All @@ -200,25 +203,25 @@ func Init(db *sql.DB) (i WebLicense, err error) {
}

var dbGetByID *sql.Stmt
dbGetByID, err = db.Prepare(
dbGetByID, err = db.Prepare(dbutils.GetParamQuery(config.Config.FrontendServer.Database,
`SELECT l.uuid, pu.title, u.name, p.type, l.device_count, l.status, p.id, l.message
FROM license_view AS l
INNER JOIN purchase as p ON l.uuid = p.license_uuid
INNER JOIN publication as pu ON p.publication_id = pu.id
INNER JOIN "user" as u ON p.user_id = u.id
WHERE l.id = ?`)
WHERE l.id = ?`))
if err != nil {
log.Println("Error preparing dbGetByID")
return
}

var dbGetFiltered *sql.Stmt
dbGetFiltered, err = db.Prepare(
dbGetFiltered, err = db.Prepare(dbutils.GetParamQuery(config.Config.FrontendServer.Database,
`SELECT l.uuid, pu.title, u.name, p.type, l.device_count, l.status, p.id, l.message FROM license_view AS l
INNER JOIN purchase as p ON l.uuid = p.license_uuid
INNER JOIN publication as pu ON p.publication_id = pu.id
INNER JOIN "user" as u ON p.user_id = u.id
WHERE l.device_count >= ?`)
WHERE l.device_count >= ?`))
if err != nil {
log.Println("Error preparing dbGetFiltered")
return
Expand Down
21 changes: 12 additions & 9 deletions frontend/webpublication/webpublication.go
Original file line number Diff line number Diff line change
Expand Up @@ -15,6 +15,7 @@ import (
"path/filepath"

"github.com/readium/readium-lcp-server/config"
"github.com/readium/readium-lcp-server/dbutils"
"github.com/readium/readium-lcp-server/encrypt"
)

Expand Down Expand Up @@ -128,7 +129,8 @@ func encryptPublication(inputPath string, pub *Publication, pubManager Publicati
// the publication uuid is the lcp db content id.
pub.UUID = notification.UUID
pub.Status = StatusOk
_, err = pubManager.db.Exec("INSERT INTO publication (uuid, title, status) VALUES ( ?, ?, ?)",
_, err = pubManager.db.Exec(dbutils.GetParamQuery(config.Config.FrontendServer.Database,
"INSERT INTO publication (uuid, title, status) VALUES ( ?, ?, ?)"),
pub.UUID, pub.Title, pub.Status)

return err
Expand Down Expand Up @@ -187,7 +189,8 @@ func (pubManager PublicationManager) Upload(file multipart.File, extension strin
// Only the title is updated
func (pubManager PublicationManager) Update(pub Publication) error {

_, err := pubManager.db.Exec("UPDATE publication SET title=?, status=? WHERE id = ?",
_, err := pubManager.db.Exec(dbutils.GetParamQuery(config.Config.FrontendServer.Database,
"UPDATE publication SET title=?, status=? WHERE id = ?"),
pub.Title, pub.Status, pub.ID)
return err
}
Expand All @@ -203,13 +206,13 @@ func (pubManager PublicationManager) Delete(id int64) error {
}

// delete all purchases relative to this publication
_, err = pubManager.db.Exec(`DELETE FROM purchase WHERE publication_id=?`, id)
_, err = pubManager.db.Exec(dbutils.GetParamQuery(config.Config.FrontendServer.Database, `DELETE FROM purchase WHERE publication_id=?`), id)
if err != nil {
return err
}

// delete the publication
_, err = pubManager.db.Exec("DELETE FROM publication WHERE id = ?", id)
_, err = pubManager.db.Exec(dbutils.GetParamQuery(config.Config.FrontendServer.Database, "DELETE FROM publication WHERE id = ?"), id)
return err
}

Expand Down Expand Up @@ -258,25 +261,25 @@ func Init(db *sql.DB) (i WebPublication, err error) {
}

var dbGetByID *sql.Stmt
dbGetByID, err = db.Prepare("SELECT id, uuid, title, status FROM publication WHERE id = ?")
dbGetByID, err = db.Prepare(dbutils.GetParamQuery(config.Config.FrontendServer.Database, "SELECT id, uuid, title, status FROM publication WHERE id = ?"))
if err != nil {
return
}

var dbGetByUUID *sql.Stmt
dbGetByUUID, err = db.Prepare("SELECT id, uuid, title, status FROM publication WHERE uuid = ?")
dbGetByUUID, err = db.Prepare(dbutils.GetParamQuery(config.Config.FrontendServer.Database, "SELECT id, uuid, title, status FROM publication WHERE uuid = ?"))
if err != nil {
return
}

var dbCheckByTitle *sql.Stmt
dbCheckByTitle, err = db.Prepare("SELECT COUNT(1) FROM publication WHERE title = ?")
dbCheckByTitle, err = db.Prepare(dbutils.GetParamQuery(config.Config.FrontendServer.Database, "SELECT COUNT(1) FROM publication WHERE title = ?"))
if err != nil {
return
}

var dbGetMasterFile *sql.Stmt
dbGetMasterFile, err = db.Prepare("SELECT title FROM publication WHERE id = ?")
dbGetMasterFile, err = db.Prepare(dbutils.GetParamQuery(config.Config.FrontendServer.Database, "SELECT title FROM publication WHERE id = ?"))
if err != nil {
return
}
Expand All @@ -285,7 +288,7 @@ func Init(db *sql.DB) (i WebPublication, err error) {
if driver == "mssql" {
dbList, err = db.Prepare("SELECT id, uuid, title, status FROM publication ORDER BY id desc OFFSET ? ROWS FETCH NEXT ? ROWS ONLY")
} else {
dbList, err = db.Prepare("SELECT id, uuid, title, status FROM publication ORDER BY id desc LIMIT ? OFFSET ?")
dbList, err = db.Prepare(dbutils.GetParamQuery(config.Config.FrontendServer.Database, "SELECT id, uuid, title, status FROM publication ORDER BY id desc LIMIT ? OFFSET ?"))

}
if err != nil {
Expand Down
Loading

0 comments on commit 8d00bbe

Please sign in to comment.