Skip to content

Commit

Permalink
Change SP500 percentile test to a generic quotes table
Browse files Browse the repository at this point in the history
  • Loading branch information
vladmihalcea committed Apr 18, 2024
1 parent 30e9c64 commit 1408e2a
Show file tree
Hide file tree
Showing 4 changed files with 2,607 additions and 1,277 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -6,14 +6,11 @@
import org.junit.Test;

import java.math.BigDecimal;
import java.sql.Timestamp;
import java.time.LocalDate;
import java.time.ZoneId;
import java.util.Date;
import java.util.List;
import java.util.Locale;
import java.util.Properties;

import static org.hibernate.cfg.SchemaToolingSettings.JAKARTA_HBM2DDL_CREATE_SCRIPT_SOURCE;
import static org.hibernate.cfg.SchemaToolingSettings.JAKARTA_HBM2DDL_LOAD_SCRIPT_SOURCE;
import static org.junit.Assert.assertEquals;

Expand All @@ -25,30 +22,39 @@ public class WindowFunctionPercentilesTest extends AbstractTest {
@Override
protected Class<?>[] entities() {
return new Class<?>[] {
SP500.class,
Quote.class,
};
}

@Override
protected Database database() {
return Database.POSTGRESQL;
return Database.SQLSERVER;
}

@Override
protected void additionalProperties(Properties properties) {
properties.put(JAKARTA_HBM2DDL_LOAD_SCRIPT_SOURCE, "data/sp500.sql");
properties.put(
JAKARTA_HBM2DDL_LOAD_SCRIPT_SOURCE,
database() == Database.ORACLE ? "data/oracle_quotes.sql" : "data/quotes.sql"
);
}

@Test
public void test() {
if(!(database() == Database.ORACLE || database() == Database.POSTGRESQL)) {
return;
}
doInJPA(entityManager -> {
List<Tuple> prices = entityManager.createNativeQuery("""
SELECT
PERCENTILE_CONT(0.50) WITHIN GROUP(ORDER BY close_price) AS median,
PERCENTILE_CONT(0.75) WITHIN GROUP(ORDER BY close_price) AS p75,
PERCENTILE_CONT(0.95) WITHIN GROUP(ORDER BY close_price) AS p95,
PERCENTILE_CONT(0.99) WITHIN GROUP(ORDER BY close_price) AS p99
FROM sp500
PERCENTILE_CONT(0.50) WITHIN GROUP(ORDER BY close_price) AS median,
PERCENTILE_CONT(0.75) WITHIN GROUP(ORDER BY close_price) AS p75,
PERCENTILE_CONT(0.95) WITHIN GROUP(ORDER BY close_price) AS p95,
PERCENTILE_CONT(0.99) WITHIN GROUP(ORDER BY close_price) AS p99
FROM quotes
WHERE
ticker = 'SPX' AND
quote_date BETWEEN DATE '2019-01-01' AND DATE '2023-12-31'
""", Tuple.class)
.getResultList();

Expand All @@ -58,30 +64,96 @@ public void test() {
doInJPA(entityManager -> {
List<Tuple> prices = entityManager.createNativeQuery("""
SELECT
extract(year from price_date) AS year,
extract(year from quote_date) AS year,
PERCENTILE_CONT(0.50) WITHIN GROUP(ORDER BY close_price) AS median,
PERCENTILE_CONT(0.75) WITHIN GROUP(ORDER BY close_price) AS p75,
PERCENTILE_CONT(0.95) WITHIN GROUP(ORDER BY close_price) AS p95,
PERCENTILE_CONT(0.99) WITHIN GROUP(ORDER BY close_price) AS p99
FROM sp500
GROUP BY extract(year from price_date)
FROM quotes
WHERE
ticker = 'SPX' AND
quote_date BETWEEN DATE '2019-01-01' AND DATE '2023-12-31'
GROUP BY extract(year from quote_date)
ORDER BY year
""", Tuple.class)
.getResultList();

assertEquals(5, prices.size());
});
}

@Test
public void testSQLServer() {
if(!(database() == Database.SQLSERVER)) {
return;
}
doInJPA(entityManager -> {
List<Tuple> prices = entityManager.createNativeQuery("""
SELECT DISTINCT
PERCENTILE_CONT(0.50) WITHIN GROUP(ORDER BY close_price)
OVER (PARTITION BY ticker) AS median,
PERCENTILE_CONT(0.75) WITHIN GROUP(ORDER BY close_price)
OVER (PARTITION BY ticker) AS p75,
PERCENTILE_CONT(0.95) WITHIN GROUP(ORDER BY close_price)
OVER (PARTITION BY ticker) AS p95,
PERCENTILE_CONT(0.99) WITHIN GROUP(ORDER BY close_price)
OVER (PARTITION BY ticker) AS p99
FROM quotes
WHERE
ticker = 'SPX' AND
quote_date BETWEEN '2019-01-01' AND '2023-12-31'
""", Tuple.class)
.getResultList();

assertEquals(1, prices.size());
});

doInJPA(entityManager -> {
List<Tuple> prices = entityManager.createNativeQuery("""
SELECT DISTINCT
YEAR(quote_date) AS year,
PERCENTILE_CONT(0.50) WITHIN GROUP(ORDER BY close_price)
OVER (PARTITION BY YEAR(quote_date)) AS median,
PERCENTILE_CONT(0.75) WITHIN GROUP(ORDER BY close_price)
OVER (PARTITION BY YEAR(quote_date)) AS p75,
PERCENTILE_CONT(0.95) WITHIN GROUP(ORDER BY close_price)
OVER (PARTITION BY YEAR(quote_date)) AS p95,
PERCENTILE_CONT(0.99) WITHIN GROUP(ORDER BY close_price)
OVER (PARTITION BY YEAR(quote_date)) AS p99
FROM quotes
WHERE
ticker = 'SPX' AND
quote_date BETWEEN '2019-01-01' AND '2023-12-31'
ORDER BY year
""", Tuple.class)
.getResultList();

assertEquals(5, prices.size());
});
}

@Entity(name = "SP500")
public static class SP500 {
@Entity(name = "quotes")
public static class Quote {

@Id
@Column(length = 4)
private String ticker;

@Id
@Column(name = "price_date")
@Column(name = "quote_date")
private LocalDate date;

@Column(name = "close_price")
@Column(name = "close_price", precision = 12, scale = 4)
private BigDecimal price;

public String getTicker() {
return ticker;
}

public void setTicker(String ticker) {
this.ticker = ticker;
}

public LocalDate getDate() {
return date;
}
Expand Down

0 comments on commit 1408e2a

Please sign in to comment.