You are viewing a plain text version of this content. The canonical link for it is here.
Posted to dev@phoenix.apache.org by jtaylor-sfdc <gi...@git.apache.org> on 2014/05/15 07:58:55 UTC

[GitHub] incubator-phoenix pull request: Add functions FIRST_VALUE and LAST...

Github user jtaylor-sfdc commented on a diff in the pull request:

    https://github.com/apache/incubator-phoenix/pull/30#discussion_r12675530
  
    --- Diff: phoenix-core/src/it/java/org/apache/phoenix/end2end/FirstLastValueFunctionIT.java ---
    @@ -0,0 +1,604 @@
    +/*
    + * Copyright 2014 The Apache Software Foundation
    + *
    + * Licensed to the Apache Software Foundation (ASF) under one
    + * or more contributor license agreements.  See the NOTICE file
    + * distributed with this work for additional information
    + * regarding copyright ownership.  The ASF licenses this file
    + * to you under the Apache License, Version 2.0 (the
    + * "License"); you may not use this file except in compliance
    + * with the License.  You may obtain a copy of the License at
    + *
    + * http://www.apache.org/licenses/LICENSE-2.0
    + *
    + * Unless required by applicable law or agreed to in writing, software
    + * distributed under the License is distributed on an "AS IS" BASIS,
    + * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
    + * See the License for the specific language governing permissions and
    + * limitations under the License.
    + */
    +package org.apache.phoenix.end2end;
    +
    +import static org.junit.Assert.*;
    +import java.sql.*;
    +import org.junit.Test;
    +
    +/**
    + * Integration tests for FIRST|LAST VALUE built in function
    + */
    +public class FirstLastValueFunctionIT extends BaseHBaseManagedTimeIT {
    +
    +	private void prepareTable() throws Exception {
    +		Connection conn = DriverManager.getConnection(getUrl());
    +		String ddl = "CREATE TABLE IF NOT EXISTS firstValue "
    +				+ "(id INTEGER NOT NULL PRIMARY KEY, page_id INTEGER,"
    +				+ " date INTEGER, \"value\" INTEGER)";
    +		conn.createStatement().execute(ddl);
    +
    +		//in value column will be 0, 2, 4, 6, 8, so 8 is the biggest
    +		for (int i = 0; i < 5; i++) {
    +			conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\")"
    +					+ " VALUES (" + i + ", 8, " + 100 * i + ", " + i * 2 + ")");
    +		}
    +
    +		conn.commit();
    +	}
    +
    +	@Test
    +	public void testFirst() throws Exception {
    +		prepareTable();
    +		Connection conn = DriverManager.getConnection(getUrl());
    +
    +		ResultSet rs = conn.createStatement().executeQuery(
    +				"SELECT FIRST_VALUE(\"value\", date) FROM firstValue GROUP BY page_id");
    +
    +		assertTrue(rs.next());
    +		assertEquals(rs.getInt(1), 0);
    +		assertFalse(rs.next());
    +	}
    +
    +	@Test
    +	public void offsetValue() throws Exception {
    +		Connection conn = DriverManager.getConnection(getUrl());
    +
    +		String ddl = "CREATE TABLE IF NOT EXISTS firstValue "
    +				+ "(id INTEGER NOT NULL PRIMARY KEY, page_id UNSIGNED_LONG,"
    +				+ " date INTEGER, \"value\" UNSIGNED_LONG)";
    +		conn.createStatement().execute(ddl);
    +
    +		conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\") VALUES (1, 8, 0, 300)");
    +		conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\") VALUES (2, 8, 1, 7)");
    +		conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\") VALUES (3, 8, 2, 9)");
    +		conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\") VALUES (4, 8, 3, 4)");
    +		conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\") VALUES (5, 8, 4, 2)");
    +		conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\") VALUES (6, 8, 5, 150)");
    +		conn.commit();
    +
    +		ResultSet rs = conn.createStatement().executeQuery("SELECT FIRST_VALUE(\"value\", date, 2) FROM firstValue GROUP BY page_id");
    +
    +		assertTrue(rs.next());
    +		assertEquals(rs.getInt(1), 7);
    +		assertFalse(rs.next());
    +	}
    +
    +	@Test
    +	public void offsetValueLast() throws Exception {
    +		Connection conn = DriverManager.getConnection(getUrl());
    +
    +		String ddl = "CREATE TABLE IF NOT EXISTS firstValue "
    +				+ "(id INTEGER NOT NULL PRIMARY KEY, page_id UNSIGNED_LONG,"
    +				+ " date INTEGER, \"value\" UNSIGNED_LONG)";
    +		conn.createStatement().execute(ddl);
    +
    +		conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\") VALUES (1, 8, 0, 300)");
    +		conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\") VALUES (2, 8, 1, 7)");
    +		conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\") VALUES (3, 8, 2, 9)");
    +		conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\") VALUES (4, 8, 3, 4)");
    +		conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\") VALUES (5, 8, 4, 2)");
    +		conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\") VALUES (6, 8, 5, 150)");
    +		conn.commit();
    +
    +		ResultSet rs = conn.createStatement().executeQuery(
    +				"SELECT LAST_VALUE(\"value\", date, 2) FROM firstValue GROUP BY page_id");
    +
    +		assertTrue(rs.next());
    +		assertEquals(rs.getInt(1), 2);
    +		assertFalse(rs.next());
    +	}
    +
    +	@Test
    +	public void offsetValueLastMismatchByColumn() throws Exception {
    +		Connection conn = DriverManager.getConnection(getUrl());
    +
    +		String ddl = "CREATE TABLE IF NOT EXISTS firstValue "
    +				+ "(id INTEGER NOT NULL PRIMARY KEY, page_id UNSIGNED_LONG,"
    +				+ " date INTEGER, \"value\" UNSIGNED_LONG)";
    +		conn.createStatement().execute(ddl);
    +
    +		conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\") VALUES (1, 8, 5, 8)");
    +		conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\") VALUES (2, 8, 2, 7)");
    +		conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\") VALUES (3, 8, 1, 9)");
    +		conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\") VALUES (4, 8, 4, 4)");
    +		conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\") VALUES (5, 8, 3, 2)");
    +		conn.createStatement().execute("UPSERT INTO firstValue (id, page_id, date, \"value\") VALUES (6, 8, 0, 1)");
    +		conn.commit();
    +
    +		ResultSet rs = conn.createStatement().executeQuery(
    +				"SELECT LAST_VALUE(\"value\", date, 2) FROM firstValue GROUP BY page_id");
    --- End diff --
    
    This pull request looks great and I'd really like to pull it in. But I'd still like to see the syntax tweaked to be more standard. It would look like this instead:
    
        SELECT LAST_VALUE(val) WITHIN GROUP (ORDER BY date ASC) FROM firstValue GROUP BY page_id
    
    and the version with the offset argument would be:
    
        SELECT NTH_VALUE(val, 2) WITHIN GROUP (ORDER BY date ASC) FROM firstValue GROUP BY page_id
    
    Everything else would be the same - we already support this syntax in our grammer - you'd define an NTH_VALUE built-in that could be derived from you FIRST_VALUE/LAST_VALUE built-in. This way our syntax is in line with other databases and when we introduce support for PARTITION BY down the road, we can add that syntax without breaking b/w compat.
    
    What do you think, @tzolkincz?



---
If your project is set up for it, you can reply to this email and have your
reply appear on GitHub as well. If your project does not have this feature
enabled and wishes so, or if the feature is enabled but not working, please
contact infrastructure at infrastructure@apache.org or file a JIRA ticket
with INFRA.
---