[BugFix] Fix mv rewrite bugs with IllegalStateException (#63655)
Signed-off-by: shuming.li <ming.moriarty@gmail.com>
This commit is contained in:
parent
fb05bb99a4
commit
7ed48a790a
|
|
@ -1272,6 +1272,10 @@ public class OlapTable extends Table {
|
|||
if (partitionName.startsWith(ExpressionRangePartitionInfo.SHADOW_PARTITION_PREFIX)) {
|
||||
continue;
|
||||
}
|
||||
// ensure partitionName is in nameToPartition
|
||||
if (!nameToPartition.containsKey(partitionName)) {
|
||||
continue;
|
||||
}
|
||||
rangePartitionMap.put(partitionName, rangePartitionInfo.getRange(partitionId));
|
||||
}
|
||||
return rangePartitionMap;
|
||||
|
|
@ -1317,6 +1321,9 @@ public class OlapTable extends Table {
|
|||
if (partitionName.startsWith(ExpressionRangePartitionInfo.SHADOW_PARTITION_PREFIX)) {
|
||||
continue;
|
||||
}
|
||||
if (!nameToPartition.containsKey(partitionName)) {
|
||||
continue;
|
||||
}
|
||||
// one item
|
||||
List<LiteralExpr> literalValues = listPartitionInfo.getLiteralExprValues().get(partitionId);
|
||||
if (CollectionUtils.isNotEmpty(literalValues)) {
|
||||
|
|
|
|||
|
|
@ -187,6 +187,13 @@ public class MVTaskRunProcessor extends BaseTaskRunProcessor implements MVRefres
|
|||
Preconditions.checkState(mv != null);
|
||||
mvMetricsEntity = MaterializedViewMetricsRegistry.getInstance().getMetricsEntity(mv.getMvId());
|
||||
this.taskRunState = retryProcessTaskRun(context);
|
||||
if (this.taskRunState == Constants.TaskRunState.SUCCESS) {
|
||||
logger.info("Refresh materialized view {} finished successfully.", mv.getName());
|
||||
// if success, try to generate next task run
|
||||
mvRefreshProcessor.generateNextTaskRunIfNeeded();
|
||||
} else {
|
||||
logger.warn("Refresh materialized view {} failed with state: {}.", mv.getName(), taskRunState);
|
||||
}
|
||||
// update metrics
|
||||
mvMetricsEntity.increaseRefreshJobStatus(taskRunState);
|
||||
connectContext.getState().setOk();
|
||||
|
|
|
|||
|
|
@ -169,6 +169,11 @@ public abstract class BaseMVRefreshProcessor {
|
|||
protected abstract BaseTableSnapshotInfo buildBaseTableSnapshotInfo(BaseTableInfo baseTableInfo,
|
||||
Table table);
|
||||
|
||||
/**
|
||||
* Generate the next task run to be processed and set it to the nextTaskRun field.
|
||||
*/
|
||||
public abstract void generateNextTaskRunIfNeeded();
|
||||
|
||||
/**
|
||||
* Get the retry times for the mv refresh processor.
|
||||
*
|
||||
|
|
@ -355,9 +360,11 @@ public abstract class BaseMVRefreshProcessor {
|
|||
String partitionName = toRefreshPartitions.partitions().iterator().next().name();
|
||||
Partition partition = mv.getPartition(partitionName);
|
||||
dataProperty = partitionInfo.getDataProperty(partition.getId());
|
||||
}
|
||||
for (PCellWithName partName : toRefreshPartitions.partitions()) {
|
||||
mv.dropPartition(db.getId(), partName.name(), false);
|
||||
mv.dropPartition(db.getId(), partitionName, false);
|
||||
} else {
|
||||
for (PCellWithName partName : toRefreshPartitions.partitions()) {
|
||||
mvRefreshPartitioner.dropPartition(db, mv, partName.name());
|
||||
}
|
||||
}
|
||||
|
||||
// for non-partitioned table, we need to build the partition here
|
||||
|
|
|
|||
|
|
@ -159,11 +159,6 @@ public final class MVPCTBasedRefreshProcessor extends BaseMVRefreshProcessor {
|
|||
updatePCTMeta(mvExecPlan, pctMVToRefreshedPartitions, pctRefTableRefreshPartitions);
|
||||
}
|
||||
|
||||
// do not generate next task run if the current task run is killed
|
||||
if (mvContext.hasNextBatchPartition() && !mvContext.getTaskRun().isKilled()) {
|
||||
generateNextTaskRun();
|
||||
}
|
||||
|
||||
return Constants.TaskRunState.SUCCESS;
|
||||
}
|
||||
|
||||
|
|
@ -248,7 +243,12 @@ public final class MVPCTBasedRefreshProcessor extends BaseMVRefreshProcessor {
|
|||
return insertStmt;
|
||||
}
|
||||
|
||||
private void generateNextTaskRun() {
|
||||
@Override
|
||||
public void generateNextTaskRunIfNeeded() {
|
||||
if (!mvContext.hasNextBatchPartition() || mvContext.getTaskRun().isKilled()) {
|
||||
return;
|
||||
}
|
||||
|
||||
TaskManager taskManager = GlobalStateMgr.getCurrentState().getTaskManager();
|
||||
Map<String, String> properties = mvContext.getProperties();
|
||||
long mvId = Long.parseLong(properties.get(MV_ID));
|
||||
|
|
|
|||
|
|
@ -544,7 +544,7 @@ public abstract class MVPCTRefreshPartitioner {
|
|||
return false;
|
||||
}
|
||||
|
||||
protected void dropPartition(Database db, MaterializedView materializedView, String mvPartitionName) {
|
||||
public void dropPartition(Database db, MaterializedView materializedView, String mvPartitionName) {
|
||||
String dropPartitionName = materializedView.getPartition(mvPartitionName).getName();
|
||||
Locker locker = new Locker();
|
||||
if (!locker.tryLockTableWithIntensiveDbLock(db.getId(), materializedView.getId(), LockType.WRITE,
|
||||
|
|
|
|||
|
|
@ -180,11 +180,6 @@ public class MVIVMBasedMVRefreshProcessor extends BaseMVRefreshProcessor {
|
|||
}
|
||||
}
|
||||
|
||||
// generate the next task run state
|
||||
if (hasNextTaskRun && !mvContext.getTaskRun().isKilled()) {
|
||||
generateNextTaskRun();
|
||||
}
|
||||
|
||||
return Constants.TaskRunState.SUCCESS;
|
||||
}
|
||||
|
||||
|
|
@ -338,7 +333,11 @@ public class MVIVMBasedMVRefreshProcessor extends BaseMVRefreshProcessor {
|
|||
return result;
|
||||
}
|
||||
|
||||
private void generateNextTaskRun() {
|
||||
@Override
|
||||
public void generateNextTaskRunIfNeeded() {
|
||||
if (!hasNextTaskRun || mvContext.getTaskRun().isKilled()) {
|
||||
return;
|
||||
}
|
||||
TaskManager taskManager = GlobalStateMgr.getCurrentState().getTaskManager();
|
||||
Map<String, String> properties = mvContext.getProperties();
|
||||
long mvId = Long.parseLong(properties.get(MV_ID));
|
||||
|
|
|
|||
|
|
@ -14,7 +14,7 @@
|
|||
|
||||
package com.starrocks.sql.common;
|
||||
|
||||
import com.google.common.base.Joiner;
|
||||
import com.starrocks.common.Config;
|
||||
|
||||
import java.util.Iterator;
|
||||
import java.util.List;
|
||||
|
|
@ -123,8 +123,9 @@ public record PCellSortedSet(SortedSet<PCellWithName> partitions) {
|
|||
}
|
||||
SortedSet<PCellWithName> limitedPartitions = new TreeSet<>(partitions);
|
||||
Iterator<PCellWithName> iterator = limitedPartitions.iterator();
|
||||
int removeCount = limitedPartitions.size() - limit;
|
||||
int count = 0;
|
||||
while (iterator.hasNext() && count < limitedPartitions.size() - limit) {
|
||||
while (iterator.hasNext() && count < removeCount) {
|
||||
iterator.next();
|
||||
iterator.remove();
|
||||
count++;
|
||||
|
|
@ -165,7 +166,29 @@ public record PCellSortedSet(SortedSet<PCellWithName> partitions) {
|
|||
if (partitions == null || partitions.isEmpty()) {
|
||||
return "";
|
||||
}
|
||||
return Joiner.on(",").join(getPartitionNames());
|
||||
int maxLen = Config.max_mv_task_run_meta_message_values_length;
|
||||
int size = partitions.size();
|
||||
|
||||
if (size <= maxLen) {
|
||||
// Join all names if under limit
|
||||
return partitions.stream()
|
||||
.map(PCellWithName::name)
|
||||
.collect(Collectors.joining(","));
|
||||
} else {
|
||||
int half = maxLen / 2;
|
||||
List<String> names = partitions.stream()
|
||||
.map(PCellWithName::name)
|
||||
.collect(Collectors.toList());
|
||||
|
||||
String prefix = names.stream()
|
||||
.limit(half)
|
||||
.collect(Collectors.joining(","));
|
||||
String suffix = names.stream()
|
||||
.skip(size - half)
|
||||
.collect(Collectors.joining(","));
|
||||
|
||||
return prefix + ",...," + suffix;
|
||||
}
|
||||
}
|
||||
|
||||
@Override
|
||||
|
|
|
|||
|
|
@ -486,6 +486,8 @@ public final class AggregatedMaterializedViewPushDownRewriter extends Materializ
|
|||
.setPartitionByColumns(groupBys)
|
||||
.build();
|
||||
OptExpression optAggOp = OptExpression.create(newAggOp, optExpression);
|
||||
// derive logical property for newly created agg node
|
||||
MvUtils.deriveLogicalProperty(optAggOp);
|
||||
|
||||
// rewrite by mv.
|
||||
OptExpression rewritten = doRewritePushDownAgg(mvRewriteContext, ctx, optAggOp, rule);
|
||||
|
|
|
|||
|
|
@ -831,7 +831,7 @@ public class MaterializedViewRewriter implements IMaterializedViewRewriter {
|
|||
Map<Integer, ColumnRefSet> tableToJoinColumns = Maps.newHashMap();
|
||||
// first is from left, second is from right
|
||||
List<Pair<ColumnRefOperator, ColumnRefOperator>> joinColumnPairs = Lists.newArrayList();
|
||||
ColumnRefSet leftColumns = queryExpr.inputAt(0).getOutputColumns();
|
||||
ColumnRefSet leftColumns = MvUtils.getOutputColumns(queryExpr.inputAt(0));
|
||||
boolean isSupported = isSupportedPredicate(queryOnPredicate, materializationContext.getQueryRefFactory(),
|
||||
leftColumns, tableToJoinColumns, joinColumnPairs);
|
||||
if (!isSupported) {
|
||||
|
|
@ -1219,7 +1219,7 @@ public class MaterializedViewRewriter implements IMaterializedViewRewriter {
|
|||
private ScalarOperator collectMvPrunePredicate(MaterializationContext mvContext) {
|
||||
final OptExpression mvExpression = mvContext.getMvExpression();
|
||||
final Set<ScalarOperator> conjuncts = MvUtils.getAllValidPredicates(mvExpression);
|
||||
final ColumnRefSet mvOutputColumnRefSet = mvExpression.getOutputColumns();
|
||||
final ColumnRefSet mvOutputColumnRefSet = MvUtils.getOutputColumns(mvExpression);
|
||||
// conjuncts related to partition and distribution
|
||||
final List<ScalarOperator> mvPrunePredicates = Lists.newArrayList();
|
||||
|
||||
|
|
@ -1739,7 +1739,7 @@ public class MaterializedViewRewriter implements IMaterializedViewRewriter {
|
|||
.orElse(new ColumnRefSet());
|
||||
|
||||
ColumnRefSet queryOutputColumnRefs = unionRewriteMode.isPullPredicateRewriteV2() ?
|
||||
rewriteContext.getQueryExpression().getOutputColumns() : null;
|
||||
MvUtils.getOutputColumns(rewriteContext.getQueryExpression()) : null;
|
||||
Set<ScalarOperator> queryExtraPredicates = queryPredicates.stream()
|
||||
.filter(pred -> isPullUpQueryPredicate(pred, mvPredicateUsedColRefs,
|
||||
queryOnPredicateUsedColRefs, queryOutputColumnRefs))
|
||||
|
|
@ -1751,7 +1751,7 @@ public class MaterializedViewRewriter implements IMaterializedViewRewriter {
|
|||
final ScalarOperator queryExtraPredicate = Utils.compoundAnd(queryExtraPredicates);
|
||||
|
||||
// query's output should contain all the extra predicates otherwise it cannot be pulled then.
|
||||
ColumnRefSet queryOutputColumnSet = rewriteContext.getQueryExpression().getOutputColumns();
|
||||
ColumnRefSet queryOutputColumnSet = MvUtils.getOutputColumns(rewriteContext.getQueryExpression());
|
||||
if (!queryOutputColumnSet.containsAll(queryExtraPredicate.getUsedColumns())) {
|
||||
return null;
|
||||
}
|
||||
|
|
@ -2059,7 +2059,8 @@ public class MaterializedViewRewriter implements IMaterializedViewRewriter {
|
|||
.filter(entry -> !enforcedNonExistedColumns.contains(entry.getKey()))
|
||||
.forEach(entry -> newColumnRefMap.put(entry.getKey(), entry.getValue()));
|
||||
} else {
|
||||
queryExpr.getOutputColumns().getColumnRefOperators(materializationContext.getQueryRefFactory())
|
||||
MvUtils.getOutputColumns(queryExpr)
|
||||
.getColumnRefOperators(materializationContext.getQueryRefFactory())
|
||||
.stream()
|
||||
.filter(column -> !enforcedNonExistedColumns.contains(column))
|
||||
.forEach(column -> newColumnRefMap.put(column, column));
|
||||
|
|
|
|||
|
|
@ -1722,4 +1722,15 @@ public class MvUtils {
|
|||
}
|
||||
return input.length() > maxLength ? input.substring(0, maxLength) : input;
|
||||
}
|
||||
|
||||
/**
|
||||
* Ensure the logical property of the given opt expression is derived, and return its output columns.
|
||||
* Ensure optExpression has derived logical property, otherwise OptExpression.getOutputColumns will fail.
|
||||
*/
|
||||
public static ColumnRefSet getOutputColumns(OptExpression optExpression) {
|
||||
if (optExpression.getLogicalProperty() == null) {
|
||||
deriveLogicalProperty(optExpression);
|
||||
}
|
||||
return optExpression.getOutputColumns();
|
||||
}
|
||||
}
|
||||
|
|
@ -0,0 +1,213 @@
|
|||
// Copyright 2021-present StarRocks, Inc. All rights reserved.
|
||||
//
|
||||
// Licensed 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
|
||||
//
|
||||
// https://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 com.starrocks.sql.common;
|
||||
|
||||
import com.google.common.collect.ImmutableList;
|
||||
import com.google.common.collect.Range;
|
||||
import com.starrocks.catalog.PartitionKey;
|
||||
import com.starrocks.catalog.PrimitiveType;
|
||||
import com.starrocks.sql.ast.expression.DateLiteral;
|
||||
import com.starrocks.sql.ast.expression.IntLiteral;
|
||||
import com.starrocks.sql.optimizer.rule.transformation.materialization.MVTestBase;
|
||||
import org.junit.jupiter.api.Assertions;
|
||||
import org.junit.jupiter.api.Test;
|
||||
|
||||
import java.util.Collections;
|
||||
|
||||
public class PCellSortedSetTest extends MVTestBase {
|
||||
private static final PartitionKey PARTITION_KEY11 = new PartitionKey(
|
||||
ImmutableList.of(new DateLiteral(1998, 1, 1)),
|
||||
ImmutableList.of(PrimitiveType.DATE));
|
||||
private static final PartitionKey PARTITION_KEY12 = new PartitionKey(
|
||||
ImmutableList.of(new DateLiteral(1999, 1, 1)),
|
||||
ImmutableList.of(PrimitiveType.DATE));
|
||||
private static final Range<PartitionKey> RANGE1 = Range.closed(PARTITION_KEY11, PARTITION_KEY12);
|
||||
|
||||
private static final PartitionKey PARTITION_KEY21 = new PartitionKey(
|
||||
ImmutableList.of(new DateLiteral(1999, 1, 1)),
|
||||
ImmutableList.of(PrimitiveType.DATE));
|
||||
private static final PartitionKey PARTITION_KEY22 = new PartitionKey(
|
||||
ImmutableList.of(new DateLiteral(2000, 1, 1)),
|
||||
ImmutableList.of(PrimitiveType.DATE));
|
||||
private static final Range<PartitionKey> RANGE2 = Range.closed(PARTITION_KEY21, PARTITION_KEY22);
|
||||
|
||||
@Test
|
||||
public void testAddAndContainsWithPListCell() {
|
||||
PCellSortedSet set = PCellSortedSet.of();
|
||||
PListCell cell1 = new PListCell("1");
|
||||
PListCell cell2 = new PListCell("2");
|
||||
PCellWithName p1 = PCellWithName.of("p1", cell1);
|
||||
PCellWithName p2 = PCellWithName.of("p2", cell2);
|
||||
|
||||
set.add(p1);
|
||||
set.add(p2);
|
||||
|
||||
Assertions.assertTrue(set.contains(p1));
|
||||
Assertions.assertTrue(set.contains(p2));
|
||||
Assertions.assertEquals(2, set.size());
|
||||
}
|
||||
|
||||
@Test
|
||||
public void testAddAndRemoveWithPRangeCell() {
|
||||
PCellSortedSet set = PCellSortedSet.of();
|
||||
PRangeCell cell1 = new PRangeCell(RANGE1);
|
||||
PRangeCell cell2 = new PRangeCell(RANGE2);
|
||||
PCellWithName p1 = PCellWithName.of("range1", cell1);
|
||||
PCellWithName p2 = PCellWithName.of("range2", cell2);
|
||||
|
||||
set.add(p1);
|
||||
set.add(p2);
|
||||
|
||||
Assertions.assertTrue(set.contains(p1));
|
||||
Assertions.assertTrue(set.contains(p2));
|
||||
Assertions.assertEquals(2, set.size());
|
||||
|
||||
set.remove(p1);
|
||||
Assertions.assertFalse(set.contains(p1));
|
||||
Assertions.assertTrue(set.contains(p2));
|
||||
Assertions.assertEquals(1, set.size());
|
||||
}
|
||||
|
||||
@Test
|
||||
public void testLimitAndSkip() {
|
||||
PCellSortedSet set = PCellSortedSet.of();
|
||||
for (int i = 0; i < 5; i++) {
|
||||
set.add(PCellWithName.of("p" + i, new PListCell(String.valueOf(i))));
|
||||
}
|
||||
PCellSortedSet limited = set.limit(2);
|
||||
Assertions.assertEquals(2, limited.size());
|
||||
Assertions.assertTrue(limited.getPartitionNames().contains("p3"));
|
||||
Assertions.assertTrue(limited.getPartitionNames().contains("p4"));
|
||||
|
||||
PCellSortedSet skipped = set.skip(3);
|
||||
Assertions.assertEquals(2, skipped.size());
|
||||
Assertions.assertTrue(skipped.getPartitionNames().contains("p3"));
|
||||
Assertions.assertTrue(skipped.getPartitionNames().contains("p4"));
|
||||
}
|
||||
|
||||
private Range<PartitionKey> createRange(int start, int end) {
|
||||
PartitionKey startKey = new PartitionKey(
|
||||
Collections.singletonList(new IntLiteral(start)),
|
||||
Collections.singletonList(PrimitiveType.INT));
|
||||
PartitionKey endKey = new PartitionKey(
|
||||
Collections.singletonList(new IntLiteral(end)),
|
||||
Collections.singletonList(PrimitiveType.INT));
|
||||
return Range.closed(startKey, endKey);
|
||||
}
|
||||
|
||||
@Test
|
||||
public void testToStringCompaction() {
|
||||
PCellSortedSet set = PCellSortedSet.of();
|
||||
for (int i = 1; i <= 5; i++) {
|
||||
set.add(PCellWithName.of("p" + i, new PRangeCell(createRange(i, i + 10))));
|
||||
}
|
||||
String str = set.toString();
|
||||
// Should compact to something like "p1~p5" if compaction logic is correct
|
||||
Assertions.assertTrue(str.contains("p1") && str.contains("p5"));
|
||||
}
|
||||
|
||||
@Test
|
||||
public void testToStringWithOnlyPListCell() {
|
||||
PCellSortedSet set = PCellSortedSet.of();
|
||||
set.add(PCellWithName.of("l1", new PListCell("a")));
|
||||
set.add(PCellWithName.of("l2", new PListCell("b")));
|
||||
set.add(PCellWithName.of("l3", new PListCell("c")));
|
||||
|
||||
String str = set.toString();
|
||||
|
||||
System.out.println(str);
|
||||
// Should list all names, no compaction for non-numeric suffixes
|
||||
Assertions.assertTrue(str.contains("l1"));
|
||||
Assertions.assertTrue(str.contains("l2"));
|
||||
Assertions.assertTrue(str.contains("l3"));
|
||||
}
|
||||
|
||||
@Test
|
||||
public void testToStringEmptySet() {
|
||||
PCellSortedSet set = PCellSortedSet.of();
|
||||
String str = set.toString();
|
||||
Assertions.assertEquals("", str);
|
||||
}
|
||||
|
||||
@Test
|
||||
public void testToStringWithMaxLenLimit() {
|
||||
// Set up a set with more elements than max_mv_task_run_meta_message_values_length
|
||||
int maxLen = 4; // Simulate a small config for test
|
||||
int originalMaxLen = com.starrocks.common.Config.max_mv_task_run_meta_message_values_length;
|
||||
com.starrocks.common.Config.max_mv_task_run_meta_message_values_length = maxLen;
|
||||
try {
|
||||
PCellSortedSet set = PCellSortedSet.of();
|
||||
for (int i = 1; i <= 10; i++) {
|
||||
set.add(PCellWithName.of("p" + i, new PRangeCell(createRange(i, i + 1))));
|
||||
}
|
||||
String str = set.toString();
|
||||
// Should contain prefix, ..., and suffix
|
||||
Assertions.assertTrue(str.contains("..."), "String should contain ellipsis for compaction");
|
||||
// Should contain first maxLen/2 and last maxLen/2 names
|
||||
int half = maxLen / 2;
|
||||
for (int i = 1; i <= half; i++) {
|
||||
Assertions.assertTrue(str.contains("p" + i), "Should contain prefix p" + i);
|
||||
}
|
||||
for (int i = 10 - half + 1; i <= 10; i++) {
|
||||
Assertions.assertTrue(str.contains("p" + i), "Should contain suffix p" + i);
|
||||
}
|
||||
} finally {
|
||||
com.starrocks.common.Config.max_mv_task_run_meta_message_values_length = originalMaxLen;
|
||||
}
|
||||
}
|
||||
|
||||
@Test
|
||||
public void testToStringWithExactlyMaxLen() {
|
||||
int maxLen = 6;
|
||||
int originalMaxLen = com.starrocks.common.Config.max_mv_task_run_meta_message_values_length;
|
||||
com.starrocks.common.Config.max_mv_task_run_meta_message_values_length = maxLen;
|
||||
try {
|
||||
PCellSortedSet set = PCellSortedSet.of();
|
||||
for (int i = 1; i <= maxLen; i++) {
|
||||
set.add(PCellWithName.of("p" + i, new PRangeCell(createRange(i, i + 1))));
|
||||
}
|
||||
String str = set.toString();
|
||||
// Should not contain ellipsis, should list all names
|
||||
Assertions.assertFalse(str.contains("..."));
|
||||
for (int i = 1; i <= maxLen; i++) {
|
||||
Assertions.assertTrue(str.contains("p" + i));
|
||||
}
|
||||
} finally {
|
||||
com.starrocks.common.Config.max_mv_task_run_meta_message_values_length = originalMaxLen;
|
||||
}
|
||||
}
|
||||
|
||||
@Test
|
||||
public void testToStringWithSingleElement() {
|
||||
PCellSortedSet set = PCellSortedSet.of();
|
||||
set.add(PCellWithName.of("single", new PRangeCell(createRange(1, 2))));
|
||||
String str = set.toString();
|
||||
Assertions.assertEquals("single", str);
|
||||
}
|
||||
|
||||
@Test
|
||||
public void testToStringWithNonNumericNames() {
|
||||
PCellSortedSet set = PCellSortedSet.of();
|
||||
set.add(PCellWithName.of("alpha", new PListCell("a")));
|
||||
set.add(PCellWithName.of("beta", new PListCell("b")));
|
||||
set.add(PCellWithName.of("gamma", new PListCell("c")));
|
||||
String str = set.toString();
|
||||
// Should list all names, no compaction for non-numeric
|
||||
Assertions.assertTrue(str.contains("alpha"));
|
||||
Assertions.assertTrue(str.contains("beta"));
|
||||
Assertions.assertTrue(str.contains("gamma"));
|
||||
Assertions.assertFalse(str.contains("..."));
|
||||
}
|
||||
}
|
||||
|
|
@ -0,0 +1,244 @@
|
|||
-- name: test_mv_rewrite_bugfix2
|
||||
create database db_${uuid0};
|
||||
-- result:
|
||||
-- !result
|
||||
use db_${uuid0};
|
||||
-- result:
|
||||
-- !result
|
||||
CREATE TABLE `dim_region` (
|
||||
`region_id` bigint(20) NULL COMMENT "",
|
||||
`region_name` varchar(255) NULL COMMENT "",
|
||||
`region_level` varchar(64) NULL COMMENT "",
|
||||
`region_order` bigint(20) NULL COMMENT "",
|
||||
`country_id` bigint(20) NULL COMMENT "",
|
||||
`city_id` bigint(20) NULL COMMENT "",
|
||||
`city_name` varchar(255) NULL COMMENT "",
|
||||
`region_type` varchar(64) NULL COMMENT "",
|
||||
`region_code` varchar(64) NULL COMMENT "",
|
||||
`purpose` varchar(64) NULL COMMENT "",
|
||||
`parent_country` varchar(255) NULL COMMENT "",
|
||||
`parent_territory` varchar(255) NULL COMMENT "",
|
||||
`parent_region` varchar(255) NULL COMMENT "",
|
||||
`parent_city` varchar(255) NULL COMMENT "",
|
||||
`parent_subregion` varchar(255) NULL COMMENT "",
|
||||
`parent_district` varchar(255) NULL COMMENT "",
|
||||
`parent_area` varchar(255) NULL COMMENT "",
|
||||
`geohash_array` array<varchar(64)> NULL COMMENT "",
|
||||
`area_id_array` array<int(11)> NULL COMMENT ""
|
||||
) ENGINE=OLAP
|
||||
DUPLICATE KEY(`region_id`, `region_name`)
|
||||
COMMENT "OLAP"
|
||||
DISTRIBUTED BY RANDOM BUCKETS 1
|
||||
PROPERTIES (
|
||||
"replication_num" = "1"
|
||||
);
|
||||
-- result:
|
||||
-- !result
|
||||
CREATE TABLE `fact_orders` (
|
||||
`city_id` int(11) NULL COMMENT "",
|
||||
`country_id` int(11) NULL COMMENT "",
|
||||
`group_id` varchar(4) NULL COMMENT "",
|
||||
`vehicle_group` varchar(64) NULL COMMENT "",
|
||||
`vehicle_type` varchar(64) NULL COMMENT "",
|
||||
`wheels` varchar(2) NULL COMMENT "",
|
||||
`vehicle_id` bigint(20) NULL COMMENT "",
|
||||
`geohash` varchar(64) NULL COMMENT "",
|
||||
`base_surge` double NULL COMMENT "",
|
||||
`order_code` varchar(64) NULL COMMENT "",
|
||||
`total_amount` double NULL COMMENT "",
|
||||
`distance_km` double NULL COMMENT "",
|
||||
`order_time` datetime NULL COMMENT "",
|
||||
`surge` double NULL COMMENT "",
|
||||
`total_amount_usd` double NULL COMMENT "",
|
||||
`date_id` int(11) NULL COMMENT "",
|
||||
`series_id` varchar(64) NULL COMMENT "",
|
||||
`order_status` varchar(64) NULL COMMENT "",
|
||||
`local_time` datetime NULL COMMENT "",
|
||||
`local_date` datetime NULL COMMENT ""
|
||||
) ENGINE=OLAP
|
||||
DUPLICATE KEY(`city_id`, `country_id`, `group_id`)
|
||||
COMMENT "OLAP"
|
||||
PARTITION BY RANGE(`date_id`)
|
||||
(PARTITION p20230601 VALUES [("20230601"), ("20230602")),
|
||||
PARTITION p20230602 VALUES [("20230602"), ("20230603")),
|
||||
PARTITION p20230603 VALUES [("20230603"), ("20230604")),
|
||||
PARTITION p20230604 VALUES [("20230604"), ("20230605")),
|
||||
PARTITION p20230605 VALUES [("20230605"), ("20230606")),
|
||||
PARTITION p20230606 VALUES [("20230606"), ("20230607")),
|
||||
PARTITION p20230607 VALUES [("20230607"), ("20230608")),
|
||||
PARTITION p20230608 VALUES [("20230608"), ("20230609")),
|
||||
PARTITION p20230609 VALUES [("20230609"), ("20230610")),
|
||||
PARTITION p20230610 VALUES [("20230610"), ("20230611")),
|
||||
PARTITION p20230611 VALUES [("20230611"), ("20230612")),
|
||||
PARTITION p20230612 VALUES [("20230612"), ("20230613")),
|
||||
PARTITION p20230613 VALUES [("20230613"), ("20230614")),
|
||||
PARTITION p20230614 VALUES [("20230614"), ("20230615")),
|
||||
PARTITION p20230615 VALUES [("20230615"), ("20230616")),
|
||||
PARTITION p20230616 VALUES [("20230616"), ("20230617")),
|
||||
PARTITION p20230617 VALUES [("20230617"), ("20230618")),
|
||||
PARTITION p20230618 VALUES [("20230618"), ("20230619")),
|
||||
PARTITION p20230619 VALUES [("20230619"), ("20230620")),
|
||||
PARTITION p20230620 VALUES [("20230620"), ("20230621")),
|
||||
PARTITION p20230621 VALUES [("20230621"), ("20230622")),
|
||||
PARTITION p20230622 VALUES [("20230622"), ("20230623")),
|
||||
PARTITION p20230623 VALUES [("20230623"), ("20230624")),
|
||||
PARTITION p20230624 VALUES [("20230624"), ("20230625")),
|
||||
PARTITION p20230625 VALUES [("20230625"), ("20230626")),
|
||||
PARTITION p20230626 VALUES [("20230626"), ("20230627")),
|
||||
PARTITION p20230627 VALUES [("20230627"), ("20230628")),
|
||||
PARTITION p20230628 VALUES [("20230628"), ("20230629")),
|
||||
PARTITION p20230629 VALUES [("20230629"), ("20230630")),
|
||||
PARTITION p20230630 VALUES [("20230630"), ("20230701")))
|
||||
DISTRIBUTED BY HASH(`order_time`) BUCKETS 8
|
||||
PROPERTIES (
|
||||
"replication_num" = "1"
|
||||
);
|
||||
-- result:
|
||||
-- !result
|
||||
INSERT INTO fact_orders VALUES
|
||||
(6, 4, 'G1', 'Premium', 'Luxury', '4', 16866, 'w21g8', 1.5, 'ORD001', 25.00, 5.0, '2025-08-25 09:15:00', 1.2, 25.00, 20230625, 'S001', 'booked', '2025-08-25 09:00:00', '2025-08-25 00:00:00'),
|
||||
(6, 4, 'G2', 'Standard', 'Compact', '4', 15829, 'w21g9', 1.0, 'ORD002', 12.50, 4.0, '2025-08-26 14:30:00', 1.0, 12.50, 20230626, 'S002', 'booked', '2025-08-26 14:00:00', '2025-08-26 00:00:00'),
|
||||
(6, 4, 'G3', 'Premium', 'SUV', '4', 15272, 'w21g7', 1.8, 'ORD003', 30.00, 7.5, '2025-08-27 18:45:00', 1.5, 30.00, 20230627, 'S003', 'booked', '2025-08-27 18:00:00', '2025-08-27 00:00:00'),
|
||||
(6, 4, 'G4', 'Economy', 'Hatchback', '4', 10495, 'w21g6', 0.8, 'ORD004', 9.60, 3.2, '2025-08-28 11:20:00', 0.9, 9.60, 20230628, 'S004', 'booked', '2025-08-28 11:00:00', '2025-08-28 00:00:00'),
|
||||
(6, 4, 'G5', 'Motorcycle', 'Bike', '2', 462, 'w21g5', 0.5, 'ORD005', 5.25, 2.1, '2025-08-29 16:10:00', 0.6, 5.25, 20230629, 'S005', 'booked', '2025-08-29 16:00:00', '2025-08-29 00:00:00');
|
||||
-- result:
|
||||
-- !result
|
||||
INSERT INTO dim_region VALUES
|
||||
(101, 'Central Subregion', 'Subregion', 1, 1, 6, 'Metro City', 'Urban', 'REG101', 'Generic', 'Country', 'Territory', 'Region', 'City', 'Central Subregion', NULL, NULL, ['w21g8'], NULL),
|
||||
(102, 'Downtown District', 'District', 2, 1, 6, 'Metro City', 'Urban', 'REG102', 'Generic', 'Country', 'Territory', 'Region', 'City', NULL, 'Downtown District', NULL, ['w21g9'], NULL),
|
||||
(103, 'Market Area', 'Area', 3, 1, 6, 'Metro City', 'Commercial', 'REG103', 'Generic', 'Country', 'Territory', 'Region', 'City', NULL, NULL, 'Market Area', ['w21g7'], NULL),
|
||||
(104, 'North Subregion', 'Subregion', 4, 1, 6, 'Metro City', 'Residential', 'REG104', 'Generic', 'Country', 'Territory', 'Region', 'City', 'North Subregion', NULL, NULL, ['w21g6', 'w21g5', 'w21g4'], NULL),
|
||||
(105, 'Special Zone', 'Subregion', 5, 1, 6, 'Metro City', 'Special', 'REG105', 'Special', 'Country', 'Territory', 'Region', 'City', 'Special Zone', NULL, NULL, ['w21g3'], NULL),
|
||||
(1, 'Downtown', 'City', 1, 1, 101, 'Metropolis', 'Urban', 'REG001', 'Commercial', 'CountryA', 'TerritoryX', 'RegionY', 'Metropolis', 'Central', 'Downtown', 'CBD', ['geohash1', 'geohash2'], [1001, 1002]),
|
||||
(2, 'Tech Park', 'District', 2, 1, 101, 'Metropolis', 'Suburban', 'REG002', 'Industrial', 'CountryA', 'TerritoryX', 'RegionY', 'Metropolis', 'East', 'Tech Zone', 'Innovation Park', ['geohash3', 'geohash4'], [2001, 2002]),
|
||||
(3, 'Beachside', 'Subregion', 3, 1, 102, 'Coastal City', 'Resort', 'REG003', 'Tourism', 'CountryA', 'TerritoryX', 'RegionZ', 'Coastal City', 'South', 'Beach District', 'Seaside', ['geohash5', 'geohash6'], [3001, 3002]),
|
||||
(4, 'Mountain View', 'Region', 4, 1, 103, 'Hill Town', 'Rural', 'REG004', 'Residential', 'CountryA', 'TerritoryY', 'RegionW', 'Hill Town', 'North', 'Highland', 'Scenic Area', ['geohash7', 'geohash8'], [4001, 4002]),
|
||||
(5, 'Old Town', 'Area', 5, 2, 201, 'Historic City', 'Heritage', 'REG005', 'Cultural', 'CountryB', 'TerritoryZ', 'RegionV', 'Historic City', 'Center', 'Heritage Zone', 'Ancient Quarter', ['geohash9', 'geohash10'], [5001, 5002]);
|
||||
-- result:
|
||||
-- !result
|
||||
INSERT INTO fact_orders VALUES
|
||||
(101, 1, 'G1', 'Standard', 'Sedan', '4', 1001, 'ws8g', 1.2, 'ORD006', 15.50, 5.3, '2023-10-15 08:30:45', 1.1, 15.50, 20230615, 'S006', 'completed', '2023-10-15 08:00:00', '2023-10-15 00:00:00'),
|
||||
(101, 1, 'G2', 'Premium', 'SUV', '4', 1002, 'ws8h', 1.5, 'ORD007', 25.75, 7.8, '2023-10-15 09:15:22', 1.3, 25.75, 20230615, 'S007', 'completed', '2023-10-15 09:00:00', '2023-10-15 00:00:00'),
|
||||
(102, 1, 'G3', 'Motorcycle', 'Bike', '2', 2001, 'ws9j', 1.0, 'ORD008', 8.20, 3.1, '2023-10-16 14:45:10', 1.0, 8.20, 20230616, 'S008', 'cancelled', '2023-10-16 14:00:00', '2023-10-16 00:00:00'),
|
||||
(103, 2, 'G4', 'Delivery', 'Truck', '6', 3001, 'ws7k', 1.8, 'ORD009', 45.90, 12.5, '2023-10-17 11:20:33', 1.6, 45.90, 20230617, 'S009', 'completed', '2023-10-17 11:00:00', '2023-10-17 00:00:00'),
|
||||
(101, 1, 'G1', 'Pool', 'Compact', '4', 1003, 'ws8m', 0.9, 'ORD010', 10.25, 4.2, '2023-10-18 17:55:18', 0.8, 10.25, 20230618, 'S010', 'completed', '2023-10-18 17:00:00', '2023-10-18 00:00:00');
|
||||
-- result:
|
||||
-- !result
|
||||
CREATE MATERIALIZED VIEW `mv_region_geohash`
|
||||
DISTRIBUTED BY RANDOM BUCKETS 1
|
||||
REFRESH ASYNC EVERY(INTERVAL 6 HOUR)
|
||||
PROPERTIES (
|
||||
"replication_num" = "1")
|
||||
AS SELECT `t2`.`geohash`,
|
||||
max(CASE WHEN (`t2`.`region_level` = 'Subregion') THEN `t2`.`region_id` ELSE NULL END) AS `subregion_id`,
|
||||
max(CASE WHEN (`t2`.`region_level` = 'Subregion') THEN `t2`.`region_name` ELSE NULL END) AS `subregion_name`,
|
||||
max(CASE WHEN (`t2`.`region_level` = 'District') THEN `t2`.`region_id` ELSE NULL END) AS `district_id`,
|
||||
max(CASE WHEN (`t2`.`region_level` = 'District') THEN `t2`.`region_name` ELSE NULL END) AS `district_name`,
|
||||
max(CASE WHEN (`t2`.`region_level` = 'Area') THEN `t2`.`region_id` ELSE NULL END) AS `area_id`,
|
||||
max(CASE WHEN (`t2`.`region_level` = 'Area') THEN `t2`.`region_name` ELSE NULL END) AS `area_name`
|
||||
FROM (
|
||||
SELECT `dim_region`.`city_id`, `dim_region`.`region_level`, `dim_region`.`region_id`, `dim_region`.`region_name`, `dim_region`.`purpose`, `t0`.`geohash`
|
||||
FROM `dim_region` AS `dim_region`
|
||||
CROSS JOIN LATERAL unnest(`dim_region`.`geohash_array`) t0(`geohash`)
|
||||
WHERE `dim_region`.`region_level` IN ('Subregion', 'District', 'Area')
|
||||
) `t2`
|
||||
WHERE `t2`.`purpose` = 'Generic'
|
||||
GROUP BY `t2`.`geohash`;
|
||||
-- result:
|
||||
-- !result
|
||||
CREATE MATERIALIZED VIEW `mv_fact_orders_1`
|
||||
PARTITION BY (`date_id`)
|
||||
DISTRIBUTED BY HASH(`geohash`)
|
||||
ORDER BY (vehicle_id)
|
||||
REFRESH ASYNC
|
||||
PROPERTIES (
|
||||
"replication_num" = "1",
|
||||
"query_rewrite_consistency" = "loose"
|
||||
)
|
||||
AS SELECT date_trunc('day', `fact_orders`.`local_time`) AS `local_time_day`,
|
||||
date_trunc('hour', `fact_orders`.`local_time`) AS `local_time_hour`,
|
||||
`fact_orders`.`geohash`, `fact_orders`.`date_id`, `fact_orders`.`city_id`, `fact_orders`.`country_id`,
|
||||
`fact_orders`.`vehicle_id`, `fact_orders`.`wheels`, `fact_orders`.`vehicle_type`, `fact_orders`.`vehicle_group`,
|
||||
`fact_orders`.`order_status`,
|
||||
sum(`fact_orders`.`total_amount_usd`) AS `sum_total_amount_usd`,
|
||||
sum(`fact_orders`.`total_amount`) AS `sum_total_amount`,
|
||||
sum(`fact_orders`.`distance_km`) AS `sum_distance_km`,
|
||||
sum(`fact_orders`.`surge`) AS `sum_surge`,
|
||||
count(`fact_orders`.`surge`) AS `count_surge`
|
||||
FROM `fact_orders`
|
||||
WHERE `fact_orders`.`order_code` != ''
|
||||
GROUP BY 1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11;
|
||||
-- result:
|
||||
-- !result
|
||||
CREATE MATERIALIZED VIEW `mv_fact_orders_2`
|
||||
PARTITION BY (`date_id`)
|
||||
DISTRIBUTED BY HASH(`geohash`)
|
||||
ORDER BY (country_id)
|
||||
REFRESH ASYNC
|
||||
PROPERTIES (
|
||||
"replication_num" = "1",
|
||||
"query_rewrite_consistency" = "loose")
|
||||
AS SELECT date_trunc('day', `fact_orders`.`order_time`) AS `order_time_day`,
|
||||
date_trunc('hour', `fact_orders`.`order_time`) AS `order_time_hour`,
|
||||
date_trunc('hour', `fact_orders`.`local_time`) AS `local_time_hour`,
|
||||
date_trunc('day', `fact_orders`.`local_time`) AS `local_time_day`,
|
||||
`fact_orders`.`geohash`, `fact_orders`.`date_id`, `fact_orders`.`city_id`, `fact_orders`.`country_id`,
|
||||
`fact_orders`.`vehicle_id`, `fact_orders`.`wheels`, `fact_orders`.`vehicle_type`, `fact_orders`.`vehicle_group`,
|
||||
`fact_orders`.`order_status`,
|
||||
sum(`fact_orders`.`total_amount_usd`) AS `sum_total_amount_usd`,
|
||||
sum(`fact_orders`.`total_amount`) AS `sum_total_amount`,
|
||||
sum(`fact_orders`.`distance_km`) AS `sum_distance_km`,
|
||||
sum(`fact_orders`.`surge`) AS `sum_surge`,
|
||||
count(`fact_orders`.`surge`) AS `count_surge`
|
||||
FROM `fact_orders`
|
||||
WHERE `fact_orders`.`order_code` = ''
|
||||
GROUP BY 1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12, 13;
|
||||
-- result:
|
||||
-- !result
|
||||
REFRESH MATERIALIZED VIEW mv_fact_orders_1 FORCE WITH SYNC MODE;
|
||||
REFRESH MATERIALIZED VIEW mv_fact_orders_2 FORCE WITH SYNC MODE;
|
||||
REFRESH MATERIALIZED VIEW mv_region_geohash FORCE WITH SYNC MODE;
|
||||
SELECT subregion_name, CAST(SUM(total_amount) AS DOUBLE) / CAST(SUM(distance_km) AS DOUBLE) AS avg_fare_per_km FROM fact_orders AS f LEFT JOIN mv_region_geohash AS r ON CAST(r.geohash AS varchar)= CAST(f.geohash AS varchar) WHERE DATE_TRUNC('day', local_time) >= DATE_TRUNC('hour', STR_TO_DATE('2025-08-25 00:00:00', '%Y-%m-%d %H:%i:%S')) AND DATE_TRUNC('day', local_time) < DATE_TRUNC('hour', STR_TO_DATE('2025-09-01 00:00:00', '%Y-%m-%d %H:%i:%S')) AND date_id >= 20230623 AND date_id < 20250903 AND (country_id = 4 and city_id in (6) and vehicle_id in (16866, 16860, 16859, 16810, 15829, 15828, 15827, 15826, 15825, 15824, 15817, 15816, 15568, 15272, 15271, 15270, 15269, 15268, 15267, 15266, 15265, 13912, 13904, 13806, 13805, 13804, 13803, 13802, 13801, 13800, 13799, 13456, 13341, 12138, 11770, 11655, 11631, 10742, 10540, 10500, 10499, 10498, 10496, 10495, 10494, 10493, 10492, 10491, 10490, 10489, 10488, 10487, 10486, 10485, 10484, 10479, 9979, 9450, 9338, 8920, 8522, 8183, 7387, 6709, 6705, 4894, 4152, 4131, 3455, 2792, 2742, 2275, 462, 302, 187, 156, 69, 21, 20, 19, 11) and (order_code != '' and order_status = 'booked')) GROUP BY 1 ORDER BY 1 LIMIT 3;
|
||||
-- result:
|
||||
None 3.6956521739130435
|
||||
Central Subregion 5.0
|
||||
North Subregion 2.8018867924528297
|
||||
-- !result
|
||||
function: print_hit_materialized_views("SELECT subregion_name, CAST(SUM(total_amount) AS DOUBLE) / CAST(SUM(distance_km) AS DOUBLE) AS avg_fare_per_km FROM fact_orders AS f LEFT JOIN mv_region_geohash AS r ON CAST(r.geohash AS varchar)= CAST(f.geohash AS varchar) WHERE DATE_TRUNC('day', local_time) >= DATE_TRUNC('hour', STR_TO_DATE('2025-08-25 00:00:00', '%Y-%m-%d %H:%i:%S')) AND DATE_TRUNC('day', local_time) < DATE_TRUNC('hour', STR_TO_DATE('2025-09-01 00:00:00', '%Y-%m-%d %H:%i:%S')) AND date_id >= 20230623 AND date_id < 20250903 AND (country_id = 4 and city_id in (6) and vehicle_id in (16866, 16860, 16859, 16810, 15829, 15828, 15827, 15826, 15825, 15824, 15817, 15816, 15568, 15272, 15271, 15270, 15269, 15268, 15267, 15266, 15265, 13912, 13904, 13806, 13805, 13804, 13803, 13802, 13801, 13800, 13799, 13456, 13341, 12138, 11770, 11655, 11631, 10742, 10540, 10500, 10499, 10498, 10496, 10495, 10494, 10493, 10492, 10491, 10490, 10489, 10488, 10487, 10486, 10485, 10484, 10479, 9979, 9450, 9338, 8920, 8522, 8183, 7387, 6709, 6705, 4894, 4152, 4131, 3455, 2792, 2742, 2275, 462, 302, 187, 156, 69, 21, 20, 19, 11) and (order_code != '' and order_status = 'booked')) GROUP BY 1 LIMIT 10001;")
|
||||
-- result:
|
||||
mv_region_geohash,mv_fact_orders_1
|
||||
-- !result
|
||||
INSERT INTO dim_region VALUES
|
||||
(4, 'Mountain View', 'Region', 4, 1, 103, 'Hill Town', 'Rural', 'REG004', 'Residential', 'CountryA', 'TerritoryY', 'RegionW', 'Hill Town', 'North', 'Highland', 'Scenic Area', ['geohash7', 'geohash8'], [4001, 4002]);
|
||||
-- result:
|
||||
-- !result
|
||||
INSERT INTO fact_orders VALUES
|
||||
(101, 1, 'G1', 'Standard', 'Sedan', '4', 1001, 'ws8g', 1.2, 'ORD006', 15.50, 5.3, '2023-10-15 08:30:45', 1.1, 15.50, 20230615, 'S006', 'completed', '2023-10-15 08:00:00', '2023-10-15 00:00:00');
|
||||
-- result:
|
||||
-- !result
|
||||
SELECT subregion_name, CAST(SUM(total_amount) AS DOUBLE) / CAST(SUM(distance_km) AS DOUBLE) AS avg_fare_per_km FROM fact_orders AS f LEFT JOIN mv_region_geohash AS r ON CAST(r.geohash AS varchar)= CAST(f.geohash AS varchar) WHERE DATE_TRUNC('day', local_time) >= DATE_TRUNC('hour', STR_TO_DATE('2025-08-25 00:00:00', '%Y-%m-%d %H:%i:%S')) AND DATE_TRUNC('day', local_time) < DATE_TRUNC('hour', STR_TO_DATE('2025-09-01 00:00:00', '%Y-%m-%d %H:%i:%S')) AND date_id >= 20230623 AND date_id < 20250903 AND (country_id = 4 and city_id in (6) and vehicle_id in (16866, 16860, 16859, 16810, 15829, 15828, 15827, 15826, 15825, 15824, 15817, 15816, 15568, 15272, 15271, 15270, 15269, 15268, 15267, 15266, 15265, 13912, 13904, 13806, 13805, 13804, 13803, 13802, 13801, 13800, 13799, 13456, 13341, 12138, 11770, 11655, 11631, 10742, 10540, 10500, 10499, 10498, 10496, 10495, 10494, 10493, 10492, 10491, 10490, 10489, 10488, 10487, 10486, 10485, 10484, 10479, 9979, 9450, 9338, 8920, 8522, 8183, 7387, 6709, 6705, 4894, 4152, 4131, 3455, 2792, 2742, 2275, 462, 302, 187, 156, 69, 21, 20, 19, 11) and (order_code != '' and order_status = 'booked')) GROUP BY 1 ORDER BY 1 LIMIT 3;
|
||||
-- result:
|
||||
None 3.6956521739130435
|
||||
Central Subregion 5.0
|
||||
North Subregion 2.8018867924528297
|
||||
-- !result
|
||||
function: print_hit_materialized_views("SELECT subregion_name, CAST(SUM(total_amount) AS DOUBLE) / CAST(SUM(distance_km) AS DOUBLE) AS avg_fare_per_km FROM fact_orders AS f LEFT JOIN mv_region_geohash AS r ON CAST(r.geohash AS varchar)= CAST(f.geohash AS varchar) WHERE DATE_TRUNC('day', local_time) >= DATE_TRUNC('hour', STR_TO_DATE('2025-08-25 00:00:00', '%Y-%m-%d %H:%i:%S')) AND DATE_TRUNC('day', local_time) < DATE_TRUNC('hour', STR_TO_DATE('2025-09-01 00:00:00', '%Y-%m-%d %H:%i:%S')) AND date_id >= 20230623 AND date_id < 20250903 AND (country_id = 4 and city_id in (6) and vehicle_id in (16866, 16860, 16859, 16810, 15829, 15828, 15827, 15826, 15825, 15824, 15817, 15816, 15568, 15272, 15271, 15270, 15269, 15268, 15267, 15266, 15265, 13912, 13904, 13806, 13805, 13804, 13803, 13802, 13801, 13800, 13799, 13456, 13341, 12138, 11770, 11655, 11631, 10742, 10540, 10500, 10499, 10498, 10496, 10495, 10494, 10493, 10492, 10491, 10490, 10489, 10488, 10487, 10486, 10485, 10484, 10479, 9979, 9450, 9338, 8920, 8522, 8183, 7387, 6709, 6705, 4894, 4152, 4131, 3455, 2792, 2742, 2275, 462, 302, 187, 156, 69, 21, 20, 19, 11) and (order_code != '' and order_status = 'booked')) GROUP BY 1 LIMIT 10001;")
|
||||
-- result:
|
||||
mv_region_geohash,mv_fact_orders_1
|
||||
-- !result
|
||||
REFRESH MATERIALIZED VIEW mv_fact_orders_1 WITH SYNC MODE;
|
||||
REFRESH MATERIALIZED VIEW mv_fact_orders_2 WITH SYNC MODE;
|
||||
REFRESH MATERIALIZED VIEW mv_region_geohash WITH SYNC MODE;
|
||||
SELECT subregion_name, CAST(SUM(total_amount) AS DOUBLE) / CAST(SUM(distance_km) AS DOUBLE) AS avg_fare_per_km FROM fact_orders AS f LEFT JOIN mv_region_geohash AS r ON CAST(r.geohash AS varchar)= CAST(f.geohash AS varchar) WHERE DATE_TRUNC('day', local_time) >= DATE_TRUNC('hour', STR_TO_DATE('2025-08-25 00:00:00', '%Y-%m-%d %H:%i:%S')) AND DATE_TRUNC('day', local_time) < DATE_TRUNC('hour', STR_TO_DATE('2025-09-01 00:00:00', '%Y-%m-%d %H:%i:%S')) AND date_id >= 20230623 AND date_id < 20250903 AND (country_id = 4 and city_id in (6) and vehicle_id in (16866, 16860, 16859, 16810, 15829, 15828, 15827, 15826, 15825, 15824, 15817, 15816, 15568, 15272, 15271, 15270, 15269, 15268, 15267, 15266, 15265, 13912, 13904, 13806, 13805, 13804, 13803, 13802, 13801, 13800, 13799, 13456, 13341, 12138, 11770, 11655, 11631, 10742, 10540, 10500, 10499, 10498, 10496, 10495, 10494, 10493, 10492, 10491, 10490, 10489, 10488, 10487, 10486, 10485, 10484, 10479, 9979, 9450, 9338, 8920, 8522, 8183, 7387, 6709, 6705, 4894, 4152, 4131, 3455, 2792, 2742, 2275, 462, 302, 187, 156, 69, 21, 20, 19, 11) and (order_code != '' and order_status = 'booked')) GROUP BY 1 ORDER BY 1 LIMIT 3;
|
||||
-- result:
|
||||
None 3.6956521739130435
|
||||
Central Subregion 5.0
|
||||
North Subregion 2.8018867924528297
|
||||
-- !result
|
||||
function: print_hit_materialized_views("SELECT subregion_name, CAST(SUM(total_amount) AS DOUBLE) / CAST(SUM(distance_km) AS DOUBLE) AS avg_fare_per_km FROM fact_orders AS f LEFT JOIN mv_region_geohash AS r ON CAST(r.geohash AS varchar)= CAST(f.geohash AS varchar) WHERE DATE_TRUNC('day', local_time) >= DATE_TRUNC('hour', STR_TO_DATE('2025-08-25 00:00:00', '%Y-%m-%d %H:%i:%S')) AND DATE_TRUNC('day', local_time) < DATE_TRUNC('hour', STR_TO_DATE('2025-09-01 00:00:00', '%Y-%m-%d %H:%i:%S')) AND date_id >= 20230623 AND date_id < 20250903 AND (country_id = 4 and city_id in (6) and vehicle_id in (16866, 16860, 16859, 16810, 15829, 15828, 15827, 15826, 15825, 15824, 15817, 15816, 15568, 15272, 15271, 15270, 15269, 15268, 15267, 15266, 15265, 13912, 13904, 13806, 13805, 13804, 13803, 13802, 13801, 13800, 13799, 13456, 13341, 12138, 11770, 11655, 11631, 10742, 10540, 10500, 10499, 10498, 10496, 10495, 10494, 10493, 10492, 10491, 10490, 10489, 10488, 10487, 10486, 10485, 10484, 10479, 9979, 9450, 9338, 8920, 8522, 8183, 7387, 6709, 6705, 4894, 4152, 4131, 3455, 2792, 2742, 2275, 462, 302, 187, 156, 69, 21, 20, 19, 11) and (order_code != '' and order_status = 'booked')) GROUP BY 1 LIMIT 10001;")
|
||||
-- result:
|
||||
mv_fact_orders_1,mv_region_geohash
|
||||
-- !result
|
||||
drop database db_${uuid0};
|
||||
-- result:
|
||||
-- !result
|
||||
|
|
@ -0,0 +1,207 @@
|
|||
-- name: test_mv_rewrite_bugfix2
|
||||
create database db_${uuid0};
|
||||
use db_${uuid0};
|
||||
|
||||
CREATE TABLE `dim_region` (
|
||||
`region_id` bigint(20) NULL COMMENT "",
|
||||
`region_name` varchar(255) NULL COMMENT "",
|
||||
`region_level` varchar(64) NULL COMMENT "",
|
||||
`region_order` bigint(20) NULL COMMENT "",
|
||||
`country_id` bigint(20) NULL COMMENT "",
|
||||
`city_id` bigint(20) NULL COMMENT "",
|
||||
`city_name` varchar(255) NULL COMMENT "",
|
||||
`region_type` varchar(64) NULL COMMENT "",
|
||||
`region_code` varchar(64) NULL COMMENT "",
|
||||
`purpose` varchar(64) NULL COMMENT "",
|
||||
`parent_country` varchar(255) NULL COMMENT "",
|
||||
`parent_territory` varchar(255) NULL COMMENT "",
|
||||
`parent_region` varchar(255) NULL COMMENT "",
|
||||
`parent_city` varchar(255) NULL COMMENT "",
|
||||
`parent_subregion` varchar(255) NULL COMMENT "",
|
||||
`parent_district` varchar(255) NULL COMMENT "",
|
||||
`parent_area` varchar(255) NULL COMMENT "",
|
||||
`geohash_array` array<varchar(64)> NULL COMMENT "",
|
||||
`area_id_array` array<int(11)> NULL COMMENT ""
|
||||
) ENGINE=OLAP
|
||||
DUPLICATE KEY(`region_id`, `region_name`)
|
||||
COMMENT "OLAP"
|
||||
DISTRIBUTED BY RANDOM BUCKETS 1
|
||||
PROPERTIES (
|
||||
"replication_num" = "1"
|
||||
);
|
||||
|
||||
CREATE TABLE `fact_orders` (
|
||||
`city_id` int(11) NULL COMMENT "",
|
||||
`country_id` int(11) NULL COMMENT "",
|
||||
`group_id` varchar(4) NULL COMMENT "",
|
||||
`vehicle_group` varchar(64) NULL COMMENT "",
|
||||
`vehicle_type` varchar(64) NULL COMMENT "",
|
||||
`wheels` varchar(2) NULL COMMENT "",
|
||||
`vehicle_id` bigint(20) NULL COMMENT "",
|
||||
`geohash` varchar(64) NULL COMMENT "",
|
||||
`base_surge` double NULL COMMENT "",
|
||||
`order_code` varchar(64) NULL COMMENT "",
|
||||
`total_amount` double NULL COMMENT "",
|
||||
`distance_km` double NULL COMMENT "",
|
||||
`order_time` datetime NULL COMMENT "",
|
||||
`surge` double NULL COMMENT "",
|
||||
`total_amount_usd` double NULL COMMENT "",
|
||||
`date_id` int(11) NULL COMMENT "",
|
||||
`series_id` varchar(64) NULL COMMENT "",
|
||||
`order_status` varchar(64) NULL COMMENT "",
|
||||
`local_time` datetime NULL COMMENT "",
|
||||
`local_date` datetime NULL COMMENT ""
|
||||
) ENGINE=OLAP
|
||||
DUPLICATE KEY(`city_id`, `country_id`, `group_id`)
|
||||
COMMENT "OLAP"
|
||||
PARTITION BY RANGE(`date_id`)
|
||||
(PARTITION p20230601 VALUES [("20230601"), ("20230602")),
|
||||
PARTITION p20230602 VALUES [("20230602"), ("20230603")),
|
||||
PARTITION p20230603 VALUES [("20230603"), ("20230604")),
|
||||
PARTITION p20230604 VALUES [("20230604"), ("20230605")),
|
||||
PARTITION p20230605 VALUES [("20230605"), ("20230606")),
|
||||
PARTITION p20230606 VALUES [("20230606"), ("20230607")),
|
||||
PARTITION p20230607 VALUES [("20230607"), ("20230608")),
|
||||
PARTITION p20230608 VALUES [("20230608"), ("20230609")),
|
||||
PARTITION p20230609 VALUES [("20230609"), ("20230610")),
|
||||
PARTITION p20230610 VALUES [("20230610"), ("20230611")),
|
||||
PARTITION p20230611 VALUES [("20230611"), ("20230612")),
|
||||
PARTITION p20230612 VALUES [("20230612"), ("20230613")),
|
||||
PARTITION p20230613 VALUES [("20230613"), ("20230614")),
|
||||
PARTITION p20230614 VALUES [("20230614"), ("20230615")),
|
||||
PARTITION p20230615 VALUES [("20230615"), ("20230616")),
|
||||
PARTITION p20230616 VALUES [("20230616"), ("20230617")),
|
||||
PARTITION p20230617 VALUES [("20230617"), ("20230618")),
|
||||
PARTITION p20230618 VALUES [("20230618"), ("20230619")),
|
||||
PARTITION p20230619 VALUES [("20230619"), ("20230620")),
|
||||
PARTITION p20230620 VALUES [("20230620"), ("20230621")),
|
||||
PARTITION p20230621 VALUES [("20230621"), ("20230622")),
|
||||
PARTITION p20230622 VALUES [("20230622"), ("20230623")),
|
||||
PARTITION p20230623 VALUES [("20230623"), ("20230624")),
|
||||
PARTITION p20230624 VALUES [("20230624"), ("20230625")),
|
||||
PARTITION p20230625 VALUES [("20230625"), ("20230626")),
|
||||
PARTITION p20230626 VALUES [("20230626"), ("20230627")),
|
||||
PARTITION p20230627 VALUES [("20230627"), ("20230628")),
|
||||
PARTITION p20230628 VALUES [("20230628"), ("20230629")),
|
||||
PARTITION p20230629 VALUES [("20230629"), ("20230630")),
|
||||
PARTITION p20230630 VALUES [("20230630"), ("20230701")))
|
||||
DISTRIBUTED BY HASH(`order_time`) BUCKETS 8
|
||||
PROPERTIES (
|
||||
"replication_num" = "1"
|
||||
);
|
||||
|
||||
INSERT INTO fact_orders VALUES
|
||||
(6, 4, 'G1', 'Premium', 'Luxury', '4', 16866, 'w21g8', 1.5, 'ORD001', 25.00, 5.0, '2025-08-25 09:15:00', 1.2, 25.00, 20230625, 'S001', 'booked', '2025-08-25 09:00:00', '2025-08-25 00:00:00'),
|
||||
(6, 4, 'G2', 'Standard', 'Compact', '4', 15829, 'w21g9', 1.0, 'ORD002', 12.50, 4.0, '2025-08-26 14:30:00', 1.0, 12.50, 20230626, 'S002', 'booked', '2025-08-26 14:00:00', '2025-08-26 00:00:00'),
|
||||
(6, 4, 'G3', 'Premium', 'SUV', '4', 15272, 'w21g7', 1.8, 'ORD003', 30.00, 7.5, '2025-08-27 18:45:00', 1.5, 30.00, 20230627, 'S003', 'booked', '2025-08-27 18:00:00', '2025-08-27 00:00:00'),
|
||||
(6, 4, 'G4', 'Economy', 'Hatchback', '4', 10495, 'w21g6', 0.8, 'ORD004', 9.60, 3.2, '2025-08-28 11:20:00', 0.9, 9.60, 20230628, 'S004', 'booked', '2025-08-28 11:00:00', '2025-08-28 00:00:00'),
|
||||
(6, 4, 'G5', 'Motorcycle', 'Bike', '2', 462, 'w21g5', 0.5, 'ORD005', 5.25, 2.1, '2025-08-29 16:10:00', 0.6, 5.25, 20230629, 'S005', 'booked', '2025-08-29 16:00:00', '2025-08-29 00:00:00');
|
||||
INSERT INTO dim_region VALUES
|
||||
(101, 'Central Subregion', 'Subregion', 1, 1, 6, 'Metro City', 'Urban', 'REG101', 'Generic', 'Country', 'Territory', 'Region', 'City', 'Central Subregion', NULL, NULL, ['w21g8'], NULL),
|
||||
(102, 'Downtown District', 'District', 2, 1, 6, 'Metro City', 'Urban', 'REG102', 'Generic', 'Country', 'Territory', 'Region', 'City', NULL, 'Downtown District', NULL, ['w21g9'], NULL),
|
||||
(103, 'Market Area', 'Area', 3, 1, 6, 'Metro City', 'Commercial', 'REG103', 'Generic', 'Country', 'Territory', 'Region', 'City', NULL, NULL, 'Market Area', ['w21g7'], NULL),
|
||||
(104, 'North Subregion', 'Subregion', 4, 1, 6, 'Metro City', 'Residential', 'REG104', 'Generic', 'Country', 'Territory', 'Region', 'City', 'North Subregion', NULL, NULL, ['w21g6', 'w21g5', 'w21g4'], NULL),
|
||||
(105, 'Special Zone', 'Subregion', 5, 1, 6, 'Metro City', 'Special', 'REG105', 'Special', 'Country', 'Territory', 'Region', 'City', 'Special Zone', NULL, NULL, ['w21g3'], NULL),
|
||||
(1, 'Downtown', 'City', 1, 1, 101, 'Metropolis', 'Urban', 'REG001', 'Commercial', 'CountryA', 'TerritoryX', 'RegionY', 'Metropolis', 'Central', 'Downtown', 'CBD', ['geohash1', 'geohash2'], [1001, 1002]),
|
||||
(2, 'Tech Park', 'District', 2, 1, 101, 'Metropolis', 'Suburban', 'REG002', 'Industrial', 'CountryA', 'TerritoryX', 'RegionY', 'Metropolis', 'East', 'Tech Zone', 'Innovation Park', ['geohash3', 'geohash4'], [2001, 2002]),
|
||||
(3, 'Beachside', 'Subregion', 3, 1, 102, 'Coastal City', 'Resort', 'REG003', 'Tourism', 'CountryA', 'TerritoryX', 'RegionZ', 'Coastal City', 'South', 'Beach District', 'Seaside', ['geohash5', 'geohash6'], [3001, 3002]),
|
||||
(4, 'Mountain View', 'Region', 4, 1, 103, 'Hill Town', 'Rural', 'REG004', 'Residential', 'CountryA', 'TerritoryY', 'RegionW', 'Hill Town', 'North', 'Highland', 'Scenic Area', ['geohash7', 'geohash8'], [4001, 4002]),
|
||||
(5, 'Old Town', 'Area', 5, 2, 201, 'Historic City', 'Heritage', 'REG005', 'Cultural', 'CountryB', 'TerritoryZ', 'RegionV', 'Historic City', 'Center', 'Heritage Zone', 'Ancient Quarter', ['geohash9', 'geohash10'], [5001, 5002]);
|
||||
INSERT INTO fact_orders VALUES
|
||||
(101, 1, 'G1', 'Standard', 'Sedan', '4', 1001, 'ws8g', 1.2, 'ORD006', 15.50, 5.3, '2023-10-15 08:30:45', 1.1, 15.50, 20230615, 'S006', 'completed', '2023-10-15 08:00:00', '2023-10-15 00:00:00'),
|
||||
(101, 1, 'G2', 'Premium', 'SUV', '4', 1002, 'ws8h', 1.5, 'ORD007', 25.75, 7.8, '2023-10-15 09:15:22', 1.3, 25.75, 20230615, 'S007', 'completed', '2023-10-15 09:00:00', '2023-10-15 00:00:00'),
|
||||
(102, 1, 'G3', 'Motorcycle', 'Bike', '2', 2001, 'ws9j', 1.0, 'ORD008', 8.20, 3.1, '2023-10-16 14:45:10', 1.0, 8.20, 20230616, 'S008', 'cancelled', '2023-10-16 14:00:00', '2023-10-16 00:00:00'),
|
||||
(103, 2, 'G4', 'Delivery', 'Truck', '6', 3001, 'ws7k', 1.8, 'ORD009', 45.90, 12.5, '2023-10-17 11:20:33', 1.6, 45.90, 20230617, 'S009', 'completed', '2023-10-17 11:00:00', '2023-10-17 00:00:00'),
|
||||
(101, 1, 'G1', 'Pool', 'Compact', '4', 1003, 'ws8m', 0.9, 'ORD010', 10.25, 4.2, '2023-10-18 17:55:18', 0.8, 10.25, 20230618, 'S010', 'completed', '2023-10-18 17:00:00', '2023-10-18 00:00:00');
|
||||
|
||||
CREATE MATERIALIZED VIEW `mv_region_geohash`
|
||||
DISTRIBUTED BY RANDOM BUCKETS 1
|
||||
REFRESH ASYNC EVERY(INTERVAL 6 HOUR)
|
||||
PROPERTIES (
|
||||
"replication_num" = "1")
|
||||
AS SELECT `t2`.`geohash`,
|
||||
max(CASE WHEN (`t2`.`region_level` = 'Subregion') THEN `t2`.`region_id` ELSE NULL END) AS `subregion_id`,
|
||||
max(CASE WHEN (`t2`.`region_level` = 'Subregion') THEN `t2`.`region_name` ELSE NULL END) AS `subregion_name`,
|
||||
max(CASE WHEN (`t2`.`region_level` = 'District') THEN `t2`.`region_id` ELSE NULL END) AS `district_id`,
|
||||
max(CASE WHEN (`t2`.`region_level` = 'District') THEN `t2`.`region_name` ELSE NULL END) AS `district_name`,
|
||||
max(CASE WHEN (`t2`.`region_level` = 'Area') THEN `t2`.`region_id` ELSE NULL END) AS `area_id`,
|
||||
max(CASE WHEN (`t2`.`region_level` = 'Area') THEN `t2`.`region_name` ELSE NULL END) AS `area_name`
|
||||
FROM (
|
||||
SELECT `dim_region`.`city_id`, `dim_region`.`region_level`, `dim_region`.`region_id`, `dim_region`.`region_name`, `dim_region`.`purpose`, `t0`.`geohash`
|
||||
FROM `dim_region` AS `dim_region`
|
||||
CROSS JOIN LATERAL unnest(`dim_region`.`geohash_array`) t0(`geohash`)
|
||||
WHERE `dim_region`.`region_level` IN ('Subregion', 'District', 'Area')
|
||||
) `t2`
|
||||
WHERE `t2`.`purpose` = 'Generic'
|
||||
GROUP BY `t2`.`geohash`;
|
||||
|
||||
CREATE MATERIALIZED VIEW `mv_fact_orders_1`
|
||||
PARTITION BY (`date_id`)
|
||||
DISTRIBUTED BY HASH(`geohash`)
|
||||
ORDER BY (vehicle_id)
|
||||
REFRESH ASYNC
|
||||
PROPERTIES (
|
||||
"replication_num" = "1",
|
||||
"query_rewrite_consistency" = "loose"
|
||||
)
|
||||
AS SELECT date_trunc('day', `fact_orders`.`local_time`) AS `local_time_day`,
|
||||
date_trunc('hour', `fact_orders`.`local_time`) AS `local_time_hour`,
|
||||
`fact_orders`.`geohash`, `fact_orders`.`date_id`, `fact_orders`.`city_id`, `fact_orders`.`country_id`,
|
||||
`fact_orders`.`vehicle_id`, `fact_orders`.`wheels`, `fact_orders`.`vehicle_type`, `fact_orders`.`vehicle_group`,
|
||||
`fact_orders`.`order_status`,
|
||||
sum(`fact_orders`.`total_amount_usd`) AS `sum_total_amount_usd`,
|
||||
sum(`fact_orders`.`total_amount`) AS `sum_total_amount`,
|
||||
sum(`fact_orders`.`distance_km`) AS `sum_distance_km`,
|
||||
sum(`fact_orders`.`surge`) AS `sum_surge`,
|
||||
count(`fact_orders`.`surge`) AS `count_surge`
|
||||
FROM `fact_orders`
|
||||
WHERE `fact_orders`.`order_code` != ''
|
||||
GROUP BY 1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11;
|
||||
|
||||
CREATE MATERIALIZED VIEW `mv_fact_orders_2`
|
||||
PARTITION BY (`date_id`)
|
||||
DISTRIBUTED BY HASH(`geohash`)
|
||||
ORDER BY (country_id)
|
||||
REFRESH ASYNC
|
||||
PROPERTIES (
|
||||
"replication_num" = "1",
|
||||
"query_rewrite_consistency" = "loose")
|
||||
AS SELECT date_trunc('day', `fact_orders`.`order_time`) AS `order_time_day`,
|
||||
date_trunc('hour', `fact_orders`.`order_time`) AS `order_time_hour`,
|
||||
date_trunc('hour', `fact_orders`.`local_time`) AS `local_time_hour`,
|
||||
date_trunc('day', `fact_orders`.`local_time`) AS `local_time_day`,
|
||||
`fact_orders`.`geohash`, `fact_orders`.`date_id`, `fact_orders`.`city_id`, `fact_orders`.`country_id`,
|
||||
`fact_orders`.`vehicle_id`, `fact_orders`.`wheels`, `fact_orders`.`vehicle_type`, `fact_orders`.`vehicle_group`,
|
||||
`fact_orders`.`order_status`,
|
||||
sum(`fact_orders`.`total_amount_usd`) AS `sum_total_amount_usd`,
|
||||
sum(`fact_orders`.`total_amount`) AS `sum_total_amount`,
|
||||
sum(`fact_orders`.`distance_km`) AS `sum_distance_km`,
|
||||
sum(`fact_orders`.`surge`) AS `sum_surge`,
|
||||
count(`fact_orders`.`surge`) AS `count_surge`
|
||||
FROM `fact_orders`
|
||||
WHERE `fact_orders`.`order_code` = ''
|
||||
GROUP BY 1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12, 13;
|
||||
|
||||
REFRESH MATERIALIZED VIEW mv_fact_orders_1 FORCE WITH SYNC MODE;
|
||||
REFRESH MATERIALIZED VIEW mv_fact_orders_2 FORCE WITH SYNC MODE;
|
||||
REFRESH MATERIALIZED VIEW mv_region_geohash FORCE WITH SYNC MODE;
|
||||
|
||||
SELECT subregion_name, CAST(SUM(total_amount) AS DOUBLE) / CAST(SUM(distance_km) AS DOUBLE) AS avg_fare_per_km FROM fact_orders AS f LEFT JOIN mv_region_geohash AS r ON CAST(r.geohash AS varchar)= CAST(f.geohash AS varchar) WHERE DATE_TRUNC('day', local_time) >= DATE_TRUNC('hour', STR_TO_DATE('2025-08-25 00:00:00', '%Y-%m-%d %H:%i:%S')) AND DATE_TRUNC('day', local_time) < DATE_TRUNC('hour', STR_TO_DATE('2025-09-01 00:00:00', '%Y-%m-%d %H:%i:%S')) AND date_id >= 20230623 AND date_id < 20250903 AND (country_id = 4 and city_id in (6) and vehicle_id in (16866, 16860, 16859, 16810, 15829, 15828, 15827, 15826, 15825, 15824, 15817, 15816, 15568, 15272, 15271, 15270, 15269, 15268, 15267, 15266, 15265, 13912, 13904, 13806, 13805, 13804, 13803, 13802, 13801, 13800, 13799, 13456, 13341, 12138, 11770, 11655, 11631, 10742, 10540, 10500, 10499, 10498, 10496, 10495, 10494, 10493, 10492, 10491, 10490, 10489, 10488, 10487, 10486, 10485, 10484, 10479, 9979, 9450, 9338, 8920, 8522, 8183, 7387, 6709, 6705, 4894, 4152, 4131, 3455, 2792, 2742, 2275, 462, 302, 187, 156, 69, 21, 20, 19, 11) and (order_code != '' and order_status = 'booked')) GROUP BY 1 ORDER BY 1 LIMIT 3;
|
||||
function: print_hit_materialized_views("SELECT subregion_name, CAST(SUM(total_amount) AS DOUBLE) / CAST(SUM(distance_km) AS DOUBLE) AS avg_fare_per_km FROM fact_orders AS f LEFT JOIN mv_region_geohash AS r ON CAST(r.geohash AS varchar)= CAST(f.geohash AS varchar) WHERE DATE_TRUNC('day', local_time) >= DATE_TRUNC('hour', STR_TO_DATE('2025-08-25 00:00:00', '%Y-%m-%d %H:%i:%S')) AND DATE_TRUNC('day', local_time) < DATE_TRUNC('hour', STR_TO_DATE('2025-09-01 00:00:00', '%Y-%m-%d %H:%i:%S')) AND date_id >= 20230623 AND date_id < 20250903 AND (country_id = 4 and city_id in (6) and vehicle_id in (16866, 16860, 16859, 16810, 15829, 15828, 15827, 15826, 15825, 15824, 15817, 15816, 15568, 15272, 15271, 15270, 15269, 15268, 15267, 15266, 15265, 13912, 13904, 13806, 13805, 13804, 13803, 13802, 13801, 13800, 13799, 13456, 13341, 12138, 11770, 11655, 11631, 10742, 10540, 10500, 10499, 10498, 10496, 10495, 10494, 10493, 10492, 10491, 10490, 10489, 10488, 10487, 10486, 10485, 10484, 10479, 9979, 9450, 9338, 8920, 8522, 8183, 7387, 6709, 6705, 4894, 4152, 4131, 3455, 2792, 2742, 2275, 462, 302, 187, 156, 69, 21, 20, 19, 11) and (order_code != '' and order_status = 'booked')) GROUP BY 1 LIMIT 10001;")
|
||||
|
||||
INSERT INTO dim_region VALUES
|
||||
(4, 'Mountain View', 'Region', 4, 1, 103, 'Hill Town', 'Rural', 'REG004', 'Residential', 'CountryA', 'TerritoryY', 'RegionW', 'Hill Town', 'North', 'Highland', 'Scenic Area', ['geohash7', 'geohash8'], [4001, 4002]);
|
||||
INSERT INTO fact_orders VALUES
|
||||
(101, 1, 'G1', 'Standard', 'Sedan', '4', 1001, 'ws8g', 1.2, 'ORD006', 15.50, 5.3, '2023-10-15 08:30:45', 1.1, 15.50, 20230615, 'S006', 'completed', '2023-10-15 08:00:00', '2023-10-15 00:00:00');
|
||||
|
||||
SELECT subregion_name, CAST(SUM(total_amount) AS DOUBLE) / CAST(SUM(distance_km) AS DOUBLE) AS avg_fare_per_km FROM fact_orders AS f LEFT JOIN mv_region_geohash AS r ON CAST(r.geohash AS varchar)= CAST(f.geohash AS varchar) WHERE DATE_TRUNC('day', local_time) >= DATE_TRUNC('hour', STR_TO_DATE('2025-08-25 00:00:00', '%Y-%m-%d %H:%i:%S')) AND DATE_TRUNC('day', local_time) < DATE_TRUNC('hour', STR_TO_DATE('2025-09-01 00:00:00', '%Y-%m-%d %H:%i:%S')) AND date_id >= 20230623 AND date_id < 20250903 AND (country_id = 4 and city_id in (6) and vehicle_id in (16866, 16860, 16859, 16810, 15829, 15828, 15827, 15826, 15825, 15824, 15817, 15816, 15568, 15272, 15271, 15270, 15269, 15268, 15267, 15266, 15265, 13912, 13904, 13806, 13805, 13804, 13803, 13802, 13801, 13800, 13799, 13456, 13341, 12138, 11770, 11655, 11631, 10742, 10540, 10500, 10499, 10498, 10496, 10495, 10494, 10493, 10492, 10491, 10490, 10489, 10488, 10487, 10486, 10485, 10484, 10479, 9979, 9450, 9338, 8920, 8522, 8183, 7387, 6709, 6705, 4894, 4152, 4131, 3455, 2792, 2742, 2275, 462, 302, 187, 156, 69, 21, 20, 19, 11) and (order_code != '' and order_status = 'booked')) GROUP BY 1 ORDER BY 1 LIMIT 3;
|
||||
function: print_hit_materialized_views("SELECT subregion_name, CAST(SUM(total_amount) AS DOUBLE) / CAST(SUM(distance_km) AS DOUBLE) AS avg_fare_per_km FROM fact_orders AS f LEFT JOIN mv_region_geohash AS r ON CAST(r.geohash AS varchar)= CAST(f.geohash AS varchar) WHERE DATE_TRUNC('day', local_time) >= DATE_TRUNC('hour', STR_TO_DATE('2025-08-25 00:00:00', '%Y-%m-%d %H:%i:%S')) AND DATE_TRUNC('day', local_time) < DATE_TRUNC('hour', STR_TO_DATE('2025-09-01 00:00:00', '%Y-%m-%d %H:%i:%S')) AND date_id >= 20230623 AND date_id < 20250903 AND (country_id = 4 and city_id in (6) and vehicle_id in (16866, 16860, 16859, 16810, 15829, 15828, 15827, 15826, 15825, 15824, 15817, 15816, 15568, 15272, 15271, 15270, 15269, 15268, 15267, 15266, 15265, 13912, 13904, 13806, 13805, 13804, 13803, 13802, 13801, 13800, 13799, 13456, 13341, 12138, 11770, 11655, 11631, 10742, 10540, 10500, 10499, 10498, 10496, 10495, 10494, 10493, 10492, 10491, 10490, 10489, 10488, 10487, 10486, 10485, 10484, 10479, 9979, 9450, 9338, 8920, 8522, 8183, 7387, 6709, 6705, 4894, 4152, 4131, 3455, 2792, 2742, 2275, 462, 302, 187, 156, 69, 21, 20, 19, 11) and (order_code != '' and order_status = 'booked')) GROUP BY 1 LIMIT 10001;")
|
||||
|
||||
REFRESH MATERIALIZED VIEW mv_fact_orders_1 WITH SYNC MODE;
|
||||
REFRESH MATERIALIZED VIEW mv_fact_orders_2 WITH SYNC MODE;
|
||||
REFRESH MATERIALIZED VIEW mv_region_geohash WITH SYNC MODE;
|
||||
|
||||
SELECT subregion_name, CAST(SUM(total_amount) AS DOUBLE) / CAST(SUM(distance_km) AS DOUBLE) AS avg_fare_per_km FROM fact_orders AS f LEFT JOIN mv_region_geohash AS r ON CAST(r.geohash AS varchar)= CAST(f.geohash AS varchar) WHERE DATE_TRUNC('day', local_time) >= DATE_TRUNC('hour', STR_TO_DATE('2025-08-25 00:00:00', '%Y-%m-%d %H:%i:%S')) AND DATE_TRUNC('day', local_time) < DATE_TRUNC('hour', STR_TO_DATE('2025-09-01 00:00:00', '%Y-%m-%d %H:%i:%S')) AND date_id >= 20230623 AND date_id < 20250903 AND (country_id = 4 and city_id in (6) and vehicle_id in (16866, 16860, 16859, 16810, 15829, 15828, 15827, 15826, 15825, 15824, 15817, 15816, 15568, 15272, 15271, 15270, 15269, 15268, 15267, 15266, 15265, 13912, 13904, 13806, 13805, 13804, 13803, 13802, 13801, 13800, 13799, 13456, 13341, 12138, 11770, 11655, 11631, 10742, 10540, 10500, 10499, 10498, 10496, 10495, 10494, 10493, 10492, 10491, 10490, 10489, 10488, 10487, 10486, 10485, 10484, 10479, 9979, 9450, 9338, 8920, 8522, 8183, 7387, 6709, 6705, 4894, 4152, 4131, 3455, 2792, 2742, 2275, 462, 302, 187, 156, 69, 21, 20, 19, 11) and (order_code != '' and order_status = 'booked')) GROUP BY 1 ORDER BY 1 LIMIT 3;
|
||||
function: print_hit_materialized_views("SELECT subregion_name, CAST(SUM(total_amount) AS DOUBLE) / CAST(SUM(distance_km) AS DOUBLE) AS avg_fare_per_km FROM fact_orders AS f LEFT JOIN mv_region_geohash AS r ON CAST(r.geohash AS varchar)= CAST(f.geohash AS varchar) WHERE DATE_TRUNC('day', local_time) >= DATE_TRUNC('hour', STR_TO_DATE('2025-08-25 00:00:00', '%Y-%m-%d %H:%i:%S')) AND DATE_TRUNC('day', local_time) < DATE_TRUNC('hour', STR_TO_DATE('2025-09-01 00:00:00', '%Y-%m-%d %H:%i:%S')) AND date_id >= 20230623 AND date_id < 20250903 AND (country_id = 4 and city_id in (6) and vehicle_id in (16866, 16860, 16859, 16810, 15829, 15828, 15827, 15826, 15825, 15824, 15817, 15816, 15568, 15272, 15271, 15270, 15269, 15268, 15267, 15266, 15265, 13912, 13904, 13806, 13805, 13804, 13803, 13802, 13801, 13800, 13799, 13456, 13341, 12138, 11770, 11655, 11631, 10742, 10540, 10500, 10499, 10498, 10496, 10495, 10494, 10493, 10492, 10491, 10490, 10489, 10488, 10487, 10486, 10485, 10484, 10479, 9979, 9450, 9338, 8920, 8522, 8183, 7387, 6709, 6705, 4894, 4152, 4131, 3455, 2792, 2742, 2275, 462, 302, 187, 156, 69, 21, 20, 19, 11) and (order_code != '' and order_status = 'booked')) GROUP BY 1 LIMIT 10001;")
|
||||
|
||||
drop database db_${uuid0};
|
||||
Loading…
Reference in New Issue